From: | Mike Rylander <mrylander(at)gmail(dot)com> |
---|---|
To: | Richard Rowell <richard(at)bowmansystems(dot)com> |
Cc: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: Recursive SETOF function |
Date: | 2004-11-22 16:54:30 |
Message-ID: | b918cf3d041122085437cde2f1@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
I'm feeling sausey today, so here is my (untested) attempt to
translate your function. It's inline below, and you'll want to look
here http://www.postgresql.org/docs/7.4/interactive/plpgsql.html for
more information.
On Mon, 22 Nov 2004 09:18:13 -0600, Richard Rowell
<richard(at)bowmansystems(dot)com> wrote:
> I'm trying to port some TSQL to PLPGSQL. The DB has a table with a
> recursive foreign key that represents a tree hierarchy. I'm trying to
> re-create a TSQL function that pulls out all the ancestors of a given
> node in the hierarchy.
>
> I'm rather new to PLSQL and I have several questions.
>
> 1. In TSQL, I can assign a scalar to the result of query like so:
> SET @var1 = (SELECT foo FROM bar WHERE bar(dot)uid=(at)var2)
>
> How would I do this in PLSQL?
>
> 2. In TSQL the "result table" can be inserted into manually. IE:
>
> CREATE FUNCTION foo () RETURNS @ttable TABLE( uid INTEGER) AS BEGIN
> INSERT @ttable VALUES (1)
> RETURN
> END
>
> Is there a way to manually insert rows into the result table in PLSQL?
>
> What follows is my TSQL function if that helps give context.
>
> CREATE FUNCTION svp_getparentproviderids (@child_provider INTEGER)
> RETURNS @provider_ids TABLE ( uid INTEGER )
> AS
> BEGIN
> DECLARE @cid AS INTEGER
> IF (SELECT count(*) FROM providers WHERE uid =(at)child_provider) > 0
> BEGIN
> SET @cid = @child_provider
> WHILE @cid IS NOT NULL
> BEGIN
> INSERT @provider_ids VALUES (@cid)
> SET @cid = (SELECT parent_id FROM providers WHERE uid=(at)cid)
> END
> END
> RETURN
> END
>
-- This TYPE will get you a named column... easier to use SRFs with a
preexisting type.
CREATE TYPE svp_getparentproviderids_uid_type AS ( uid INTEGER );
CREATE FUNCTION svp_getparentproviderids (INTEGER)
RETURNS SETOF svp_getparentproviderids_uid_type
AS '
DECLARE
child_provider ALIAS FOR $1;
cid INTEGER;
BEGIN
SELECT count(*) FROM providers WHERE uid =(at)child_provider) > 0
LOOP
cid := child_provider
IF cid IS NULL THEN
EXIT;
END IF;
RETURN NEXT cid;
SELECT INTO cid parent_id FROM providers WHERE uid=(at)cid;
END LOOP;
RETURN
END;' LANGUAGE 'plpgsql';
Hope that helps!
> --
>
> ---------------------------(end of broadcast)---------------------------
> TIP 3: if posting/reading through Usenet, please send an appropriate
> subscribe-nomail command to majordomo(at)postgresql(dot)org so that your
> message can get through to the mailing list cleanly
>
--
Mike Rylander
mrylander(at)gmail(dot)com
GPLS -- PINES Development
Database Developer
From | Date | Subject | |
---|---|---|---|
Next Message | Mike Rylander | 2004-11-22 16:56:31 | Re: Recursive SETOF function |
Previous Message | Passynkov, Vadim | 2004-11-22 16:43:44 | Missing SELECT INTO ... DEFAULT VALUES in plpgsql for composite t ypes |