Thread: Query analyse
Good morning!
First of all, my envoronment is:
Linux netlab142.prodam 2.4.8-26mdk #1 Sun Sep 23 17:06:39 CEST 2001 i686 unknown
pg_ctl (PostgreSQL) 7.2.1
pg_ctl (PostgreSQL) 7.2.1
I would like some suggestions on how to speed up a query.
Both of the queries below are identical except that one of them use the trunc function.
You can see that the TRUNC function rise hardly up the query response time in the second query.
That shouldn´t be happen. Only because a trunc function?
What can I be in that case?
What does it happen?
Sure, there are indexes:
CREATE INDEX idx_proposta_2 ON proposta USING btree (in_situacao_proposta);
CREATE INDEX idx_proposta_4 ON proposta USING btree (nr_proponente);
And pa.nr_proponente is fk and op.nr_proponte is pk.
These are the queries:
1o. That is ok.
DEBUG: query: select
pa.nr_projeto,
pa.dc_denom_projeto,
pa.nr_proponente,
pa.dc_coordenador,
op.dc_proponente
from proposta pa
inner join orgao_proponente op
on (pa.nr_proponente = op.nr_proponente)
where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC;
pa.nr_projeto,
pa.dc_denom_projeto,
pa.nr_proponente,
pa.dc_coordenador,
op.dc_proponente
from proposta pa
inner join orgao_proponente op
on (pa.nr_proponente = op.nr_proponente)
where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC;
DEBUG: QUERY STATISTICS
! system usage stats:
! 0.015904 elapsed 0.000000 user 0.020000 system sec
! [0.010000 user 0.020000 sys total]
! 0/0 [0/0] filesystem blocks in/out
! 143/42 [353/172] page faults/reclaims, 0 [0] swaps
! 0 [0] signals rcvd, 0/0 [0/0] messages rcvd/sent
! 0/0 [0/0] voluntary/involuntary context switches
! postgres usage stats:
! Shared blocks: 88 read, 0 written, buffer hit rate = 89.19
%
! Local blocks: 0 read, 0 written, buffer hit rate = 0.00%
! Direct blocks: 0 read, 0 written
2o. But I need to use the trunc function:
DEBUG: query: select
pa.nr_projeto,
pa.dc_denom_projeto,
pa.nr_proponente,
pa.dc_coordenador,
op.dc_proponente
from proposta pa
inner join orgao_proponente op
on (trunc(pa.nr_proponente/100000,0)*100000 = op.nr_proponente)
where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC;
pa.nr_projeto,
pa.dc_denom_projeto,
pa.nr_proponente,
pa.dc_coordenador,
op.dc_proponente
from proposta pa
inner join orgao_proponente op
on (trunc(pa.nr_proponente/100000,0)*100000 = op.nr_proponente)
where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC;
DEBUG: QUERY STATISTICS
! system usage stats:
! 104.665005 elapsed 10.090000 user 0.420000 system sec
! [10.100000 user 0.420000 sys total]
! 0/0 [0/0] filesystem blocks in/out
! 141/50 [352/180] page faults/reclaims, 0 [0] swaps
! 0 [0] signals rcvd, 0/0 [0/0] messages rcvd/sent
! 0/0 [0/0] voluntary/involuntary context switches
! postgres usage stats:
! Shared blocks: 7408 read, 0 written, buffer hit rate = 13.23
%
! Local blocks: 0 read, 0 written, buffer hit rate = 0.00%
! Direct blocks: 0 read, 0 written
On Fri, 25 Jul 2003, Elielson Fontanezi wrote: > First of all, my envoronment is: > Linux netlab142.prodam 2.4.8-26mdk #1 Sun Sep 23 17:06:39 CEST 2001 > i686 unknown > pg_ctl (PostgreSQL) 7.2.1 > > I would like some suggestions on how to speed up a query. > > Both of the queries below are identical except that one of them use the > trunc function. > > You can see that the TRUNC function rise hardly up the query response > time in the second query. > That shouldn�t be happen. Only because a trunc function? > > What can I be in that case? > What does it happen? What does explain show for the two queries and what are the table schemas? You're probably ending up with different plans since in one case it has a plain column reference and in the other it has a marginally complicated expression in the join condition. As something to try, perhaps make a function that returns trunc($1/100000.0)*100000 and index on that function for the column and see if that changes the plan you get.
The first query is able to use the index on nr_proponente, because the condition involves that column directly, the second query is not, because the index only contains the values of nt_proponente, not results of trunc(..)/.... Try replacing that condition with something like pa.nr_proponente BETWEEN op.nr_proponente AND op.nr_proponente + 0.00001 I hope, it helps... Dima Elielson Fontanezi wrote: > Good morning! > > First of all, my envoronment is: > Linux netlab142.prodam 2.4.8-26mdk #1 Sun Sep 23 17:06:39 CEST > 2001 i686 unknown > pg_ctl (PostgreSQL) 7.2.1 > > I would like some suggestions on how to speed up a query. > > Both of the queries below are identical except that one of them > use the *trunc* function. > > You can see that the TRUNC function rise hardly up the query > response time in the second query. > That shouldn´t be happen. Only because a trunc function? > > What can I be in that case? > What does it happen? > > Sure, there are indexes: > > CREATE INDEX idx_proposta_2 ON proposta USING btree > (in_situacao_proposta); > CREATE INDEX idx_proposta_4 ON proposta USING btree (nr_proponente); > > And pa.nr_proponente is fk and op.nr_proponte is pk. > > These are the queries: > > 1o. That is ok. > > DEBUG: query: select > pa.nr_projeto, > pa.dc_denom_projeto, > pa.nr_proponente, > pa.dc_coordenador, > op.dc_proponente > from proposta pa > inner join orgao_proponente op > on (pa.nr_proponente = op.nr_proponente) > where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC; > > DEBUG: QUERY STATISTICS > ! system usage stats: > ! 0.015904 elapsed 0.000000 user 0.020000 system sec > ! [0.010000 user 0.020000 sys total] > ! 0/0 [0/0] filesystem blocks in/out > ! 143/42 [353/172] page faults/reclaims, 0 [0] swaps > ! 0 [0] signals rcvd, 0/0 [0/0] messages rcvd/sent > ! 0/0 [0/0] voluntary/involuntary context switches > ! postgres usage stats: > ! Shared blocks: 88 read, 0 written, buffer hit > rate = 89.19 > % > ! Local blocks: 0 read, 0 written, buffer hit > rate = 0.00% > ! Direct blocks: 0 read, 0 written > 2o. But I need to use the trunc function: > > DEBUG: query: select > pa.nr_projeto, > pa.dc_denom_projeto, > pa.nr_proponente, > pa.dc_coordenador, > op.dc_proponente > from proposta pa > inner join orgao_proponente op > on (trunc(pa.nr_proponente/100000,0)*100000 = op.nr_proponente) > where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC; > > DEBUG: QUERY STATISTICS > ! system usage stats: > ! 104.665005 elapsed 10.090000 user 0.420000 system sec > ! [10.100000 user 0.420000 sys total] > ! 0/0 [0/0] filesystem blocks in/out > ! 141/50 [352/180] page faults/reclaims, 0 [0] swaps > ! 0 [0] signals rcvd, 0/0 [0/0] messages rcvd/sent > ! 0/0 [0/0] voluntary/involuntary context switches > ! postgres usage stats: > ! Shared blocks: 7408 read, 0 written, buffer hit > rate = 13.23 > % > ! Local blocks: 0 read, 0 written, buffer hit > rate = 0.00% > ! Direct blocks: 0 read, 0 written >
It would apear the second query does not use the index. ! Shared blocks: 88 read, 0 written, buffer hit rate = 89.19 vs ! Shared blocks: 7408 read, 0 written, buffer hit rate = 13.23 You could create a second index which is based upon a function that does the truncation... Incidentally you can add a second parameter to trunc() to truncate to a set number of decimal places, which would save some time instead of dividing and multiplying. ( http://www.postgresql.org/docs/7.3/static/functions-math.html ) -Ben. -----Original Message----- From: Elielson Fontanezi [mailto:ElielsonF@prodam.sp.gov.br] Sent: 25 July 2003 14:08 To: pgsql-sql; pgsql-general Subject: [GENERAL] Query analyse Good morning! First of all, my envoronment is: Linux netlab142.prodam 2.4.8-26mdk #1 Sun Sep 23 17:06:39 CEST 2001 i686 unknown pg_ctl (PostgreSQL) 7.2.1 I would like some suggestions on how to speed up a query. Both of the queries below are identical except that one of them use the trunc function. You can see that the TRUNC function rise hardly up the query response time in the second query. That shouldn´t be happen. Only because a trunc function? What can I be in that case? What does it happen? Sure, there are indexes: CREATE INDEX idx_proposta_2 ON proposta USING btree (in_situacao_proposta); CREATE INDEX idx_proposta_4 ON proposta USING btree (nr_proponente); And pa.nr_proponente is fk and op.nr_proponte is pk. These are the queries: 1o. That is ok. DEBUG: query: select pa.nr_projeto, pa.dc_denom_projeto, pa.nr_proponente, pa.dc_coordenador, op.dc_proponente from proposta pa inner join orgao_proponente op on (pa.nr_proponente = op.nr_proponente) where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC; DEBUG: QUERY STATISTICS ! system usage stats: ! 0.015904 elapsed 0.000000 user 0.020000 system sec ! [0.010000 user 0.020000 sys total] ! 0/0 [0/0] filesystem blocks in/out ! 143/42 [353/172] page faults/reclaims, 0 [0] swaps ! 0 [0] signals rcvd, 0/0 [0/0] messages rcvd/sent ! 0/0 [0/0] voluntary/involuntary context switches ! postgres usage stats: ! Shared blocks: 88 read, 0 written, buffer hit rate = 89.19 % ! Local blocks: 0 read, 0 written, buffer hit rate = 0.00% ! Direct blocks: 0 read, 0 written 2o. But I need to use the trunc function: DEBUG: query: select pa.nr_projeto, pa.dc_denom_projeto, pa.nr_proponente, pa.dc_coordenador, op.dc_proponente from proposta pa inner join orgao_proponente op on (trunc(pa.nr_proponente/100000,0)*100000 = op.nr_proponente) where pa.in_situacao_proposta <> 'E' ORDER BY 1 DESC; DEBUG: QUERY STATISTICS ! system usage stats: ! 104.665005 elapsed 10.090000 user 0.420000 system sec ! [10.100000 user 0.420000 sys total] ! 0/0 [0/0] filesystem blocks in/out ! 141/50 [352/180] page faults/reclaims, 0 [0] swaps ! 0 [0] signals rcvd, 0/0 [0/0] messages rcvd/sent ! 0/0 [0/0] voluntary/involuntary context switches ! postgres usage stats: ! Shared blocks: 7408 read, 0 written, buffer hit rate = 13.23 % ! Local blocks: 0 read, 0 written, buffer hit rate = 0.00% ! Direct blocks: 0 read, 0 written
Stephan Szabo <sszabo@megazone.bigpanda.com> writes: > You're probably ending up with different plans since in one case it has > a plain column reference and in the other it has a marginally complicated > expression in the join condition. Yeah. 7.3 and before cannot do merge or hash joins on conditions that are any more complex than "var = var". The query with the trunc() is undoubtedly falling back to the stupidest kind of nestloop. > As something to try, perhaps make a function that returns > trunc($1/100000.0)*100000 and index on that function for the column and > see if that changes the plan you get. It might help --- you might possibly get a nestloop-with-inner-indexscan out of that. Not sure though, since the planner is likely to be using bad guesstimates about the selectivity of the expression. 7.4 should do better on this. regards, tom lane