Thread: Clarification on RLS policy
Hi Team,
We are presently using Postgresql:PostgreSQL 15.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (Red Hat 8.5.0-23), 64-bit
I have a scenario where
1.I need to enforce RLS policy on a table for Select by calling a Function
2.The function would return a character varying string which should be appended to the select as a filter.
Ex: Select * from employee would be appended with where 1=1;
3.When we try to implement it says the below error.
ERROR: invalid input syntax for type boolean: "1=1" CONTEXT: PL/pgSQL function function name(name,name) while casting return value to function's return type
4.It works fine on Oracle. Can you please suggest how to fix this issue?
Rg
Vydehi.
On 4/25/25 08:08, Vydehi Ganti wrote:
Hi Team,We are presently using Postgresql:PostgreSQL 15.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (Red Hat 8.5.0-23), 64-bitI have a scenario where1.I need to enforce RLS policy on a table for Select by calling a Function2.The function would return a character varying string which should be appended to the select as a filter.Ex: Select * from employee would be appended with where 1=1;3.When we try to implement it says the below error.ERROR: invalid input syntax for type boolean: "1=1" CONTEXT: PL/pgSQL function function name(name,name) while casting return value to function's return type4.It works fine on Oracle. Can you please suggest how to fix this issue?
Just show the output of
\d <your_table>
and particularly the Policies: section. Then also show the source of your function and anything else involved.
RgVydehi.
On Fri, Apr 25, 2025 at 9:09 AM Vydehi Ganti <rayudugs@gmail.com> wrote: > We are presently using Postgresql:PostgreSQL 15.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (Red Hat8.5.0-23), 64-bit > I have a scenario where > 1.I need to enforce RLS policy on a table for Select by calling a Function > 2.The function would return a character varying string which should be appended to the select as a filter. > Ex: Select * from employee would be appended with where 1=1; > 3.When we try to implement it says the below error. > ERROR: invalid input syntax for type boolean: "1=1" CONTEXT: PL/pgSQL function function name(name,name) while casting returnvalue to function's return type > 4.It works fine on Oracle. Can you please suggest how to fix this issue? In PostgreSQL, you won't have to resort to the 1=1 trick like on Oracle. // One RLS is active, it is an implicit DENY on all DML types. // So we must explicitly allow SELECTs, using a dummy `USING (true)` policy. // Note that we use ALL, and not just SELECT, because we used RESTRICTIVE // on the UPDATE policy (needs at last one PERMISSIVE policy) CREATE POLICY rls_pass_thru ON {} FOR ALL USING (true) (replace {} with a table name). --DD
On Fri, 2025-04-25 at 12:38 +0530, Vydehi Ganti wrote: > We are presently using Postgresql:PostgreSQL 15.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (Red Hat8.5.0-23), 64-bit > I have a scenario where > 1.I need to enforce RLS policy on a table for Select by calling a Function > 2.The function would return a character varying string which should be appended > to the select as a filter. > Ex: Select * from employee would be appended with where 1=1; > 3.When we try to implement it says the below error. > ERROR: invalid input syntax for type boolean: "1=1" CONTEXT: PL/pgSQL function function name(name,name) while castingreturn value to function's return type > 4.It works fine on Oracle. Can you please suggest how to fix this issue? You cannot add whole WHERE conditions to a query dynamically. The only way to fix that is to solve the problem differently. Since you didn't tell us details, we cannot tell you how. Yours, Laurenz Albe
On Fri, Apr 25, 2025 at 2:43 PM Laurenz Albe <laurenz.albe@cybertec.at> wrote: > On Fri, 2025-04-25 at 12:38 +0530, Vydehi Ganti wrote: > > We are presently using Postgresql:PostgreSQL 15.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (RedHat 8.5.0-23), 64-bit > > 2.The function would return a character varying string which should be appended > > to the select as a filter. > > You cannot add whole WHERE conditions to a query dynamically. > The only way to fix that is to solve the problem differently. > Since you didn't tell us details, we cannot tell you how. Laurenz is right. That's not how RLS works in PostgreSQL, unlike Oracle. In PostgreSQL, you must use a boolean SQL expression, often by calling a function. You don't simply return some SQL text that Oracle then "splices" into the SELECT. E.g., if you use custom ROLEs as an implementation detail for your security rules, your policy can be as simple as calling the pg_has_role() built-in function. FWIW. --DD CREATE POLICY ... USING (pg_has_role('SomeRole', 'MEMBER'))
This is my Scenario:
I would need a policy on table Activity which has a column country_code .
In the policy i would need to call a function get_country as below which queries the users table based on current user and checks which country code that user has access to.
Then it should build up the lPredicate with the filter condition and append to the query user runs on the Activity table.
Can you please guide how to achieve this?
CREATE OR REPLACE FUNCTION one.get_country(
powner name,
ptable_name name)
RETURNS character varying
LANGUAGE 'plpgsql'
COST 100
STABLE PARALLEL UNSAFE
AS $BODY$
DECLARE
lOSUser varchar(4000) := UPPER(SUBSTRING(current_user FROM POSITION('\' IN current_user) + 1));
lPredicate varchar(4000) := NULL;
lCount integer;
i RECORD;
BEGIN
IF position('ro' in current_user) = 0 THEN
lPredicate := '1=1';
ELSE
-- Users associated to explicit country_code
FOR i IN (SELECT r.country_code AS country_code
FROM one.users u
where UPPER(SUBSTR(u.Login, INSTR(u.Login, '\', -1) + 1)) = lOSUser )
WHERE u.role_type = 'reader') LOOP
lPredicate := lPredicate||''''||i.country_code||''',';
END LOOP;
IF lPredicate IS NOT NULL THEN
lPredicate := 'SUBSTR("id",1,3) IN ('||SUBSTR(lPredicate, 1, LENGTH(lPredicate)-1)||')';
ELSE
lPredicate := '1=1';
END IF;
END IF;
RETURN lPredicate;
END;
$BODY$;
For the below policy statement it created the policy but i cant call that
CREATE POLICY "Codebase_Filter"
ON one.activity
FOR SELECT
TO one
USING (one.get_country('one','activity'));
I would need a policy on table Activity which has a column country_code .
In the policy i would need to call a function get_country as below which queries the users table based on current user and checks which country code that user has access to.
Then it should build up the lPredicate with the filter condition and append to the query user runs on the Activity table.
Can you please guide how to achieve this?
CREATE OR REPLACE FUNCTION one.get_country(
powner name,
ptable_name name)
RETURNS character varying
LANGUAGE 'plpgsql'
COST 100
STABLE PARALLEL UNSAFE
AS $BODY$
DECLARE
lOSUser varchar(4000) := UPPER(SUBSTRING(current_user FROM POSITION('\' IN current_user) + 1));
lPredicate varchar(4000) := NULL;
lCount integer;
i RECORD;
BEGIN
IF position('ro' in current_user) = 0 THEN
lPredicate := '1=1';
ELSE
-- Users associated to explicit country_code
FOR i IN (SELECT r.country_code AS country_code
FROM one.users u
where UPPER(SUBSTR(u.Login, INSTR(u.Login, '\', -1) + 1)) = lOSUser )
WHERE u.role_type = 'reader') LOOP
lPredicate := lPredicate||''''||i.country_code||''',';
END LOOP;
IF lPredicate IS NOT NULL THEN
lPredicate := 'SUBSTR("id",1,3) IN ('||SUBSTR(lPredicate, 1, LENGTH(lPredicate)-1)||')';
ELSE
lPredicate := '1=1';
END IF;
END IF;
RETURN lPredicate;
END;
$BODY$;
For the below policy statement it created the policy but i cant call that
CREATE POLICY "Codebase_Filter"
ON one.activity
FOR SELECT
TO one
USING (one.get_country('one','activity'));
On Fri, Apr 25, 2025 at 6:23 PM Dominique Devienne <ddevienne@gmail.com> wrote:
On Fri, Apr 25, 2025 at 2:43 PM Laurenz Albe <laurenz.albe@cybertec.at> wrote:
> On Fri, 2025-04-25 at 12:38 +0530, Vydehi Ganti wrote:
> > We are presently using Postgresql:PostgreSQL 15.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.5.0 20210514 (Red Hat 8.5.0-23), 64-bit
> > 2.The function would return a character varying string which should be appended
> > to the select as a filter.
>
> You cannot add whole WHERE conditions to a query dynamically.
> The only way to fix that is to solve the problem differently.
> Since you didn't tell us details, we cannot tell you how.
Laurenz is right. That's not how RLS works in PostgreSQL, unlike Oracle.
In PostgreSQL, you must use a boolean SQL expression, often by calling
a function.
You don't simply return some SQL text that Oracle then "splices" into
the SELECT.
E.g., if you use custom ROLEs as an implementation detail for your
security rules,
your policy can be as simple as calling the pg_has_role() built-in
function. FWIW. --DD
CREATE POLICY ... USING (pg_has_role('SomeRole', 'MEMBER'))
On Fri, Apr 25, 2025 at 3:01 PM Vydehi Ganti <rayudugs@gmail.com> wrote: > Then it should build up the lPredicate with the filter condition and append to the query user runs on the Activity table. You're not reading us, and asking us to do the work for you... RLS Predicates don't return strings in PostgreSQL, but a boolean. Write your function to do your check, and return TRUE or FALSE.
So I don't have a possibility to append where clause dynamically and can only check the boolean?
On Fri, 25 Apr, 2025, 18:48 Dominique Devienne, <ddevienne@gmail.com> wrote:
On Fri, Apr 25, 2025 at 3:01 PM Vydehi Ganti <rayudugs@gmail.com> wrote:
> Then it should build up the lPredicate with the filter condition and append to the query user runs on the Activity table.
You're not reading us, and asking us to do the work for you...
RLS Predicates don't return strings in PostgreSQL, but a boolean.
Write your function to do your check, and return TRUE or FALSE.
On Fri, Apr 25, 2025 at 3:21 PM Vydehi Ganti <rayudugs@gmail.com> wrote: > So I don't have a possibility to append where clause dynamically and can only check the boolean? Indeed. But given that you can run arbitrary SQL inside the function, even dynamic SQL, that ends up pretty much the same. And you have access to in-row values too, when calling the function. It's just a different design, that's all. --DD
Can i know if there is any scenario or ref document for the design you suggested above?
On Fri, 25 Apr, 2025, 18:56 Dominique Devienne, <ddevienne@gmail.com> wrote:
On Fri, Apr 25, 2025 at 3:21 PM Vydehi Ganti <rayudugs@gmail.com> wrote:
> So I don't have a possibility to append where clause dynamically and can only check the boolean?
Indeed. But given that you can run arbitrary SQL inside the function,
even dynamic SQL,
that ends up pretty much the same. And you have access to in-row
values too, when calling the function.
It's just a different design, that's all. --DD
On Fri, Apr 25, 2025 at 3:29 PM Vydehi Ganti <rayudugs@gmail.com> wrote: > Can i know if there is any scenario or ref document for the design you suggested above? Some docs: https://www.postgresql.org/docs/current/ddl-rowsecurity.html https://satoricyber.com/postgres-security/postgres-row-level-security/ Your Oracle function converted to PostgreSQL, FWIW. Use at your own risk. https://chatgpt.com/share/680b8e36-b4ac-800e-9e0e-2601aecd2aee
On 4/25/25 14:01, Vydehi Ganti wrote: > This is my Scenario: > > CREATE OR REPLACE FUNCTION one.get_country( > powner name, > ptable_name name) > RETURNS character varying > LANGUAGE 'plpgsql' > COST 100 > STABLE PARALLEL UNSAFE > AS $BODY$ > DECLARE > > lOSUser varchar(4000) := UPPER(SUBSTRING(current_user FROM > POSITION('\' IN current_user) + 1)); > lPredicate varchar(4000) := NULL; > lCount integer; > > i RECORD; > > BEGIN > IF position('ro' in current_user) = 0 THEN > lPredicate := '1=1'; > ELSE > -- Users associated to explicit country_code > FOR i IN (SELECT r.country_code AS country_code > FROM one.users u > where UPPER(SUBSTR(u.Login, INSTR(u.Login, > '\', -1) + 1)) = lOSUser ) > WHERE u.role_type = 'reader') LOOP > lPredicate := lPredicate||''''||i.country_code||''','; > END LOOP; > > IF lPredicate IS NOT NULL THEN > lPredicate := 'SUBSTR("id",1,3) IN ('||SUBSTR(lPredicate, > 1, LENGTH(lPredicate)-1)||')'; > ELSE > lPredicate := '1=1'; > END IF; > END IF; > > RETURN lPredicate; > > END; > $BODY$; > > For the below policy statement it created the policy but i cant call that > CREATE POLICY "Codebase_Filter" > ON one.activity > FOR SELECT > TO one > USING (one.get_country('one','activity')); side note : it seems ptable_name and powner are not read in your function
On 4/25/25 06:01, Vydehi Ganti wrote: > This is my Scenario: > > *Can you please guide how to achieve this?* > > CREATE OR REPLACE FUNCTION one.get_country( > powner name, > ptable_name name) > RETURNS character varying > LANGUAGE 'plpgsql' > > For the below policy statement it created the policy but i cant call that > CREATE POLICY "Codebase_Filter" > ON one.activity > FOR SELECT > TO one > USING (one.get_country('one','activity')); The core of the issue you are getting is that this from the function: RETURNS character varying is not going to work here: USING (one.get_country('one','activity')) as what USING will see is a string not the evaluation of 1=1 hence the error you get: ERROR: invalid input syntax for type boolean: "1=1" CONTEXT: PL/pgSQL function function name(name,name) while casting return value to function's return type -- Adrian Klaver adrian.klaver@aklaver.com