Thread: PL/PGSQL Record type question

PL/PGSQL Record type question

From
Gábriel Ákos
Date:
Hi,

How should I define a record type (there is no table with this record
type) programmatically in pl/pgsql?
I'd like to return a record with 3 string elements, 2 integers and 1
date.

Rgds,
Akos



--
Üdvözlettel,
Gábriel Ákos
-=E-Mail :akos.gabriel@i-logic.hu|Web:  http://www.i-logic.hu =-
-=Tel/fax:+3612367353            |Mobil:+36209278894          =-


Re: PL/PGSQL Record type question

From
imad
Date:
You might be looking for PostgreSQL RECORD data type.

--Imad
www.EnterpriseDB.com

On 5/11/07, Gábriel Ákos <akos.gabriel@i-logic.hu> wrote:
> Hi,
>
> How should I define a record type (there is no table with this record
> type) programmatically in pl/pgsql?
> I'd like to return a record with 3 string elements, 2 integers and 1
> date.
>
> Rgds,
> Akos
>
>
>
> --
> Üdvözlettel,
> Gábriel Ákos
> -=E-Mail :akos.gabriel@i-logic.hu|Web:  http://www.i-logic.hu =-
> -=Tel/fax:+3612367353            |Mobil:+36209278894          =-
>
> ---------------------------(end of broadcast)---------------------------
> TIP 2: Don't 'kill -9' the postmaster
>


Re: PL/PGSQL Record type question

From
Gábriel Ákos
Date:
On Fri, 11 May 2007 19:09:07 +0500
imad <immaad@gmail.com> wrote:

> You might be looking for PostgreSQL RECORD data type.

Thanks. Give me an example please. I saw the documentation already.

>
> --Imad
> www.EnterpriseDB.com
>
> On 5/11/07, Gábriel Ákos <akos.gabriel@i-logic.hu> wrote:
> > Hi,
> >
> > How should I define a record type (there is no table with this
> > record type) programmatically in pl/pgsql?
> > I'd like to return a record with 3 string elements, 2 integers and 1
> > date.



--
Üdvözlettel,
Gábriel Ákos
-=E-Mail :akos.gabriel@i-logic.hu|Web:  http://www.i-logic.hu =-
-=Tel/fax:+3612367353            |Mobil:+36209278894          =-


Re: PL/PGSQL Record type question

From
John DeSoi
Date:
You can use CREATE TYPE:

http://www.postgresql.org/docs/8.2/interactive/sql-createtype.html

Example from the documentation:

CREATE TYPE compfoo AS (f1 int, f2 text);


Then make your function return compfoo (or setof compfoo).
Alternately, you can define your function with out or in/out
parameters so you don't need the CREATE TYPE statement.




On May 11, 2007, at 10:42 AM, Gábriel Ákos wrote:

>> You might be looking for PostgreSQL RECORD data type.
>
> Thanks. Give me an example please. I saw the documentation already.



John DeSoi, Ph.D.
http://pgedit.com/
Power Tools for PostgreSQL



Re: PL/PGSQL Record type question

From
imad
Date:
create a function with return type as a RECORD.

CREATE FUNCTION xyz() RETURNS record AS
$$declare abc RECORD;begin abc := (1, 2); return abc;end;
$$
language plpgsql;

And execute the function in this fashion:

select a, b from xyz() as (a int, b int);

Do you like that ...  :-)

--Imad
www.EnterpriseDB.com


On 5/11/07, Gábriel Ákos <akos.gabriel@i-logic.hu> wrote:
> On Fri, 11 May 2007 19:09:07 +0500
> imad <immaad@gmail.com> wrote:
>
> > You might be looking for PostgreSQL RECORD data type.
>
> Thanks. Give me an example please. I saw the documentation already.
>
> >
> > --Imad
> > www.EnterpriseDB.com
> >
> > On 5/11/07, Gábriel Ákos <akos.gabriel@i-logic.hu> wrote:
> > > Hi,
> > >
> > > How should I define a record type (there is no table with this
> > > record type) programmatically in pl/pgsql?
> > > I'd like to return a record with 3 string elements, 2 integers and 1
> > > date.
>
>
>
> --
> Üdvözlettel,
> Gábriel Ákos
> -=E-Mail :akos.gabriel@i-logic.hu|Web:  http://www.i-logic.hu =-
> -=Tel/fax:+3612367353            |Mobil:+36209278894          =-
>
> ---------------------------(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
>


Re: PL/PGSQL Record type question

From
Robins
Date:
Hi Gabriel,

There are two ways to do this:
1. Imad's way (Define the function with the return type as RECORD). Its only problem is that while querying from this function, you need to give a proper SELECT query or else PG returns an error.

e.g.  As Imad gives in his example ...

CREATE FUNCTION xyz() RETURNS record AS
$$
 declare
 abc RECORD;
 begin
 abc := (1, 2);
 return abc;
 end;
$$
language plpgsql;

And execute the function in this fashion:

select a, b from xyz() as (a int, b int);

The only problem with this is that if you have 6 elements your select statement becomes quite long. Also, in case your function return parameter count changes, or its types change, you would need to change the SELECT SQL at all the places.

2. Define a TYPE as John mentioned, and set the function's return type as this TYPE. The advantage is that you can always redefine the function and the type in case the return parameters are changing and that your select statement is a simple SELECT * from fn().

Personally, I have tried both and believe the second way (TYPE) is quite convenient for me.

Regards,
Robins Tharakan

On 5/11/07, Gábriel Ákos <akos.gabriel@i-logic.hu> wrote:
Hi,

How should I define a record type (there is no table with this record
type) programmatically in pl/pgsql?
I'd like to return a record with 3 string elements, 2 integers and 1
date.

Rgds,
Akos



--
Üdvözlettel,
Gábriel Ákos
-=E-Mail :akos.gabriel@i-logic.hu|Web:  http://www.i-logic.hu =-
-=Tel/fax:+3612367353            |Mobil:+36209278894          =-

---------------------------(end of broadcast)---------------------------
TIP 2: Don't 'kill -9' the postmaster



--
Robins

Re: PL/PGSQL Record type question

From
imad
Date:
On 5/11/07, Robins <tharakan@gmail.com> wrote:
> Hi Gabriel,
>
> There are two ways to do this:
> 1. Imad's way (Define the function with the return type as RECORD). Its only
> problem is that while querying from this function, you need to give a proper
> SELECT query or else PG returns an error.

Yeah ... valid point.

>
> e.g.  As Imad gives in his example ...
>
> CREATE FUNCTION xyz() RETURNS record AS
> $$
>  declare
>   abc RECORD;
>  begin
>   abc := (1, 2);
>   return abc;
>  end;
>  $$
> language plpgsql;
>
> And execute the function in this fashion:
>
> select a, b from xyz() as (a int, b int);
>
> The only problem with this is that if you have 6 elements your select
> statement becomes quite long. Also, in case your function return parameter
> count changes, or its types change, you would need to change the SELECT SQL
> at all the places.
>
> 2. Define a TYPE as John mentioned, and set the function's return type as
> this TYPE. The advantage is that you can always redefine the function and
> the type in case the return parameters are changing and that your select
> statement is a simple SELECT * from fn().

The drawback is that you need to know the complete definition in
advance. In contrast, you can assign any type of row to a RECORD
variable ... much more flexible.


--Imad
www.EnterpriseDB.com