473,394 Members | 1,706 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,394 software developers and data experts.

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 br*****@oit.gatech.edu
---------------------------(end of broadcast)---------------------------
TIP 9: the planner will ignore your desire to choose an index scan if your
joining column's datatypes do not match

Nov 22 '05 #1
9 1259
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
-----------------------------------------------------------------
---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddressHere" to ma*******@postgresql.org)

Nov 22 '05 #2
Brandon Craig Rhodes <br*****@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

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddressHere" to ma*******@postgresql.org)

Nov 22 '05 #3
On Feb 25, 2004, at 8:02 PM, Tom Lane wrote:
Brandon Craig Rhodes <br*****@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
ma*******@postgresql.org)

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddressHere" to ma*******@postgresql.org)

Nov 22 '05 #4
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
---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

Nov 22 '05 #5
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
---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?

http://www.postgresql.org/docs/faqs/FAQ.html

Nov 22 '05 #6
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

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddressHere" to ma*******@postgresql.org)

Nov 22 '05 #7
Joe Conway <ma**@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
---------------------------(end of broadcast)---------------------------
TIP 3: if posting/reading through Usenet, please send an appropriate
subscribe-nomail command to ma*******@postgresql.org so that your
message can get through to the mailing list cleanly

Nov 22 '05 #8
On Feb 26, 2004, at 3:10 PM, Greg Stark wrote:
Joe Conway <ma**@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
---------------------------(end of broadcast)---------------------------
TIP 4: Don't 'kill -9' the postmaster

Nov 22 '05 #9
Greg Stark <gs*****@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

---------------------------(end of broadcast)---------------------------
TIP 3: if posting/reading through Usenet, please send an appropriate
subscribe-nomail command to ma*******@postgresql.org so that your
message can get through to the mailing list cleanly

Nov 22 '05 #10

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

2
by: grigoo | last post by:
bonjour a tous je me presente a vous::: greg dit le grigoo sur le web ,,etudiant en bioinformatique a montreal et jusqu au cou dans notre language prefere....java. et biojava.. et je suis en un...
36
by: Riccardo Rossi | last post by:
Hi all! How does Python pass arguments to a function? By value or by reference? Thanks, Riccardo Rossi.
14
by: Cartel | last post by:
Hello, I wish to modify the dimension of the font within a given table (that is, not yet in the whole page); when I hit a button, the font's size increases by 1 point; another button decreases it...
1
by: puneet.bansal | last post by:
Hi, I have a frameset and in one of the frames I have two functions. This code resides in a frame named leftFrame - //This function downloads an Excel report function downloadExcelReport() {...
12
by: Edmund Dengler | last post by:
Hi folks! A query I am running does not seem to use indexes that are available (running version 7.4.2). I have the following table: => \d replicated Table "public.replicated" Column | ...
5
by: Silvio Matthes | last post by:
Hello, I'm new to the list and did not find a suitable answer to my question so here it is: I try to select the rows of a table where the content of a varchar-column is empty ('') and...
1
by: lists | last post by:
When using the (tbl).field notation for selecting a specific field from a composite field then the query returning the field is executed once per field. An example is giving below. The runtime is...
13
by: Kenneth Brody | last post by:
You Know You've Been Reading clc Too Long When... You switch to another Usenet group, see a thread with the subject "bread", and think "but bread() isn't standard -- it's a FreeBSD extension". ...
1
by: vid6 | last post by:
Hi! Basically I'm creating a database in which i have 2 fields called "Product Code" and "Product Name" respectively in one table each with a number of entries. What i require is that in the...
0
by: Charles Arthur | last post by:
How do i turn on java script on a villaon, callus and itel keypad mobile phone
0
by: ryjfgjl | last post by:
If we have dozens or hundreds of excel to import into the database, if we use the excel import function provided by database editors such as navicat, it will be extremely tedious and time-consuming...
0
by: ryjfgjl | last post by:
In our work, we often receive Excel tables with data in the same format. If we want to analyze these data, it can be difficult to analyze them because the data is spread across multiple Excel files...
1
by: Sonnysonu | last post by:
This is the data of csv file 1 2 3 1 2 3 1 2 3 1 2 3 2 3 2 3 3 the lengths should be different i have to store the data by column-wise with in the specific length. suppose the i have to...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...
0
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows...
0
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.