Thread: partial indexes not used on parameterized queries?
Hi,<br /><br /> we are using postgresql 8.1.4 and found that partial indexes are <b>not</b> being used when the query isrun using parameters, eg. in a function. When running the same query with arguments passed in the query string partialindexes are being used.<br /><br /><b>here is the index:</b><br /><br /> CREATE INDEX c_6012_index ON consumption(voi) WHERE code = 6012 AND val1 IS NULL;<br /><br /><b>here is the query using parameters inside the query stringwhich uses an index scan in turn:</b><br /><br /> explain analyze UPDATE c SET val1=1784 WHERE code=6012 AND voi='1923328-8-0-0'AND val1 IS NULL;<br /> QUERY PLAN<br /> -------------------------------------------------------------------------------------------------------------------------------<br /> Index Scan using c_6012_index on c (cost=0.00..4.71 rows=1 width=164) (actual time=0.196..0.196 rows=0 loops=1)<br /> Index Cond: (voi = '1923328-8-0-0'::text)<br /> Filter: ((code = 6012) AND (val1 IS NULL))<br /> Total runtime:0.304 ms<br /> (4 rows)<br /><br /><br /><b>Now put it in a function with parameter passing we get a seq scan:</b><br/><br /><br /> CREATE FUNCTION setsize(integer, integer, text)<br /> RETURNS integer AS<br /> $BODY$<br />DECLARE<br /> v_size alias for $1;<br /> v_code alias for $2;<br /> v_voi alias for $3;<br/> r record;<br /> BEGIN<br /> FOR r IN<br /> EXPLAIN UPDATE c SET val1=v_size WHEREcode=v_code AND voi=v_voi AND val1 IS NULL LOOP<br /> RAISE NOTICE '%', r;<br /> END LOOP;<br /> RETURN 0;<br /> END;<br /><br /> # select setsize(1784, 6012, '1923328-8-0-0');<br /> NOTICE: ("Seq Scan on c (cost=0.00..344372.82rows=1 width=164)")<br /> NOTICE: (" Filter: ((code = $2) AND (voi = $3) AND (val1 IS NULL))")<br/> setsize<br /> ---------<br /> 0<br /> (1 row)<br /><br /><br /> Bummer, a sequential scan is beingrun.<br /><br /> Any clues? Has this behaviour changed for a while?<br /><br /> Regards,<br /><br /> Dirk<br /><br /><br/>
On Mon, 2006-07-10 at 12:22 +0200, Dirk Lutzeb=C3=A4ck wrote: > we are using postgresql 8.1.4 and found that partial indexes are not > being used when the query is run using parameters, eg. in a function. > When running the same query with arguments passed in the query string > partial indexes are being used. > Any clues? Has this behaviour changed for a while? No, it's always worked like this. The index can only be used if we know at plan time that the index predicate is true for all times that the query is executed. We cannot know this for the exact query and index combination you have requested. If we acted differently, your query would return the wrong answer in some circumstances. I can't find anything in the manual that explains this distinction. Here's an example that explains this more easily: If your index looked like this CREATE INDEX c_6000_index ON consumption (voi)=20 WHERE=20 code > 5000 AND val1 IS NULL; and your query like this UPDATE c=20 SET val1=3D1784=20 WHERE=20 ( code > 6000 AND val1 IS NULL ) AND code =3D ?=20 AND voi =3D '1923328-8-0-0'; ...then the index could be used, because the index predicate is implied by part of the query clause for all values of the parameter. So its best to look for some other static definition of the index. I'll submit a doc patch. --=20 Simon Riggs EnterpriseDB http://www.enterprisedb.com
Hi Simon,<br /><br /> are you sure this has not been changed? I'm pretty sure my code worked a while ago. We are using PerlDBD::Pg on the client side and almost never pass parameters inside the SQL string for security reasons. I can't say ifit broke from 8.0 -> 8.1 for us or in one of the minor 8.1 releases.<br /><br /> In any case I would see this as a securityproblem because you cannot control sql code injection easily (as with using DBD::Pg) if you have to pass parametersin the SQL string to use partial indexes.<br /><br /> Regards,<br /><br /> Dirk<br /><br /> Simon Riggs wrote:<blockquote cite="mid1152530366.2518.20.camel@localhost.localdomain" type="cite"><pre wrap="">On Mon, 2006-07-10 at12:22 +0200, Dirk Lutzebäck wrote: </pre><blockquote type="cite"><pre wrap="">we are using postgresql 8.1.4 and found that partial indexes are not being used when the query is run using parameters, eg. in a function. When running the same query with arguments passed in the query string partial indexes are being used. </pre></blockquote><pre wrap=""> </pre><blockquote type="cite"><pre wrap="">Any clues?Has this behaviour changed for a while? </pre></blockquote><pre wrap=""> No, it's always worked like this. The index can only be used if we know at plan time that the index predicate is true for all times that the query is executed. We cannot know this for the exact query and index combination you have requested. If we acted differently, your query would return the wrong answer in some circumstances. I can't find anything in the manual that explains this distinction. Here's an example that explains this more easily: If your index looked like this CREATE INDEX c_6000_index ON consumption (voi) WHERE code > 5000 AND val1 IS NULL; and your query like this UPDATE c SET val1=1784 WHERE ( code > 6000 AND val1 IS NULL ) AND code = ? AND voi = '1923328-8-0-0'; ...then the index could be used, because the index predicate is implied by part of the query clause for all values of the parameter. So its best to look for some other static definition of the index. I'll submit a doc patch. </pre></blockquote><br /><div class="moz-signature">-- <br /><small><i>This email and any files transmitted with it areconfidential and intended solely for the use of the individual or entity to whom they are addressed. If you are not theintended recipient, you should not copy it, re-transmit it, use it or disclose its contents, but should return it to thesender immediately and delete your copy from your system. Thank you for your cooperation.</i></small><p><b>Dirk Lutzebäck</b><a class="moz-txt-link-rfc2396E" href="mailto:lutzeb@aeccom.com"><lutzeb@aeccom.com></a> Tel +49.30.5362.1635Fax .1638<br /> CTO <a href="http://www.aeccom.com">AEC/communications GmbH</a>, Berlin, Germany </div>
On Mon, 2006-07-10 at 13:35 +0200, Dirk Lutzeb=C3=A4ck wrote: > In any case I would see this as a security problem because you cannot > control sql code injection easily (as with using DBD::Pg) if you have > to pass parameters in the SQL string to use partial indexes. That's not what I said. I see no security problem as a result of this behaviour. --=20 Simon Riggs EnterpriseDB http://www.enterprisedb.com
Ok, we checked our client code to eliminate this problem. Thanks for the doc patch.<br /><br /> Regards,<br /><br /> Dirk<br/><br /> Simon Riggs wrote: <blockquote cite="mid1152534578.2518.32.camel@localhost.localdomain" type="cite"><prewrap="">On Mon, 2006-07-10 at 13:35 +0200, Dirk Lutzebäck wrote: </pre><blockquote type="cite"><pre wrap="">In any case I would see this as a security problem because you cannot control sql code injection easily (as with using DBD::Pg) if you have to pass parameters in the SQL string to use partial indexes. </pre></blockquote><pre wrap=""> That's not what I said. I see no security problem as a result of this behaviour. </pre></blockquote><br /><div class="moz-signature">-- <br /><small><i>This email and any files transmitted with it areconfidential and intended solely for the use of the individual or entity to whom they are addressed. If you are not theintended recipient, you should not copy it, re-transmit it, use it or disclose its contents, but should return it to thesender immediately and delete your copy from your system. Thank you for your cooperation.</i></small><p><b>Dirk Lutzebäck</b><a class="moz-txt-link-rfc2396E" href="mailto:lutzeb@aeccom.com"><lutzeb@aeccom.com></a> Tel +49.30.5362.1635Fax .1638<br /> CTO <a href="http://www.aeccom.com">AEC/communications GmbH</a>, Berlin, Germany </div>
Hi, On Mon, 10 Jul 2006, [UTF-8] Dirk Lutzeb=E4ck wrote: > Hi Simon, > > are you sure this has not been changed? I'm pretty sure my code worked a= =20 > while ago. We are using Perl DBD::Pg on the client side and almost never = pass=20 > parameters inside the SQL string for security reasons. I can't say if it= =20 > broke from 8.0 -> 8.1 for us or in one of the minor 8.1 releases. DBD::Pg only recently started preparing queries in the server. Older versions of DBD::Pg simulated prepared statements behind the scenes so your postgresql server got to plan every query individually. You might want to switch of server side prepares for your specific=20 query and see if that helps. See the description of the pg_server_prepare in the DBD::Pg manpage on how to go about this. > In any case I would see this as a security problem because you cannot con= trol=20 > sql code injection easily (as with using DBD::Pg) if you have to pass=20 > parameters in the SQL string to use partial indexes. I hope you are not relying on prepared statements as your only defense against sql code injection. Greetings Christian --=20 Christian Kratzer ck@cksoft.de CK Software GmbH http://www.cksoft.de/ Phone: +49 7452 889 135 Fax: +49 7452 889 136