[SQL] Optimize querry sql
Hi, I want to optimize my qerry sql (execution time : 2448 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; dns=> \d stat_dns_domaine; Table «public.stat_dns_domaine» idxdxreseller | integer | not null idxdo | integer | not null idxd | integer | not null nbrq | integer | default 0 month | 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_idxrevendeur» btree (idxrevendeur) «stat_dns_domaine_idx_mois_annee_idxrev» btree (mois, annee, idxrevendeur) \d revendeur limit 20; Table «public.revendeur» idxreseller| integer | not null default nextval(('idxrevendeur_seq'::text)::regclass) namereseller | text| asp | integer | Index : «reseller_pkey» PRIMARY KEY, btree (idxreseller) Thank you STan ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
[SQL] Optimize querry sql
Hi, I want to optimize my qerry sql (execution time : 2448 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; dns=> \d stat_dns_domaine; Table «public.stat» idxdxreseller | integer | not null idxdo | integer | not null idxd | integer | not null nbrq | integer | default 0 month | 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_idxrevendeur» btree (idxrevendeur) «stat_dns_domaine_idx_mois_annee_idxrev» btree (mois, annee, idxrevendeur) \d revendeur; Table «public.reseller» idxreseller| integer | not null default nextval(('idxrevendeur_seq'::text)::regclass) namereseller | text| asp | integer | Index : «reseller_pkey» PRIMARY KEY, btree (idxreseller) Thank you Stan ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
Re: [SQL] Optimize querry sql
am Fri, dem 14.09.2007, um 10:31:39 +0200 mailte Stanislas de Larocque folgendes: > Hi, > > I want to optimize my qerry sql (execution time : 2448 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; Show us the output from EXLAIN ANALYSE . My guess: you need at least an index in reseller.asp. Why do you have columns such a.month and a.year? se a regular DATE or TIMESTAMPTZ field instead and an index on this. And use CURRENT_DATE instead now(). Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net ---(end of broadcast)--- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match
Re: [SQL] Optimize querry sql
Hi, Explain my sql querry : Limit (cost=1057.15..1057.16 rows=1 width=27) -> HashAggregate (cost=1057.15..1057.16 rows=1 width=27) -> Nested Loop (cost=0.00..1057.14 rows=1 width=27) -> Seq Scan on stat a (cost=0.00..1042.98 rows=1 width=8) 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 resaller_pkey on revendeur b (cost=0.00..14.15 rows=1 width=23) Index Cond: ("outer".idxresaller = b.idxresaller) Filter: (asp = 6) I would optimize "Seq Scan on stat a (cost=0.00..1042.98 rows=1 width=8)" What is your advice ? Thank you Stan 2007/9/14, A. Kretschmer <[EMAIL PROTECTED]>: > am Fri, dem 14.09.2007, um 10:31:39 +0200 mailte Stanislas de Larocque > folgendes: > > Hi, > > > > I want to optimize my qerry sql (execution time : 2448 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; > > Show us the output from EXLAIN ANALYSE . > > My guess: you need at least an index in reseller.asp. Why do you have > columns such a.month and a.year? se a regular DATE or TIMESTAMPTZ field > instead and an index on this. > And use CURRENT_DATE instead now(). > > Andreas > -- > Andreas Kretschmer > Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) > GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net > > ---(end of broadcast)--- > TIP 9: In versions below 8.0, the planner will ignore your desire to >choose an index scan if your joining column's datatypes do not >match > ---(end of broadcast)--- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match
Re: [SQL] Optimize querry sql
am Fri, dem 14.09.2007, um 12:26:00 +0200 mailte Stanislas de Larocque folgendes: > Hi, > > Explain my sql querry : > > Limit (cost=1057.15..1057.16 rows=1 width=27) >-> HashAggregate (cost=1057.15..1057.16 rows=1 width=27) > -> Nested Loop (cost=0.00..1057.14 rows=1 width=27) >-> Seq Scan on stat a (cost=0.00..1042.98 rows=1 width=8) > 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 resaller_pkey on revendeur b > (cost=0.00..14.15 rows=1 width=23) > Index Cond: ("outer".idxresaller = b.idxresaller) > Filter: (asp = 6) > > I would optimize "Seq Scan on stat a (cost=0.00..1042.98 rows=1 width=8)" > > What is your advice ? Create indexes on the columns month and year. But, again, you have an unpractical table-design. > > Thank you > > Stan > > > 2007/9/14, A. Kretschmer <[EMAIL PROTECTED]>: Please no top-posting. (answer on top and fullquote below) Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net ---(end of broadcast)--- TIP 6: explain analyze is your friend
Re: [SQL] Optimize querry sql
On Fri, Sep 14, 2007 at 12:26:00PM +0200, Stanislas de Larocque wrote: > Explain my sql querry : did you notice, that andreas asked: > > Show us the output from EXLAIN ANALYSE . 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) ---(end of broadcast)--- TIP 1: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly
[SQL] 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) Total runtime: 2655.713 ms dns=> \d stat; Table «public.stat» idxreseller | integer | not null idxdo | integer | not null idxd | integer | not null nbrq | integer | default 0 month | 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 ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
Re: [SQL] Optimize querry sql
On 9/14/07, A. Kretschmer <[EMAIL PROTECTED]> wrote: > And use CURRENT_DATE instead now(). Out of curiosity, why the advice to switch from now() to CURRENT_DATE? ---(end of broadcast)--- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match
Re: [SQL] Optimize querry sql
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) ---(end of broadcast)--- TIP 3: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faq
Re: [SQL] Optimize querry sql
am Fri, dem 14.09.2007, um 8:36:47 -0500 mailte Scott Marlowe folgendes: > On 9/14/07, A. Kretschmer <[EMAIL PROTECTED]> wrote: > > > And use CURRENT_DATE instead now(). > > Out of curiosity, why the advice to switch from now() to CURRENT_DATE? Mhh, don't know... Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net ---(end of broadcast)--- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match
Re: [SQL] Optimize querry sql
On 9/14/07, A. Kretschmer <[EMAIL PROTECTED]> wrote: > am Fri, dem 14.09.2007, um 8:36:47 -0500 mailte Scott Marlowe folgendes: > > On 9/14/07, A. Kretschmer <[EMAIL PROTECTED]> wrote: > > > > > And use CURRENT_DATE instead now(). > > > > Out of curiosity, why the advice to switch from now() to CURRENT_DATE? > > Mhh, don't know... OK, I was just afraid there was some "bad thing" TM that I wasn't aware of with now(), which, btw, I use all the time. whew. ---(end of broadcast)--- TIP 6: explain analyze is your friend