Thread: Stored procedures and "pseudo" fields..

Stored procedures and "pseudo" fields..

From
Lars Erik Thorsplass
Date:
I have recently ventured into the exciting world of stored procedures,
but I have now become lost.

Background:

Am currently working on access control in a web application. My goal
is to process access control on the SQL level. This way if a row is in
the result set, you have access to it, if not, you dont.


Problem:

My stored procedure "acl_check()" takes two integers as parameters.
Param1 is the object id to check acl on, Param 2 is the object id of
the user currently using the system. The procedure returns a positive
numer (1 or 3 ) if you have some kind of access to the object. As one
might understand I want the returned value from the acl_check()
procedure to be a part of the result set.

Kinda like this:

SELECT *, acl_check( objects.obid, <user_id> ) AS mode FROM objects
WHERE mode > 0;

This gives me a: ERROR:  column "mode" does not exist

If I remove the "mode > 0" logic, I get a resultset with mode in it as
expected. Why cant I do logic tests with the mode "field" ?


I tried a diffrent approach with a diffrent error:

SELECT * FROM objects, acl_check( objects.obid, 32 ) as mode WHERE mode > 0;

This gives me a: ERROR:  function expression in FROM may not refer to
other relations of same query level.

Here objecs.obid is unknown i suppose, but if I enter "10" as the
first param using the mode "field" in a logic statement works.



I would appreciate any hints to a workaround which would enable me to
accomplish my scenario.


Best regards,


L.E.Thorsplass

Re: Stored procedures and "pseudo" fields..

From
"Scott Marlowe"
Date:
On Tue, 2004-07-20 at 04:43, Lars Erik Thorsplass wrote:
> I have recently ventured into the exciting world of stored procedures,
> but I have now become lost.
>
> Background:
>
> Am currently working on access control in a web application. My goal
> is to process access control on the SQL level. This way if a row is in
> the result set, you have access to it, if not, you dont.
>
>
> Problem:
>
> My stored procedure "acl_check()" takes two integers as parameters.
> Param1 is the object id to check acl on, Param 2 is the object id of
> the user currently using the system. The procedure returns a positive
> numer (1 or 3 ) if you have some kind of access to the object. As one
> might understand I want the returned value from the acl_check()
> procedure to be a part of the result set.
>
> Kinda like this:
>
> SELECT *, acl_check( objects.obid, <user_id> ) AS mode FROM objects
> WHERE mode > 0;

Here's the problem. In order to do the select, the query first needs to
run the where clause.  I.e.:

select a as test from table where a > 50;

works, but

select a as test from table where test > 50;

fails.  The reason is that when the where clause fires first, there IS
no test yet, as it hasn't been materialized.  what you need to do is:

select custom_function(a,b) from table where custom_function(a,b) > 0;