Specifying multiple partitioning keys in a RANGE partitioned table v14
You can often improve performance by specifying multiple key columns for a RANGE partitioned table. If you often select rows using comparison operators on a small set of columns based on a greater-than or less-than value, consider using those columns in RANGE partitioning rules.
Specifying multiple keys in a range-partitioned table
Range-partitioned table definitions can include multiple columns in the partitioning key. To specify multiple partitioning keys for a range-partitioned table, include the column names in a comma-separated list after the PARTITION BY RANGE clause:
CREATE TABLE sales
(
dept_no number,
part_no varchar2,
country varchar2(20),
sale_year number,
sale_month number,
sale_day number,
amount number
)
PARTITION BY RANGE(sale_year, sale_month)
(
PARTITION q1_2012
VALUES LESS THAN(2012, 4),
PARTITION q2_2012
VALUES LESS THAN(2012, 7),
PARTITION q3_2012
VALUES LESS THAN(2012, 10),
PARTITION q4_2012
VALUES LESS THAN(2013, 1)
);If a table is created with multiple partitioning keys, you must specify multiple key values when querying the table to take full advantage of partition pruning:
edb=# EXPLAIN SELECT * FROM sales WHERE sale_year = 2012 AND sale_month = 8;
QUERY PLAN
----------------------------------------------------------------------------
Append (cost=0.00..14.35 rows=1 width=250)
-> Seq Scan on sales_q3_2012 (cost=0.00..14.35 rows=1 width=250)
Filter: ((sale_year = '2012'::numeric) AND (sale_month = '8'::numeric))
(3 rows)Since all rows with a value of 8 in the sale_month column and a value of 2012 in the sale_year column are stored in the q3_2012 partition, EDB Postgres Advanced Server searches only that partition.