From: | Stephan Szabo <sszabo(at)megazone(dot)bigpanda(dot)com> |
---|---|
To: | Kumar <sgnerd(at)yahoo(dot)com(dot)sg> |
Cc: | psql <pgsql-sql(at)postgresql(dot)org> |
Subject: | Re: Return more than a record |
Date: | 2004-02-26 15:29:27 |
Message-ID: | 20040226071613.Y54753@megazone.bigpanda.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
On Thu, 26 Feb 2004, Kumar wrote:
> Get the following from the groups
> create or replace function ExpensiveDepartments() returns setof table1 as
Note that at least the example with this name in the SetReturningFunctions
guide seems to use setof int as the return type.
> '
> declare
> r table1%rowtype;
> begin
> for r in select departmentid, sum(salary) as totalsalary
> from GetEmployees() group by departmentid loop
>
> if (r.totalsalary > 70000) then
> r.totalsalary := CAST(r.totalsalary * 1.75 as int8);
> else
> r.totalsalary := CAST(r.totalsalary * 1.5 as int8);
> end if;
>
> if (r.totalsalary > 100000) then
> return next r.departmentid;
> end if;
>
> end loop;
> return;
> end
> '
> language 'plpgsql';
> Is possible for me to return a variable along with that 'return' statement? Because the table 'table1' contains some date
> column. I have done some calculation on those columns and want to return the calculated date along with that row of the
> table1. How to do that. Please shed some light.
If you want to return a composite type, you can make another rowtype
variable that has the set of columns (and their types) to return, fill in
the values to return and then do return next with that variable.
For example, to say return departmentid, sum(salary) and the computed
"totalsalary" from the above, you might do something like (untested so
there might be syntactic errors)
create type holder as (departmentid int, totalsalary int8);
create type holder2 as (departmentid int, sumsalary int8, totalsalary
int8);
create or replace function ExpensiveDepartments() returns setof holder2 as
'
declare
r holder%rowtype;
s holder2%rowtype;
begin
for r in select departmentid, sum(salary) as totalsalary
from GetEmployees() group by departmentid loop
s.departmentid := r.departmentid;
s.sumsalary := r.totalsalary;
if (r.totalsalary > 70000) then
s.totalsalary := CAST(r.totalsalary * 1.75 as int8);
else
s.totalsalary := CAST(r.totalsalary * 1.5 as int8);
end if;
if (s.totalsalary > 100000) then
return next s;
end if;
end loop;
return;
end
'
language 'plpgsql';
The important differences here are that we've got a new rowtype variable s
of the return type and that we fill s with the values from r (the select)
plus the calculation that we're doing (rather than before where we just
overwrote the values in r.totalsalary) and then we return next s rather
than a particular field.
From | Date | Subject | |
---|---|---|---|
Next Message | Leo Leo | 2004-02-26 15:58:28 | a few Questions about quoted varaibles in psql |
Previous Message | Bruno Wolff III | 2004-02-26 15:26:08 | Re: Scalar in a range (but textual not numeric) |