Re: Partitioning and constraint exclusion

From: Jayadevan M <maymala(dot)jayadevan(at)gmail(dot)com>
To: "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>
Cc: "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org>
Subject: Re: Partitioning and constraint exclusion
Date: 2015-09-08 11:49:27
Message-ID: CAFS1N4jXADP7P-U6-hZMMKtq0oizYLxwxXJipQkZVEshg1fcmA@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

>
>
>
> ​I am not sure but am doubting it is intelligent enough to recognize the
> functional expression even if all of the values are present. "simple
> equality" (
> http://www.postgresql.org/docs/9.4/interactive/ddl-partitioning.html)
> this is not.
>

Looks like the tables with about 100+ values in the check list gets pulled
in, even with constraint exclusion on. I created a simple test case. One
parent table with just one column, and 3 child tables with one column.
test=# \d+ parent
Table "public.parent"
Column | Type | Modifiers | Storage | Stats target | Description
--------+---------+-----------+---------+--------------+-------------
id | integer | | plain | |
Child tables: child1,
child2,
child3

test=# \d+ child1
Table "public.child1"
Column | Type | Modifiers | Storage | Stats target | Description
--------+---------+-----------+---------+--------------+-------------
id | integer | | plain | |
Check constraints:
"c" CHECK (id = ANY (ARRAY[1, 2]))
Inherits: parent

test=# \d+ child2
Table "public.child2"
Column | Type | Modifiers | Storage | Stats target | Description
--------+---------+-----------+---------+--------------+-------------
id | integer | | plain | |
Check constraints:
"c" CHECK (id = ANY (ARRAY[3, 4]))
Inherits: parent

test=# \d+ child3
Table "public.child3"
Column | Type | Modifiers | Storage | Stats target | Description
--------+---------+-----------+---------+--------------+-------------
id | integer | | plain | |
Check constraints:
"c3" CHECK (id = ANY (ARRAY[5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16,
17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35,
36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54,
55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73,
74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92,
93, 94, 95, 96, 97, 98, 99, 100]))
Inherits: parent

test=# explain analyze select * from parent where id = 1;
QUERY PLAN

--------------------------------------------------------------------------------------------------------
Append (cost=0.00..40.00 rows=13 width=4) (actual time=0.002..0.002
rows=0 loops=1)
-> Seq Scan on parent (cost=0.00..0.00 rows=1 width=4) (actual
time=0.001..0.001 rows=0 loops=1)
Filter: (id = 1)
* -> Seq Scan on child1 (cost=0.00..40.00 rows=12 width=4) (actual
time=0.000..0.000 rows=0 loops=1)*
* Filter: (id = 1)*
Total runtime: 0.029 ms

If I increase the number of values a bit more.....
with t as (select generate_series(*5,110*) x ) select 'alter table child3
add constraint c3 check ( id in ( ' || string_agg(x::text,',') || ' ))
; ' from t;

test=# explain analyze select * from parent where id = 1;
QUERY PLAN

--------------------------------------------------------------------------------------------------------
Append (cost=0.00..80.00 rows=25 width=4) (actual time=0.003..0.003
rows=0 loops=1)
-> Seq Scan on parent (cost=0.00..0.00 rows=1 width=4) (actual
time=0.001..0.001 rows=0 loops=1)
Filter: (id = 1)
-> Seq Scan on child1 (cost=0.00..40.00 rows=12 width=4) (actual
time=0.000..0.000 rows=0 loops=1)
Filter: (id = 1)
* -> Seq Scan on child3 (cost=0.00..40.00 rows=12 width=4) (actual
time=0.000..0.000 rows=0 loops=1)*
* Filter: (id = 1)*

Thanks,
Jayadevan

David J.
>
>

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Ramesh T 2015-09-08 12:19:25 view
Previous Message Craig Ringer 2015-09-08 06:33:43 Re: bdr admin role