[postgis-users] Problem with syntax in function

Obe, Regina robe.dnd at cityofboston.gov
Tue May 22 17:07:42 PDT 2007


I noticed that you have to build up the constant parameter sql because I think the bbox cast operators require a cstring.  I'm not quite sure why unknown can be cast to cstring but text can't.
 
I think you could still do the same thing using an SQL function if you use the GeomFromText function which accepts variable strings - downside you have to explode bbox to a polygon notation.
 
So your function using SQL function would look something like (my order of exploding may be wrong)
 
CREATE OR REPLACE FUNCTION
myschema.sel_by_pos2(varchar, varchar, varchar, varchar)
RETURNS SETOF myschema.mytable AS
$BODY$
       select * from myschema.mytable where (geom_column
 && GeomFromText('POLYGON((' || $1 || ' ' || $2 || ', ' || $1 || ' ' || $4 || ', ' || $3 || ' ' || $4 || ', ' ||  $3 || ' ' || $4 || ', ' || $1 || ' ' || $2 || '))', 26591));
$BODY$ 
LANGUAGE 'sql' VOLATILE;

 
Thanks,
Regina

 
________________________________

From: postgis-users-bounces at postgis.refractions.net on behalf of Mark Cave-Ayland
Sent: Tue 5/22/2007 6:02 PM
To: PostGIS Users Discussion
Subject: RE: [postgis-users] Problem with syntax in function



On Tue, 2007-05-22 at 23:20 +0200, Ludovico Bianchini wrote:
> I'm using PostgreSQL 8.1. Trying this
>
> CREATE OR REPLACE FUNCTION
> myschema.sel_by_pos(varchar, varchar, varchar,
>  varchar)
>    RETURNS SETOF myschema.mytable AS
>  $BODY$
>   select * from myschema.mytable where (geom_column
>  &&
>  SetSRID('BOX3D(' || $1 || ' ' || $2 || ', ' || $3 ||
>  ' ' || $4 || ')'::box3d, 26591))
>   $BODY$> LANGUAGE 'sql' VOLATILE;
>
> I get: ERROR:  BOX3D parser - doesnt start with BOX3D(
> CONTEXT:  SQL function "sel_by_pos"
>
> I'm in very trouble with this behaviour...


Hi Ludovico,

Because you are building up a parameter using string operators, you need
to generate the SQL statement as a string and then execute it. So you'll
need to use PL/PGSQL rather than just SQL, e.g. something like:


CREATE OR REPLACE FUNCTION
myschema.sel_by_pos(varchar, varchar, varchar, varchar)
RETURNS SETOF myschema.mytable AS
$$
DECLARE
        str text;
    rec record;
BEGIN
        str := 'select * from myschema.mytable where (geom_column
 && SetSRID(''BOX3D(' || $1 || ' ' || $2 || ', ' || $3 ||
 ' ' || $4 || ')''::box3d, 26591))';
       
    -- For debugging only
        raise notice 'str is: %', str;

    for rec in execute str loop
        return next rec;
    end loop;

END
$$ LANGUAGE 'plpgsql' VOLATILE;


Kind regards,

Mark.

--
ILande - Open Source Consultancy
http://www.ilande.co.uk <http://www.ilande.co.uk/> 


_______________________________________________
postgis-users mailing list
postgis-users at postgis.refractions.net
http://postgis.refractions.net/mailman/listinfo/postgis-users




-----------------------------------------
The substance of this message, including any attachments, may be
confidential, legally privileged and/or exempt from disclosure
pursuant to Massachusetts law. It is intended
solely for the addressee. If you received this in error, please
contact the sender and delete the material from any computer.
-------------- next part --------------
An HTML attachment was scrubbed...
URL: <http://lists.osgeo.org/pipermail/postgis-users/attachments/20070522/b0dd76c9/attachment.html>


More information about the postgis-users mailing list