t_p为父表,t_p_1,t_p_2是子表
hank=> \d+ t_p
Table "hank.t_p"
Column | Type | Modifiers | Storage | Stats target | Description
--------+-----------------------------+-----------------------------------+----------+--------------+-------------
c1 | integer | | plain | |
c2 | character varying(20) | | extended | |
c3 | timestamp without time zone | | plain | |
c4 | character varying(20) | | extended | |
c5 | character varying(20) | default 'test'::character varying | extended | |
c6 | character varying(20) | default 'hank'::character varying | extended | |
Child tables: t_p_1,
t_p_2
hank=> \d t_p_2
Table "hank.t_p_2"
Column | Type | Modifiers
--------+-----------------------------+-----------------------------------
c1 | integer |
c2 | character varying(20) |
c3 | timestamp without time zone |
c4 | character varying(20) |
c5 | character varying(20) | default 'test'::character varying
c6 | character varying(20) | default 'hank'::character varying
Check constraints:
"t_p_201802" CHECK (c3 >= '2018-02-01'::date AND c3 < '2018-03-01'::date)
Inherits: t_p
hank=> \d t_p_1
Table "hank.t_p_1"
Column | Type | Modifiers
--------+-----------------------------+-----------------------------------
c1 | integer |
c2 | character varying(20) |
c3 | timestamp without time zone |
c4 | character varying(20) |
c5 | character varying(20) | default 'test'::character varying
c6 | character varying(20) | default 'hank'::character varying
Check constraints:
"t_p_201801" CHECK (c3 >= '2018-01-01'::date AND c3 < '2018-02-01'::date)
Inherits: t_p
查看分区筛选参数:
hank=> show constraint_exclusion ;
constraint_exclusion
----------------------
partition
(1 row)
如果是to_date无法裁剪,扫描了父表和所有子表
hank=> explain select * from t_p where c3>to_date('2018-02-02','yyyy-mm-dd');
QUERY PLAN
--------------------------------------------------------------------------------
Gather (cost=1000.00..76112.02 rows=3 width=208)
Workers Planned: 3
-> Append (cost=0.00..75111.72 rows=3 width=208)
-> Parallel Seq Scan on t_p (cost=0.00..0.00 rows=1 width=244)
Filter: (c3 > to_date('2018-02-02'::text, 'yyyy-mm-dd'::text))
-> Parallel Seq Scan on t_p_1 (cost=0.00..75098.46 rows=1 width=190)
Filter: (c3 > to_date('2018-02-02'::text, 'yyyy-mm-dd'::text))
-> Parallel Seq Scan on t_p_2 (cost=0.00..13.26 rows=1 width=190)
Filter: (c3 > to_date('2018-02-02'::text, 'yyyy-mm-dd'::text))
(9 rows)
date可以裁剪,过滤掉无关分区,只扫描父表和t_p_2,达到优化效果
hank=> explain select * from t_p where c3>date'2018-02-02';
QUERY PLAN
--------------------------------------------------------------
Append (cost=0.00..14.62 rows=2 width=217)
-> Seq Scan on t_p (cost=0.00..0.00 rows=1 width=244)
Filter: (c3 > '2018-02-02'::date)
-> Seq Scan on t_p_2 (cost=0.00..14.62 rows=1 width=190)
Filter: (c3 > '2018-02-02'::date)
(5 rows)
这里to_date为什么不能过滤掉无效分区呢,而date可以,因为过滤分区的首要条件是要immutable函数,to_date是stable函数,所以无效
查看to_date的稳定性
这里s是stable,i是immutable
hank=> select proname,provolatile,proargtypes from pg_proc where proname='to_date';
proname | provolatile | proargtypes
---------+-------------+-------------
to_date | s | 25 25
(1 row)
hank=> select oid,typname from pg_type where oid in (25);
oid | typname
-----+---------
25 | text
(1 row)
查看date稳定性
hank=> select proname,provolatile,proargtypes from pg_proc where proname='date';
proname | provolatile | proargtypes
---------+-------------+-------------
date | s | 1184
date | s | 702
date | i | 1114
(3 rows)
hank=> select oid,typname from pg_type where oid in (1184,702,1114);
oid | typname
------+-------------
702 | abstime
1114 | timestamp
1184 | timestamptz