Re: Query performance problems with partitioned tables - Mailing list pgsql-performance
From | Andreas Haumer |
---|---|
Subject | Re: Query performance problems with partitioned tables |
Date | |
Msg-id | 46362027.9000803@xss.co.at Whole thread Raw |
In response to | Re: Query performance problems with partitioned tables ("Neil Peter Braggio" <pbraggio@gmail.com>) |
List | pgsql-performance |
-----BEGIN PGP SIGNED MESSAGE----- Hash: SHA1 Hi! Neil Peter Braggio schrieb: > Just cast the value in the WHERE clause: > > select ts from mwdb.t_mv where zr=3622 and ts > '2006-01-01 00:00:00' > ::TIMESTAMP order by ts asc limit 1; > > This search only into the right partitioned tables if you build the > rules based in the ts field. > This doesn't help. A cast is not needed in this case, as the following query shows, where the query planner already is able to reduce the scan to the right tables: testdb_part=> select ts from mwdb.t_mv where zr=3622 and ts > '2005-12-31 22:00:00' and ts < '2006-01-01 02:00:00'; ts - ------------------------ 2005-12-31 23:00:00+01 2006-01-01 00:00:00+01 2006-01-01 01:00:00+01 (3 rows) testdb_part=> explain analyze select ts from mwdb.t_mv where zr=3622 and ts > '2005-12-31 22:00:00' and ts < '2006-01-0102:00:00'; QUERY PLAN - ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Result (cost=0.00..26.64 rows=4 width=8) (actual time=0.040..0.088 rows=3 loops=1) -> Append (cost=0.00..26.64 rows=4 width=8) (actual time=0.035..0.071 rows=3 loops=1) -> Index Scan using i_mv_ts on t_mv (cost=0.00..8.27 rows=1 width=8) (actual time=0.010..0.010 rows=0 loops=1) Index Cond: (((ts)::timestamp with time zone > '2005-12-31 22:00:00+01'::timestamp with time zone) AND ((ts)::timestampwith time zone < '2006-01-01 02:00:00+01'::timestamp with time zone)) Filter: ((zr)::integer = 3622) -> Index Scan using pk_mv_200512 on t_mv_200512 t_mv (cost=0.00..8.30 rows=1 width=8) (actual time=0.019..0.022rows=1 loops=1) Index Cond: (((zr)::integer = 3622) AND ((ts)::timestamp with time zone > '2005-12-31 22:00:00+01'::timestampwith time zone) AND ((ts)::timestamp with time zone < '2006-01-01 02:00:00+01'::timestamp with timezone)) -> Index Scan using pk_mv_200601 on t_mv_200601 t_mv (cost=0.00..10.07 rows=2 width=8) (actual time=0.014..0.019rows=2 loops=1) Index Cond: (((zr)::integer = 3622) AND ((ts)::timestamp with time zone > '2005-12-31 22:00:00+01'::timestampwith time zone) AND ((ts)::timestamp with time zone < '2006-01-01 02:00:00+01'::timestamp with timezone)) Total runtime: 0.176 ms (10 rows) Here, two child tables are involved (t_mv_200512 and t_mv_200601) and the query only uses those two, even without cast of the constants in the where clause. - - andreas - -- Andreas Haumer | mailto:andreas@xss.co.at *x Software + Systeme | http://www.xss.co.at/ Karmarschgasse 51/2/20 | Tel: +43-1-6060114-0 A-1100 Vienna, Austria | Fax: +43-1-6060114-71 -----BEGIN PGP SIGNATURE----- Version: GnuPG v1.4.6 (GNU/Linux) Comment: Using GnuPG with Mozilla - http://enigmail.mozdev.org iD8DBQFGNiATxJmyeGcXPhERAo23AJwPCBwvWQT/m3QRXRWqK0aECeMQ2gCbBDjA E5iZNnU41vrFBNtXzdCSmWY= =0+pC -----END PGP SIGNATURE-----
pgsql-performance by date: