Thread: need help to write a function in postgresql

need help to write a function in postgresql

From
"Madhu.Lanka"
Date:

Hi Friends

 

Can u please help to write a function for the following scenario?

 

I have 3 table’s user_roles, principals and roles.

I have to write a function in postgresql which should excepts 2 parameters (name, password)

With those 2 parameters the query should be executed and return the result.(Result of the query will be 1 or more rows).

The query is working fine if executed it manually by hardcoding the values for name and password, but is as to be written in function so that I can send different values.

 

“select u.role_id,u.user_id,p.name,p.creation_date,p.telephone_number,p.email,p.remarks,p.city,p.state,p.country,p.postal_address,p.company_name,p.department_name,p.contact_person,

p.role_group,p.role_description,p.first_name,p.last_name,p.pincode,p.status,p.department_id,p.designation_id,r.role_name,r.right_edit,r.right_filter,r.right_search,r.right_browse,

r.right_print, r.right_download,r.right_admin_user,r.right_image_creator,r.right_vector_download,r.right_wps,r.right_queries_filter,r.right_google_map,r.right_user_management,

r.right_route_analysis, r.right_legend,r.right_treeview,r.insert,r.update,r.delete,r.query,r.lock from user_roles u,.principals p,roles r where p.PRINCIPAL_ID = u.USER_ID and

r.role_id = u.role_id and p.name=? and p.password=?

 

 

Thanks in Advance.

 

Regards

Madhu.Lanka

Re: need help to write a function in postgresql

From
Thomas Kellerer
Date:
Madhu.Lanka, 19.07.2012 11:14:
> Hi Friends
>
> Can u please help to write a function for the following scenario?
>
> I have 3 table’s user_roles, principals and roles.
>
> I have to write a function in postgresql which should excepts 2 parameters (name, password)
>
> With those 2 parameters the query should be executed and return the result.(Result of the query will be 1 or more
rows).
>
> The query is working fine if executed it manually by hardcoding the values for name and password, but is as to be
writtenin function so that I can send different values. 
>
> “select
u.role_id,u.user_id,p.name,p.creation_date,p.telephone_number,p.email,p.remarks,p.city,p.state,p.country,p.postal_address,p.company_name,p.department_name,p.contact_person,
>
>
p.role_group,p.role_description,p.first_name,p.last_name,p.pincode,p.status,p.department_id,p.designation_id,r.role_name,r.right_edit,r.right_filter,r.right_search,r.right_browse,
>
> r.right_print,
r.right_download,r.right_admin_user,r.right_image_creator,r.right_vector_download,r.right_wps,r.right_queries_filter,r.right_google_map,r.right_user_management,
>
> r.right_route_analysis, r.right_legend,r.right_treeview,r.insert,r.update,r.delete,r.query,r.lock from user_roles
u,.principalsp,roles r where p.PRINCIPAL_ID = u.USER_ID and 
>
> r.role_id = u.role_id and p.name=? and p.password=?”
>

Something like this:

     create or replace function retrieve_user(uname text, pwd text)
       returns table (role_id integer, user_id integer, name text, .... more columns ...)
     as
     $$
     SELECT u.role_id,
            u.user_id,
            p.name,
            p.creation_date,
            p.telephone_number,
            .... more columns ...
     FROM user_roles u,
          principals p,
          roles r
     WHERE p.principal_id = u.user_id
     AND   r.role_id = u.role_id
     AND   p.name = $1
     AND   p.password = $2
     $$
     language SQL;


Then you can do:

     select *
     from retrieve_user('foo', 'bar');

Personally I'd prefer to create view that wraps that select statement and then simply do a

    select *
    from user_view
    where name = 'foo'
    and password = 'bar'

Regards
Thomas



Re: need help to write a function in postgresql

From
"Albe Laurenz"
Date:
Madhu.Lanka wrote:
> Can u please help to write a function for the following scenario?

> "select [...] from [...] where [...] and p.name=? and p.password=?"

Don't use "?" for the parameters.
Use "$1" for the first parameter and "$2" for the second.

Yours,
Laurenz Albe

Re: need help to write a function in postgresql

From
Laszlo Nagy
Date:
> Then you can do:
>         select *
>     from retrieve_user('foo', 'bar');
>
> Personally I'd prefer to create view that wraps that select statement
> and then simply do a
>
>    select *
>    from user_view
>    where name = 'foo'
>    and password = 'bar'
It is also better because with a view, you can also do " name is null ".
But you cannot do that with a function (unless you write unnecessary
circumstancial code.)

Re: need help to write a function in postgresql

From
Craig Ringer
Date:
On 08/03/2012 04:37 PM, Laszlo Nagy wrote:
> It is also better because with a view, you can also do " name is null
> ". But you cannot do that with a function (unless you write
> unnecessary circumstancial code.)
>
While I agree with you on the view - among other things, it lets the
query optimiser push conditions down into the view query - there is a
reasonable answer to the problem of comparing to NULL. Just use IS
DISTINCT FROM, eg:

    WHERE name IS DISTINCT FROM _test_variable

"IS DISTINCT FROM" is an equality comparison that treats null as a
comparable value like any other, so "NULL IS DISTINCT FROM NULL" is
false. Very handy.

--
Craig Ringer