Re: Parameterized Query

From: David G Johnston <david(dot)g(dot)johnston(at)gmail(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: Parameterized Query
Date: 2014-06-09 13:36:13
Message-ID: 1402320973871-5806502.post@n5.nabble.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

frankliu747 wrote
> I have a query that works on sql sql server or oracle that do a
> parameterized query, I would like to move this to postgreSQL but I'm just
> not sure how to get it done. This is the query
> select * from quest q
> left join ask a on q.ask_id=a.id
> where q.createtime>=:StartDate and q.createtime<=:EndDate
> and a.asktime>=:StartDate and asktime<=:EndDate
>
> i need to define parameters in the WHERE clause to build dynamic
> SELECT,like ":StartDate" may be repeat more than one time.
>
> This works great on SQL Server or oracle but not on postgreSQL. Any help
> would be appreciated.
>
> and i use sql server reporting service use odbc connect postgres 9.34

The main SQL executor does not support named parameters, though psql does
since it has its own pre-parse step before sending the query to the server.

The typical way of doing this in PostgreSQL is to create a table returning
function with as many arguments as you have parameters. Within the function
body you can reference the input arguments repeatedly.

CREATE FUNCTION do_query(startdate date, enddate date)
RETURNS TABLE (col1 text,col2 date)
AS $func$

SELECT col1, col2 FROM tbl WHERE (col2 BETWEEN startdate AND enddate) AND
(col3 BETWEEN startdate AND enddate);

$func$
LANGUAGE SQL
;

Note that you do not use any special prefix to refer to the arguments in the
query.

In the client you call the function, with, parameters, using the following
query:

SELECT col1,col2 FROM do_query(?,?);

The documentation on CREATE FUNCTION as well as both the SQL and pl/pgsql
languages will be of great assistance on this topic.

David J.

--
View this message in context: http://postgresql.1045698.n5.nabble.com/Parameterized-Query-tp5806470p5806502.html
Sent from the PostgreSQL - sql mailing list archive at Nabble.com.

Browse pgsql-sql by date

  From Date Subject
Next Message Bruce 2014-06-09 16:02:04 Problem with strange chars in text filed.
Previous Message bricklen 2014-05-29 22:00:05 Re: PGsql function timestamp issue