[SQL] PL/PGSQL - How to pass in variables?
Using PL/PGSQL, I am trying to create a procedure to display the count of rows in any single table of a database. The End-user would pass in a table name and the prodecure would display the table name with the row count. I am able to hardcode the variable for table and get the appropriate results from my count function (see below), but cannot pass in a variable and have the function work. Any suggesstions??? CREATE FUNCTION get_table_count(tablename text) RETURNS integer AS $$ DECLARE --tablename ALIAS FOR $1; rowcount INTEGER; BEGIN SELECT INTO rowcount count(*) FROM tablename; RETURN rowcount; END; $$ LANGUAGE 'plpgsql';
Re: [SQL] PL/PGSQL - How to pass in variables?
Hi Scott,
You'll have to execute dynamic SQL (see doc chapter "36.6.5. Executing
Dynamic Commands") for your function to work:
CREATE FUNCTION get_table_count(tablename text) RETURNS integer AS
$$
DECLARE
--tablename ALIAS FOR $1;
rowcount INTEGER;
BEGIN
execute 'SELECT count(*) FROM '||tablename into rowcount;
return rowcount;
END;
$$ LANGUAGE 'plpgsql';
select get_table_count('bar');
get_table_count
-
3
(1 row)
Cheers,
--
Jean-Paul Argudo
www.PostgreSQLFr.org
www.dalibo.com
---(end of broadcast)---
TIP 1: if posting/reading through Usenet, please send an appropriate
subscribe-nomail command to [EMAIL PROTECTED] so that your
message can get through to the mailing list cleanly
Re: [SQL] PL/PGSQL - How to pass in variables?
On 5/14/06, Scott Yohonn <[EMAIL PROTECTED]> wrote: Using PL/PGSQL, I am trying to create a procedure to display the count of rows in any single table of a database. The End-user would pass in a table name and the prodecure would display the table name with the row count. I am able to hardcode the variable for table and get the appropriate results from my count function (see below), but cannot pass in a variable and have the function work. Any suggesstions??? CREATE FUNCTION get_table_count(tablename text) RETURNS integer AS $$ DECLARE --tablename ALIAS FOR $1; rowcount INTEGER; BEGIN SELECT INTO rowcount count(*) FROM tablename; RETURN rowcount; END; $$ LANGUAGE 'plpgsql'; you can't do this because tablename is a variable not a table, you have to append the content of the variable in a string that can be EXECUTE'd EXECUTE 'SELECT count(*) FROM ' || tablename INTO rowcount; -- regards, Jaime Casanova "Programming today is a race between software engineers striving to build bigger and better idiot-proof programs and the universe trying to produce bigger and better idiots. So far, the universe is winning." Richard Cook ---(end of broadcast)--- TIP 4: Have you searched our list archives? http://archives.postgresql.org
Re: [SQL] PL/PGSQL - How to pass in variables?
Scott Yohonn wrote:
> Jean-Paul,
>
> Thanks! This did work. The output put the name of the function
> (get_table_count) as the header. How would I display the name of the table
> that I am requesting the row count of?
The only way I know is to alias the output in the query calling the
function, so:
select get_table_count('bar') as bar;
bar
-
3
(1 row)
I don't know any other way to do that...
Cheers,
--
Jean-Paul Argudo
www.PostgreSQLFr.org
www.dalibo.com
---(end of broadcast)---
TIP 9: In versions below 8.0, the planner will ignore your desire to
choose an index scan if your joining column's datatypes do not
match
