473,382 Members | 1,717 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,382 software developers and data experts.

error querying temp table in plpgsql function

(PostgreSQL 8.0 beta 4 on Mac OS X 10.3.6)

I'm working on a function which creates and populates a temporary
table, then returns the number of records it has inserted. I'm getting
an error, though, after successive invocations of the function (I can
call it once successfully, but on the next call I get an error). I've
been able to reproduce the error with the following sample function:

create or replace function test() returns integer as
$$
declare result integer;
begin

-- drop temp table, if it exists (ignore exception if it doesn't)
begin
execute 'drop table test';
exception
when undefined_table then
null; -- do nothing
end;

-- create the vehicle route table
execute 'create temp table test ('
|| 'seq_num serial not null, '
|| 'foo text'
|| ')';

select count(*) into result from test;

return result;

end;
$$
language 'plpgsql';

Here is a clipping of a psql session which creates the function and
calls it twice, along with the error that results:

silo=# \i test.sql
CREATE FUNCTION
silo=# select test();
NOTICE: CREATE TABLE will create implicit sequence "test_seq_num_seq"
for serial column "test.seq_num"
CONTEXT: SQL statement "create temp table test (seq_num serial not
null, foo text)"
PL/pgSQL function "test" line 13 at execute statement
test
------
0
(1 row)

silo=# select test();
NOTICE: CREATE TABLE will create implicit sequence "test_seq_num_seq"
for serial column "test.seq_num"
CONTEXT: SQL statement "create temp table test (seq_num serial not
null, foo text)"
PL/pgSQL function "test" line 13 at execute statement
ERROR: relation with OID 524907 does not exist
CONTEXT: SQL statement "SELECT count(*) from test"
PL/pgSQL function "test" line 18 at select into variables
silo=#

If, instead of executing the "select count(*)" directly, I use the
EXECUTE command, then everything works. Is this expected behavior?

Thanks,
Tim
---------------------------(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 23 '05 #1
1 6553
Timothy Perrigo wrote:
(PostgreSQL 8.0 beta 4 on Mac OS X 10.3.6)

I'm working on a function which creates and populates a temporary table,
then returns the number of records it has inserted. I'm getting an
error, though, after successive invocations of the function (I can call
it once successfully, but on the next call I get an error). I've been
able to reproduce the error with the following sample function: select count(*) into result from test; If, instead of executing the "select count(*)" directly, I use the
EXECUTE command, then everything works. Is this expected behavior?


Yes - the reference to table "test" will be compiled down to it's OID.
When you re-create the test table it will have a new OID and so you get
an error.

As you say, you need to use EXECUTE in cases like this with plpgsql. An
interpreted language (pltcl/plperl) should be OK in situations like
this, though at the cost of parsing the query each time the function is
called.

--
Richard Huxton
Archonet Ltd

---------------------------(end of broadcast)---------------------------
TIP 1: subscribe and unsubscribe commands go to ma*******@postgresql.org

Nov 23 '05 #2

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

Similar topics

5
by: Thomas LeBlanc | last post by:
I copied an example from the help: CREATE FUNCTION somefunc() RETURNS integer AS ' DECLARE quantity integer := 30; BEGIN RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 30...
5
by: Oksana Yasynska | last post by:
Hi all, I'm running Postgres 7.2.1 and I need to return multiple row sets from plpgsql function. I'm new in plpgsql but according documentation and everything I could find in the mailing list...
20
by: ctyrrell | last post by:
Does anyone have any idea how to recover from a run-time error 3002 which I get after creating a workspace 242 times? Or better yet, avoid getting it in the first place? I am creating a...
0
by: Janning Vygen | last post by:
Hi, i have a question about how to handle postgresql constraint errors in the client app. I found some mails in the archive about it, too. But i have still so many questions about how to do it,...
5
by: Uwe C. Schroeder | last post by:
-----BEGIN PGP SIGNED MESSAGE----- Hash: SHA1 Hi, maybe my mind is stuck, but here's something strange. This is the classic "counter" thing, where you can't / won't use sequences....
1
by: Alexander Pucher | last post by:
Hi, struggling around with this for some time: How can I use a table name as a parameter in a PL/pgSQL function ?? I tried this but it didn't work... CREATE OR REPLACE FUNCTION...
5
by: Rahul B | last post by:
Hi, I have very little knowledge about creating Procedures/functions in DB2. When i tried to create the test function like CREATE FUNCTION GET_TEST (P_TEST_ID INTEGER, P_SEL_OR_SORT...
1
by: finizaini | last post by:
I'm receiving an "Object Expected" Error (Line:309, Char:0). I'm confused as to what is happening.Also, I can't run this code using other browser such as Fire Fox. Thispage only can view using IE....
7
vikas251074
by: vikas251074 | last post by:
I am getting error above in following code since few days giving tension day and night. How can I solve this? I am facing since Oct.25. in line no. 362 After doing a lot of homework, I am...
0
by: Faith0G | last post by:
I am starting a new it consulting business and it's been a while since I setup a new website. Is wordpress still the best web based software for hosting a 5 page website? The webpages will be...
0
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 3 Apr 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome former...
0
by: ryjfgjl | last post by:
In our work, we often need to import Excel data into databases (such as MySQL, SQL Server, Oracle) for data analysis and processing. Usually, we use database tools like Navicat or the Excel import...
0
by: aa123db | last post by:
Variable and constants Use var or let for variables and const fror constants. Var foo ='bar'; Let foo ='bar';const baz ='bar'; Functions function $name$ ($parameters$) { } ...
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...
0
by: emmanuelkatto | last post by:
Hi All, I am Emmanuel katto from Uganda. I want to ask what challenges you've faced while migrating a website to cloud. Please let me know. Thanks! Emmanuel
0
BarryA
by: BarryA | last post by:
What are the essential steps and strategies outlined in the Data Structures and Algorithms (DSA) roadmap for aspiring data scientists? How can individuals effectively utilize this roadmap to progress...
1
by: nemocccc | last post by:
hello, everyone, I want to develop a software for my android phone for daily needs, any suggestions?
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...

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.