Thread: Stored procedures and "pseudo" fields..
I also posted this to the general list, which might not have been a suitable forum. -- 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 don't. 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 number (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 result set with mode in it as expected. Why cant I do logic tests with the mode "field" ? I tried a different approach with a different 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
On 2004-07-20 15:34, Użytkownik Lars Erik Thorsplass napisał: > 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 > number (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 You can't access column output alias in where clause. Instead you have to use your function twice: SELECT *, acl_check( objects.obid, <user_id> ) AS mode FROM objects WHERE acl_check( objects.obid, <user_id> ) > 0; Regards, Tomasz Myrta
В Втр, 20.07.2004, в 15:57, Tomasz Myrta пишет: > On 2004-07-20 15:34, Użytkownik Lars Erik Thorsplass napisał: > > 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 > > number (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 > > You can't access column output alias in where clause. Instead you have > to use your function twice: > > SELECT *, acl_check( objects.obid, <user_id> ) AS mode FROM objects > WHERE acl_check( objects.obid, <user_id> ) > 0; and if you properly marked the function STABLE and I am not mistaken, then PostgreSQL is smart enough to execute the function only once per row. -- Markus Bertheau <twanger@bluetwanger.de>