Problem with function returning a result set - Mailing list pgsql-sql

From Thomas Kellerer
Subject Problem with function returning a result set
Date
Msg-id hpk5kd$98o$1@dough.gmane.org
Whole thread Raw
Responses Re: Problem with function returning a result set  (Tom Lane <tgl@sss.pgh.pa.us>)
Re: Problem with function returning a result set  (Pavel Stehule <pavel.stehule@gmail.com>)
List pgsql-sql
Hi,

I'm playing around with functions returning result sets, and I have a problem with the following function:

-- Create sample data
CREATE TABLE employee (id integer, first_name varchar(50), last_name varchar(50));
INSERT INTO employee values (1, 'Arthur', 'Dent');
INSERT INTO employee values (2, 'Zaphod', 'Beeblebrox');
INSERT INTO employee values (3, 'Ford', 'Prefect');
COMMIT;

-- Create the function
CREATE OR REPLACE FUNCTION get_employees(name_pattern varchar)
RETURNS TABLE(id integer, full_name text)
AS
$$
BEGIN
  RETURN QUERY    SELECT id, first_name||' '||last_name    FROM employee    WHERE last_name LIKE name_pattern ||'%';
END
$$
LANGUAGE plpgsql;

COMMIT;

Now when I run:

SELECT *
FROM get_employees('D');

I get one row returned which is correct, but the ID column is null (but should be 1). It does not depend which row(s) I
selectthrough the procedure. I also tried to change the datatype of the returned id to int8 and an explicit cast in the
SELECTstatement, but to no avail.
 

When I define the function using SQL as a language (with the approriate changes), the ID column is returned correctly.

I'm using Postgres 8.4.3 on Windows XP
postgres=> select version();                           version
------------------------------------------------------------- PostgreSQL 8.4.3, compiled by Visual C++ build 1400,
32-bit
(1 row)

What am I missing?

Regards
Thomas



pgsql-sql by date:

Previous
From: Yeb Havinga
Date:
Subject: Re: Table Design for Hierarchical Data
Next
From: Tom Lane
Date:
Subject: Re: Problem with function returning a result set