Thread: Improving SQL performance
Hi,
I know that the problem with the following SQL is the "LOG.CODCEP = ENDE.CODCEP||CODLOG" condition, but what can I
do to improve the performance?
do to improve the performance?
Is there a type of index that could help or is there another way to build this SQL?
Thank you in advance!
explain analyze
SELECT ENDE.* , DEND.DESEND, DEND.USOEND, DEND.DUPEND,
to_char('F') as NOVO,
LOG.TIPLOG
FROM TT_END ENDE LEFT OUTER JOIN TD_END DEND ON DEND.CODTAB = ENDE.TIPEND
LEFT OUTER JOIN TT_LOG LOG ON LOG.CODCEP = ENDE.CODCEP||CODLOG
WHERE ENDE.FILCLI = '001'
AND ENDE.CODCLI = ' 19475';
SELECT ENDE.* , DEND.DESEND, DEND.USOEND, DEND.DUPEND,
to_char('F') as NOVO,
LOG.TIPLOG
FROM TT_END ENDE LEFT OUTER JOIN TD_END DEND ON DEND.CODTAB = ENDE.TIPEND
LEFT OUTER JOIN TT_LOG LOG ON LOG.CODCEP = ENDE.CODCEP||CODLOG
WHERE ENDE.FILCLI = '001'
AND ENDE.CODCLI = ' 19475';
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------
Nested Loop Left Join (cost=0.00..25366.84 rows=1259 width=417) (actual time=1901.499..1901.529 rows=1 loops=1)
Join Filter: (("inner".codcep)::text = (("outer".codcep)::text || ("outer".codlog)::text))
-> Nested Loop Left Join (cost=0.00..4.91 rows=1 width=412) (actual time=0.117..0.144 rows=1 loops=1)
Join Filter: ("inner".codtab = "outer".tipend)
-> Index Scan using pk_end on tt_end ende (cost=0.00..3.87 rows=1 width=388) (actual time=0.066..0.078 rows=1 loops=1)
Index Cond: ((filcli = '001'::bpchar) AND (codcli = ' 19475'::bpchar))
-> Seq Scan on td_end dend (cost=0.00..1.02 rows=2 width=33) (actual time=0.012..0.018 rows=2 loops=1)
-> Seq Scan on tt_log log (cost=0.00..12254.24 rows=582424 width=17) (actual time=0.013..582.521 rows=582424 loops=1)
Total runtime: 1901.769 ms
(9 rows)
\d tt_log
Table "TOTALL.tt_log"
Column | Type | Modifiers
--------+------------------------+-----------
codbai | numeric(5,0) | not null
nomlog | character varying(55) | not null
codcep | character(8) | not null
Table "TOTALL.tt_log"
Column | Type | Modifiers
--------+------------------------+-----------
codbai | numeric(5,0) | not null
nomlog | character varying(55) | not null
codcep | character(8) | not null
\d tt_end
Table "TOTALL.tt_end"
Column | Type | Modifiers
--------+-----------------------+-----------------------------------------
...
...
...
codlog | character(3) |
...
...
...
codcep | character(5) |
...
...
Table "TOTALL.tt_end"
Column | Type | Modifiers
--------+-----------------------+-----------------------------------------
...
...
...
codlog | character(3) |
...
...
...
codcep | character(5) |
...
...
Reimer
Carlos H. Reimer wrote: > Hi, > > I know that the problem with the following SQL is the "LOG.CODCEP = > ENDE.CODCEP||CODLOG" condition, but what can I > do to improve the performance? > I wouldn't say it's the join condition. There is a nested loop join on 500k+ rows. Is it possible to put an index on LOG.CODCEP? That might give you a better plan, as you only have 1 row in the left of the join. so index scan would be preferable. Regards Russell Smith > Is there a type of index that could help or is there another way to > build this SQL? > > Thank you in advance! > > explain analyze > SELECT ENDE.* , DEND.DESEND, DEND.USOEND, DEND.DUPEND, > to_char('F') as NOVO, > LOG.TIPLOG > FROM TT_END ENDE LEFT OUTER JOIN TD_END DEND ON DEND.CODTAB > = ENDE.TIPEND > LEFT OUTER JOIN TT_LOG LOG ON LOG.CODCEP = > ENDE.CODCEP||CODLOG > WHERE ENDE.FILCLI = '001' > AND ENDE.CODCLI = ' 19475'; > > > QUERY > PLAN > ---------------------------------------------------------------------------------------------------------------------------------- > Nested Loop Left Join (cost=0.00..25366.84 rows=1259 width=417) > (actual time=1901.499..1901.529 rows=1 loops=1) > Join Filter: (("inner".codcep)::text = (("outer".codcep)::text || > ("outer".codlog)::text)) > -> Nested Loop Left Join (cost=0.00..4.91 rows=1 width=412) > (actual time=0.117..0.144 rows=1 loops=1) > Join Filter: ("inner".codtab = "outer".tipend) > -> Index Scan using pk_end on tt_end ende (cost=0.00..3.87 > rows=1 width=388) (actual time=0.066..0.078 rows=1 loops=1) > Index Cond: ((filcli = '001'::bpchar) AND (codcli = ' > 19475'::bpchar)) > -> Seq Scan on td_end dend (cost=0.00..1.02 rows=2 > width=33) (actual time=0.012..0.018 rows=2 loops=1) > -> Seq Scan on tt_log log (cost=0.00..12254.24 rows=582424 > width=17) (actual time=0.013..582.521 rows=582424 loops=1) > Total runtime: 1901.769 ms > (9 rows) > > \d tt_log > Table "TOTALL.tt_log" > Column | Type | Modifiers > --------+------------------------+----------- > codbai | numeric(5,0) | not null > nomlog | character varying(55) | not null > codcep | character(8) | not null > > \d tt_end > Table "TOTALL.tt_end" > Column | Type | Modifiers > --------+-----------------------+----------------------------------------- > ... > ... > ... > codlog | character(3) | > ... > ... > ... > codcep | character(5) | > ... > ... > > Reimer > >
"Carlos H. Reimer" <carlos.reimer@opendb.com.br> writes: > I know that the problem with the following SQL is the "LOG.CODCEP = > ENDE.CODCEP||CODLOG" condition, but what can I > do to improve the performance? Seems the problem is not using an index for tt_log. Do you have an index on tt_log.codcep? If so, maybe you need to cast the result of the concatenation to char(8) to get it to use the index. regards, tom lane
Yes, I do have an index on tt_log.codcep. Indexes I´ve on both tables: tt_end Indexes: "pk_end" PRIMARY KEY, btree (filcli, codcli, codfil, numend) "ak_end_numdoc" UNIQUE, btree (numdoc) "i_fk_end_darc" btree (codarc, tiparc) "i_fk_end_dend" btree (tipend) "i_fk_end_dfil" btree (codfil) "i_fk_end_dreg" btree (regiao) "i_fk_end_mun" btree (codcid) tt_log Indexes: "i_fk_log_bai" btree (codbai) "i_lc_log_codcep" btree (codcep) Any clue? Thanks! Reimer > -----Mensagem original----- > De: Tom Lane [mailto:tgl@sss.pgh.pa.us] > Enviada em: quinta-feira, 11 de janeiro de 2007 16:31 > Para: carlos.reimer@opendb.com.br > Cc: pgsql-performance@postgresql.org > Assunto: Re: [PERFORM] Improving SQL performance > > > "Carlos H. Reimer" <carlos.reimer@opendb.com.br> writes: > > I know that the problem with the following SQL is the "LOG.CODCEP = > > ENDE.CODCEP||CODLOG" condition, but what can I > > do to improve the performance? > > Seems the problem is not using an index for tt_log. Do you have an > index on tt_log.codcep? If so, maybe you need to cast the result of > the concatenation to char(8) to get it to use the index. > > regards, tom lane > >
Hi, Carlos, Wouldn't it be better if you used INT in 'codcep' in both tables (as CEP/ZIP numbers are [0-9]{8})? Casting as Tom Lane suggested is also a good alternative, yet I think it'd be much better if you used int in both columns. Regards, Cesar Let's see the query: SELECT ENDE.* , DEND.DESEND, DEND.USOEND, DEND.DUPEND, to_char('F') as NOVO, LOG.TIPLOG FROM TT_END ENDE LEFT OUTER JOIN TD_END DEND ON DEND.CODTAB = ENDE.TIPEND LEFT OUTER JOIN TT_LOG LOG ON LOG.CODCEP = ENDE.CODCEP||CODLOG WHERE ENDE.FILCLI = '001' AND ENDE.CODCLI = ' 19475'; Carlos H. Reimer wrote: > Yes, I do have an index on tt_log.codcep. > > Indexes I´ve on both tables: > > tt_end > Indexes: > "pk_end" PRIMARY KEY, btree (filcli, codcli, codfil, numend) > "ak_end_numdoc" UNIQUE, btree (numdoc) > "i_fk_end_darc" btree (codarc, tiparc) > "i_fk_end_dend" btree (tipend) > "i_fk_end_dfil" btree (codfil) > "i_fk_end_dreg" btree (regiao) > "i_fk_end_mun" btree (codcid) > tt_log > Indexes: > "i_fk_log_bai" btree (codbai) > "i_lc_log_codcep" btree (codcep) > > Any clue? > > Thanks! > > Reimer > > > >> -----Mensagem original----- >> De: Tom Lane [mailto:tgl@sss.pgh.pa.us] >> Enviada em: quinta-feira, 11 de janeiro de 2007 16:31 >> Para: carlos.reimer@opendb.com.br >> Cc: pgsql-performance@postgresql.org >> Assunto: Re: [PERFORM] Improving SQL performance >> >> >> "Carlos H. Reimer" <carlos.reimer@opendb.com.br> writes: >> >>> I know that the problem with the following SQL is the "LOG.CODCEP = >>> ENDE.CODCEP||CODLOG" condition, but what can I >>> do to improve the performance? >>> >> Seems the problem is not using an index for tt_log. Do you have an >> index on tt_log.codcep? If so, maybe you need to cast the result of >> the concatenation to char(8) to get it to use the index. >> >> regards, tom lane >> >> >> > > > ---------------------------(end of broadcast)--------------------------- > TIP 6: explain analyze is your friend > >
Yes, casting the result improved the time response a lot. Thank you! Reimer > -----Mensagem original----- > De: pgsql-performance-owner@postgresql.org > [mailto:pgsql-performance-owner@postgresql.org]Em nome de Tom Lane > Enviada em: quinta-feira, 11 de janeiro de 2007 16:31 > Para: carlos.reimer@opendb.com.br > Cc: pgsql-performance@postgresql.org > Assunto: Re: [PERFORM] Improving SQL performance > > > "Carlos H. Reimer" <carlos.reimer@opendb.com.br> writes: > > I know that the problem with the following SQL is the "LOG.CODCEP = > > ENDE.CODCEP||CODLOG" condition, but what can I > > do to improve the performance? > > Seems the problem is not using an index for tt_log. Do you have an > index on tt_log.codcep? If so, maybe you need to cast the result of > the concatenation to char(8) to get it to use the index. > > regards, tom lane > > ---------------------------(end of broadcast)--------------------------- > TIP 4: Have you searched our list archives? > > http://archives.postgresql.org > >