Thread: key = currval('tab_key_seq') choses SEQSCAN?!
I have a large table (named "changes") which is perfectly willing to support index lookups when its primary key (named "change") is compared to a constant integer: # explain select * from changes where change = 42; QUERY PLAN ----------------------------------------------------------------------------- Index Scan using changes_pkey on changes (cost=0.00..3.01 rows=1 width=78) Index Cond: (change = 42) (2 rows) But this same table suddenly becomes unwilling to use an index scan if the target value is the result of the currval() function: # explain select * from changes where change = currval('changes_change_seq'); QUERY PLAN ---------------------------------------------------------- Seq Scan on changes (cost=0.00..323.21 rows=1 width=78) Filter: (change = currval('changes_change_seq'::text)) (2 rows) Explicitly casting the result of currval() to an integer (of any size) does not seem improve the situation. Is my expectation unreasonable that the planner should consider the result of an INTEGER CAST in the same way it considers a literal integer? -- Brandon Craig Rhodes http://www.rhodesmill.org/brandon Georgia Tech brandon@oit.gatech.edu
El Mié 25 Feb 2004 18:52, Brandon Craig Rhodes escribió: > > But this same table suddenly becomes unwilling to use an index scan if > the target value is the result of the currval() function: > > # explain select * from changes where change = > currval('changes_change_seq'); QUERY PLAN Try with this: explain select * from changes where change = (SELECT currval('changes_change_seq'))::INT; -- 19:06:01 up 92 days, 1:15, 3 users, load average: 0.72, 0.37, 0.24 ----------------------------------------------------------------- Martín Marqués | select 'mmarques' || '@' || 'unl.edu.ar' Centro de Telematica | DBA, Programador, Administrador Universidad Nacional del Litoral -----------------------------------------------------------------
Brandon Craig Rhodes <brandon@oit.gatech.edu> writes: > But this same table suddenly becomes unwilling to use an index scan if > the target value is the result of the currval() function: currval() is considered a volatile function, therefore it is unsafe to use in an indexscan constraint. The subselect hack mentioned nearby fools the planner ... at the moment. I wouldn't guarantee that it will work indefinitely. A better solution is to wrap currval() in a function that you lyingly claim is stable. regards, tom lane
On Feb 25, 2004, at 8:02 PM, Tom Lane wrote: > Brandon Craig Rhodes <brandon@oit.gatech.edu> writes: >> But this same table suddenly becomes unwilling to use an index scan if >> the target value is the result of the currval() function: > > currval() is considered a volatile function, therefore it is unsafe to > use in an indexscan constraint. I suppose this is obvious, but it's volatile because *other* backends can change it while the current transaction is still in progress? eric > > The subselect hack mentioned nearby fools the planner ... at the > moment. > I wouldn't guarantee that it will work indefinitely. A better solution > is to wrap currval() in a function that you lyingly claim is stable. > > regards, tom lane > > ---------------------------(end of > broadcast)--------------------------- > TIP 2: you can get off all lists at once with the unregister command > (send "unregister YourEmailAddressHere" to > majordomo@postgresql.org)
Eric B.Ridge wrote: > I suppose this is obvious, but it's volatile because *other* backends > can change it while the current transaction is still in progress? No. Other backends don't affect currval, but your own might on a row-by-row basis. Consider: regression=# create sequence seq; CREATE SEQUENCE regression=# select nextval('seq'), currval('seq'), s from generate_series(1,4) as t(s); nextval | currval | s ---------+---------+--- 1 | 1 | 1 2 | 2 | 2 3 | 3 | 3 4 | 4 | 4 (4 rows) Joe
On Feb 25, 2004, at 9:07 PM, Joe Conway wrote: > Eric B.Ridge wrote: >> I suppose this is obvious, but it's volatile because *other* backends >> can change it while the current transaction is still in progress? > > No. Other backends don't affect currval, but your own might on a > row-by-row basis. Consider: gotcha. Stated differently, it's not volatile because, by design, it doesn't always produce the same output for the same input. > regression=# select nextval('seq'), currval('seq'), s from > generate_series(1,4) as t(s); OT: generate_series looks useful. Is this only in 7.5? eric
Eric B. Ridge wrote: > gotcha. Stated differently, it's not volatile because, by design, it > doesn't always produce the same output for the same input. Right. But further, it doesn't even produce the same result within a single scan. Here's from pg_proc.h: /* * Symbolic values for provolatile column: these indicate whether the * result of a function is dependent *only* on the values of its * explicit arguments, or can change due to outside factors (such as * parameter variables or table contents). NOTE: functions having * side-effects, such as setval(), must be labeled volatile to ensure * they will not get optimized away, even if the actual return value is * not changeable. */ #define PROVOLATILE_IMMUTABLE 'i' /* never changes for given input */ #define PROVOLATILE_STABLE 's' /* does not change within a scan */ #define PROVOLATILE_VOLATILE 'v' /* can change even within a scan */ > OT: generate_series looks useful. Is this only in 7.5? Yes, new in 7.5. Joe
Joe Conway <mail@joeconway.com> writes: > Eric B. Ridge wrote: > > gotcha. Stated differently, it's not volatile because, by design, it doesn't > > always produce the same output for the same input. > > Right. But further, it doesn't even produce the same result within a single > scan. Here's from pg_proc.h: Consider a query like select * from foo where a = currval('xyz') and b = nextval('xyz') in that case it wouldn't be legitimate to use an index lookup on "a". Imagine if currval('xyz')==3 at the start and there are multiple records where a=3. Then it would return records where b = 3,4,5,... as long as a=3, which doesn't really make sense. Though actually I don't really see how any interpretation of this query really makes a whole lot of sense. -- greg
On Feb 26, 2004, at 3:10 PM, Greg Stark wrote: > Joe Conway <mail@joeconway.com> writes: > >> Eric B. Ridge wrote: >>> gotcha. Stated differently, it's not volatile because, by design, >>> it doesn't >>> always produce the same output for the same input. >> >> Right. But further, it doesn't even produce the same result within a >> single >> scan. Here's from pg_proc.h: > > Consider a query like > > select * from foo where a = currval('xyz') and b = nextval('xyz') yeah, it never even occurred to me, until Joe Conway's comment yesterday, that one could (or even would!) use nextval() and currval() together in the same statement. eric
Greg Stark <gsstark@mit.edu> writes: > Consider a query like > select * from foo where a = currval('xyz') and b = nextval('xyz') > ... > Though actually I don't really see how any interpretation of this > query really makes a whole lot of sense. Yeah. The only moderately credible use-case I've ever seen for volatile functions in WHERE clauses is select * from foo where random() < 0.01; which gets you a random sampling of approximately 1% of the table. regards, tom lane