Thread: Optimize querry sql
Hi, I had errors in my last emails. sorry I want to optimize my query sql (execution time : 2665 ms) : SELECT b.idxreseller, sum(a.nbrq), b.namereseller from stat a ,reseller b where b.asp=6 and a.idxreseller=b.reseller and a.month=date_part('month',now() - interval '1 month') and a.year=date_part('year',now() - interval '1 month') GROUP BY b.idxreseller,b.namereseller limit 15; Explain analyse : Limit (cost=1057.15..1057.16 rows=1 width=27) (actual time=2655.083..2655.176 rows=15 loops=1) -> HashAggregate (cost=1057.15..1057.16 rows=1 width=27) (actual time=2655.074..2655.132 rows=15 loops=1) -> Nested Loop (cost=0.00..1057.14 rows=1 width=27) (actual time=0.646..2464.563 rows=18543 loops=1) -> Seq Scan on stat a (cost=0.00..1042.98 rows=1 width=8) (actual time=0.273..1239.510 rows=24881 loops=1) Filter: (((month)::double precision = date_part('month'::text, (now() - '1 mon'::interval))) AND ((year)::double precision = date_part('year'::text, (now() - '1 mon'::interval)))) -> Index Scan using reseller_pkey on reseller b (cost=0.00..14.15 rows=1 width=23) (actual time=0.034..0.038 rows=1 loops=24881) Index Cond: ("outer".idxrreseller = b.idxreseller) Filter: (asp = 6)Totalruntime: 2655.713 ms dns=> \d stat; Table «public.stat» idxreseller | integer | not nullidxdo | integer | not nullidxd | integer | not nullnbrq | integer | default0month | integer | default date_part('month'::text, (now() - '1 mon'::interval))year | integer | default date_part('year'::text, (now() - '1 mon'::interval)) Index : «stat_dns_domaine_idx_idxr_idxreseller» btree (dxreseller) «stat_dns_domaine_idx_month_year_idxres» btree (month,year, idxreseller) \d reseller; Table «public.reseller» idxreseller | integer | not null default nextval(('idxrevendeur_seq'::text)::regclass)namereseller | text |asp | integer | Index : «reseller_pkey» PRIMARY KEY, btree (idxreseller) Have you advices ? Thank you Stan
On Fri, Sep 14, 2007 at 03:02:59PM +0200, Stanislas de Larocque wrote: > I want to optimize my query sql (execution time : 2665 ms) : SELECT b.idxreseller, sum(a.nbrq), b.namereseller from stat a, reseller b where b.asp=6 and a.idxreseller=b.reseller and a.month=date_part('month',now() - interval '1 month') and a.year=date_part('year',now()- interval '1 month') GROUP BY b.idxreseller,b.namereseller limit 15; 1. cast all date_parts to int4, like in: a.month = cast( date_part('month',now() - interval '1 month') as int4) 2. why there is a limit without any order by? 3. change it to get namereseller from subselect, not from join. depesz -- quicksil1er: "postgres is excellent, but like any DB it requires a highly paid DBA. here's my CV!" :) http://www.depesz.com/ - blog dla ciebie (i moje CV)
Hi, I deleted the fonction date_part and now the time of the querry is : 464 ms !!! Limit (cost=1373.32..1373.50 rows=15 width=27) (actual time=463.762..463.857 rows=15 loops=1) -> HashAggregate (cost=1373.32..1408.52 rows=2816 width=27) (actual time=463.755..463.820 rows=15 loops=1) -> Hash Join (cost=149.72..1189.22 rows=24546 width=27) (actual time=42.106..348.561 rows=18543 loops=1) Hash Cond: ("outer".idxreseller = "inner".idxreseller) -> Seq Scan on stat a (cost=0.00..545.27 rows=24877 width=8) (actual time=0.054..167.340 rows=24881 loops=1) Filter: ((month = 8) AND (year = 2007)) -> Hash (cost=142.68..142.68 rows=2816 width=23) (actual time=41.954..41.954 rows=2816 loops=1) -> Seq Scan on reseller b (cost=0.00..142.68 rows=2816 width=23) (actual time=0.035..28.447 rows=2816 loops=1) Filter: (asp = 6)Total runtime:464.337 ms Have you advices to optimize the query please ? Stan 2007/9/14, hubert depesz lubaczewski <depesz@depesz.com>: > On Fri, Sep 14, 2007 at 03:02:59PM +0200, Stanislas de Larocque wrote: > > I want to optimize my query sql (execution time : 2665 ms) : > SELECT > b.idxreseller, > sum(a.nbrq), > b.namereseller > from > stat a, > reseller b > where > b.asp=6 > and a.idxreseller=b.reseller > and a.month=date_part('month',now() - interval '1 month') > and a.year=date_part('year',now() - interval '1 month') > GROUP BY > b.idxreseller,b.namereseller limit 15; > > 1. cast all date_parts to int4, like in: > a.month = cast( date_part('month',now() - interval '1 month') as int4) > 2. why there is a limit without any order by? > 3. change it to get namereseller from subselect, not from join. > > depesz > > -- > quicksil1er: "postgres is excellent, but like any DB it requires a > highly paid DBA. here's my CV!" :) > http://www.depesz.com/ - blog dla ciebie (i moje CV) > -- Stanislas de Larocque dllstan@gmail.com 06 63 64 00 47
On Mon, Sep 17, 2007 at 09:17:58AM +0200, Stanislas de Larocque wrote: > Have you advices to optimize the query please ? for some many rows the 400ms looks quite reasonable. the best thing you can make to speed things up is to calculate the counts with triggers. depesz -- quicksil1er: "postgres is excellent, but like any DB it requires a highly paid DBA. here's my CV!" :) http://www.depesz.com/ - blog dla ciebie (i moje CV)