Attached is the v8 patch for your review, with updated variable names and a rebase applied.
On Mon, Nov 10, 2025 at 10:46 AM Akshay Joshi <[email protected]> wrote: > Thanks for the clarification. However, I still believe this is out of > scope for the CREATE POLICY DDL. The command ALTER TABLE ... ENABLE ROW > LEVEL SECURITY seems more appropriate as part of the CREATE TABLE > reconstruction rather than CREATE POLICY. > > That said, I’m open to adding it if the majority feels it should be > included in this feature. > > On Fri, Nov 7, 2025 at 8:18 PM Marcos Pegoraro <[email protected]> wrote: > >> Em sex., 7 de nov. de 2025 às 11:27, Akshay Joshi < >> [email protected]> escreveu: >> >>> I don’t think we need that statement. Could you please elaborate on >>> where exactly it needs to be added? >>> >> >> well, these pg_get_..._ddl() functions will be cool for compare/clone >> schemas in a multi tenant world. >> Instead of dump/sed/restore a schema to create a new one, I could use >> something like >> select pg_get_table_ddl(oid) from pg_class where nspname = 'customer_050' >> and relkind = 'r' union all >> select pg_get_constraint_ddl(oid) from pg_constraint inner join pg_class >> on ... where ... union all >> select pg_get_trigger_ddl(oid) from pg_trigger inner join pg_class on >> ... where ... union all >> ... >> >> And pg_get_policy_ddl() will be part of these union all selects >> >> Because that would be good to worry about create that only if it does not >> exists or drop first too. >> >> regards >> Marcos >> >
From 2421b3821457ddc765da70667fde2aed437b30bf Mon Sep 17 00:00:00 2001 From: Akshay Joshi <[email protected]> Date: Fri, 10 Oct 2025 15:46:13 +0530 Subject: [PATCH v8] Add pg_get_policy_ddl() function to reconstruct CREATE POLICY statements MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit This patch introduces a new system function: pg_get_policy_ddl(regclass table, name policy_name, bool pretty), which reconstructs the CREATE POLICY statement for the specified policy. Usage examples: SELECT pg_get_policy_ddl('rls_table', 'pol1'); -- non-pretty formatted DDL SELECT pg_get_policy_ddl('rls_table', 'pol1', true); -- pretty formatted DDL SELECT pg_get_policy_ddl(16564, 'pol1'); -- non-pretty formatted DDL SELECT pg_get_policy_ddl(16564, 'pol1', true); -- pretty formatted DDL Reference: PG-163 Author: Akshay Joshi <[email protected]> Reviewed-by: Álvaro Herrera <[email protected]> --- doc/src/sgml/func/func-info.sgml | 55 ++++++ src/backend/catalog/system_functions.sql | 6 + src/backend/commands/policy.c | 27 +++ src/backend/utils/adt/ruleutils.c | 212 ++++++++++++++++++++++ src/include/catalog/pg_proc.dat | 3 + src/include/commands/policy.h | 2 + src/test/regress/expected/rowsecurity.out | 207 ++++++++++++++++++++- src/test/regress/sql/rowsecurity.sql | 80 ++++++++ 8 files changed, 591 insertions(+), 1 deletion(-) diff --git a/doc/src/sgml/func/func-info.sgml b/doc/src/sgml/func/func-info.sgml index d4508114a48..edfd9381be0 100644 --- a/doc/src/sgml/func/func-info.sgml +++ b/doc/src/sgml/func/func-info.sgml @@ -3797,4 +3797,59 @@ acl | {postgres=arwdDxtm/postgres,foo=r/postgres} </sect2> + <sect2 id="functions-get-object-ddl"> + <title>Get Object DDL Functions</title> + + <para> + The functions described in <xref linkend="functions-get-object-ddl-table"/> + return the Data Definition Language (DDL) statement for any given database object. + This feature is implemented as a set of distinct functions for each object type. + </para> + + <table id="functions-get-object-ddl-table"> + <title>Get Object DDL Functions</title> + <tgroup cols="1"> + <thead> + <row> + <entry role="func_table_entry"><para role="func_signature"> + Function + </para> + <para> + Description + </para></entry> + </row> + </thead> + + <tbody> + <row> + <entry role="func_table_entry"><para role="func_signature"> + <indexterm> + <primary>pg_get_policy_ddl</primary> + </indexterm> + <function>pg_get_policy_ddl</function> + ( <parameter>table</parameter> <type>regclass</type>, <parameter>policy_name</parameter> <type>name</type>, <optional> <parameter>pretty</parameter> <type>boolean</type> </optional> ) + <returnvalue>text</returnvalue> + </para> + <para> + Reconstructs the <command>CREATE POLICY</command> statement from the + system catalogs for a specified table and policy name. The result is a + comprehensive <command>CREATE POLICY</command> statement. + </para></entry> + </row> + </tbody> + </tgroup> + </table> + + <para> + Most of the functions that reconstruct (decompile) database objects have an + optional <parameter>pretty</parameter> flag, which if + <literal>true</literal> causes the result to be + <quote>pretty-printed</quote>. Pretty-printing adds tab character and new + line character for legibility. Passing <literal>false</literal> for the + <parameter>pretty</parameter> parameter yields the same result as omitting + the parameter. + </para> + + </sect2> + </sect1> diff --git a/src/backend/catalog/system_functions.sql b/src/backend/catalog/system_functions.sql index 2d946d6d9e9..a5e22374668 100644 --- a/src/backend/catalog/system_functions.sql +++ b/src/backend/catalog/system_functions.sql @@ -657,6 +657,12 @@ LANGUAGE INTERNAL STRICT VOLATILE PARALLEL UNSAFE AS 'pg_replication_origin_session_setup'; +CREATE OR REPLACE FUNCTION + pg_get_policy_ddl(tableID regclass, policyName name, pretty bool DEFAULT false) +RETURNS text +LANGUAGE INTERNAL +AS 'pg_get_policy_ddl'; + -- -- The default permissions for functions mean that anyone can execute them. -- A number of functions shouldn't be executable by just anyone, but rather diff --git a/src/backend/commands/policy.c b/src/backend/commands/policy.c index 83056960fe4..1abe0c44353 100644 --- a/src/backend/commands/policy.c +++ b/src/backend/commands/policy.c @@ -128,6 +128,33 @@ parse_policy_command(const char *cmd_name) return polcmd; } +/* + * get_policy_cmd_name - + * helper function to convert char representation to full command strings. + * + * cmd - Valid values are '*', 'r', 'a', 'w' and 'd'. + * + */ +char * +get_policy_cmd_name(char cmd) +{ + switch (cmd) + { + case '*': + return "ALL"; + case ACL_SELECT_CHR: + return "SELECT"; + case ACL_INSERT_CHR: + return "INSERT"; + case ACL_UPDATE_CHR: + return "UPDATE"; + case ACL_DELETE_CHR: + return "DELETE"; + default: + elog(ERROR, "unrecognized policy command"); + } +} + /* * policy_role_list_to_array * helper function to convert a list of RoleSpecs to an array of diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index 556ab057e5a..9adadf65743 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -33,12 +33,14 @@ #include "catalog/pg_opclass.h" #include "catalog/pg_operator.h" #include "catalog/pg_partitioned_table.h" +#include "catalog/pg_policy.h" #include "catalog/pg_proc.h" #include "catalog/pg_statistic_ext.h" #include "catalog/pg_trigger.h" #include "catalog/pg_type.h" #include "commands/defrem.h" #include "commands/tablespace.h" +#include "commands/policy.h" #include "common/keywords.h" #include "executor/spi.h" #include "funcapi.h" @@ -94,6 +96,10 @@ ((pretty) ? (PRETTYFLAG_PAREN | PRETTYFLAG_INDENT | PRETTYFLAG_SCHEMA) \ : PRETTYFLAG_INDENT) +#define GET_DDL_PRETTY_FLAGS(pretty) \ + ((pretty) ? (PRETTYFLAG_PAREN | PRETTYFLAG_INDENT | PRETTYFLAG_SCHEMA) \ + : 0) + /* Default line length for pretty-print wrapping: 0 means wrap always */ #define WRAP_COLUMN_DEFAULT 0 @@ -546,6 +552,12 @@ static void get_json_table_nested_columns(TableFunc *tf, JsonTablePlan *plan, deparse_context *context, bool showimplicit, bool needcomma); +static void get_formatted_string(StringInfo buf, + int prettyFlags, + int nTabChars, + const char *fmt,...) pg_attribute_printf(4, 5); +static char *pg_get_policy_ddl_worker(Oid tableID, Name policyName, + int prettyFlags); #define only_marker(rte) ((rte)->inh ? "" : "ONLY ") @@ -13743,3 +13755,203 @@ get_range_partbound_string(List *bound_datums) return buf.data; } + +/* + * get_formatted_string + * + * Return a formatted version of the string. + * + * prettyFlags - Based on prettyFlags the output includes tabs (\t) and + * newlines (\n). + * nTabChars - indent with specified no of tabs. + * fmt - printf-style format string used by appendStringInfoVA. + */ +static void +get_formatted_string(StringInfo buf, int prettyFlags, int nTabChars, const char *fmt,...) +{ + va_list args; + + if (prettyFlags & PRETTYFLAG_INDENT) + { + appendStringInfoChar(buf, '\n'); + /* Indent with tabs */ + for (int i = 0; i < nTabChars; i++) + { + appendStringInfoChar(buf, '\t'); + } + } + else + appendStringInfoChar(buf, ' '); + + va_start(args, fmt); + appendStringInfoVA(buf, fmt, args); + va_end(args); +} + +/* + * pg_get_policy_ddl + * + * Generate a CREATE POLICY statement for the specified policy. + * + * tableID - Table ID of the policy. + * policyName - Name of the policy for which to generate the DDL. + * pretty - If true, format the DDL with indentation and line breaks. + */ +Datum +pg_get_policy_ddl(PG_FUNCTION_ARGS) +{ + Oid tableID = PG_GETARG_OID(0); + Name policyName = PG_GETARG_NAME(1); + bool pretty = PG_GETARG_BOOL(2); + int prettyFlags; + char *res; + + prettyFlags = GET_DDL_PRETTY_FLAGS(pretty); + res = pg_get_policy_ddl_worker(tableID, policyName, prettyFlags); + + if (res == NULL) + PG_RETURN_NULL(); + + PG_RETURN_TEXT_P(string_to_text(res)); +} + +static char * +pg_get_policy_ddl_worker(Oid tableID, Name policyName, int prettyFlags) +{ + bool attrIsNull; + Datum valueDatum; + HeapTuple tuplePolicy; + Relation pgPolicyRel; + char *targetTable; + ScanKeyData skey[2]; + SysScanDesc sscan; + Form_pg_policy policyForm; + StringInfoData buf; + + /* Validate that the relation exists */ + if (!OidIsValid(tableID) || get_rel_name(tableID) == NULL) + return NULL; + + initStringInfo(&buf); + + targetTable = generate_qualified_relation_name(tableID); + /* Find policy to begin scan */ + pgPolicyRel = table_open(PolicyRelationId, AccessShareLock); + + /* Set key - policy's relation id. */ + ScanKeyInit(&skey[0], + Anum_pg_policy_polrelid, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(tableID)); + + /* Set key - policy's name. */ + ScanKeyInit(&skey[1], + Anum_pg_policy_polname, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(NameStr(*policyName))); + + sscan = systable_beginscan(pgPolicyRel, + PolicyPolrelidPolnameIndexId, true, NULL, 2, + skey); + + tuplePolicy = systable_getnext(sscan); + /* Check that the policy is found, raise an error if not. */ + if (!HeapTupleIsValid(tuplePolicy)) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("policy \"%s\" for table \"%s\" does not exist", + NameStr(*policyName), + targetTable))); + + policyForm = (Form_pg_policy) GETSTRUCT(tuplePolicy); + + /* Build the CREATE POLICY statement */ + appendStringInfo(&buf, "CREATE POLICY %s ON %s", + quote_identifier(NameStr(*policyName)), + targetTable); + + /* Check the type is PERMISSIVE or RESTRICTIVE */ + get_formatted_string(&buf, prettyFlags, 1, + policyForm->polpermissive ? "AS PERMISSIVE" : "AS RESTRICTIVE"); + + /* Check command to which the policy applies */ + get_formatted_string(&buf, prettyFlags, 1, "FOR %s", + get_policy_cmd_name(policyForm->polcmd)); + + /* Check if the policy has a TO list */ + valueDatum = heap_getattr(tuplePolicy, + Anum_pg_policy_polroles, + RelationGetDescr(pgPolicyRel), + &attrIsNull); + if (!attrIsNull) + { + ArrayType *policy_roles = DatumGetArrayTypePCopy(valueDatum); + int nitems = ARR_DIMS(policy_roles)[0]; + Oid *roles = (Oid *) ARR_DATA_PTR(policy_roles); + StringInfoData role_names; + + initStringInfo(&role_names); + + for (int i = 0; i < nitems; i++) + { + if (OidIsValid(roles[i])) + { + char *rolename = GetUserNameFromId(roles[i], false); + + if (i > 0) + appendStringInfoString(&role_names, ", "); + appendStringInfoString(&role_names, rolename); + } + } + + if (role_names.len > 0) + get_formatted_string(&buf, prettyFlags, 1, "TO %s", role_names.data); + else + + /* + * When no specific role is provided, generate the TO clause with + * the PUBLIC role. + */ + get_formatted_string(&buf, prettyFlags, 1, "TO PUBLIC"); + } + + /* Check if the policy has a USING expr */ + valueDatum = heap_getattr(tuplePolicy, + Anum_pg_policy_polqual, + RelationGetDescr(pgPolicyRel), + &attrIsNull); + if (!attrIsNull) + { + text *exprtext = DatumGetTextPP(valueDatum); + text *usingExpression = pg_get_expr_worker(exprtext, + policyForm->polrelid, + prettyFlags); + + get_formatted_string(&buf, prettyFlags, 1, "USING (%s)", + text_to_cstring(usingExpression)); + } + + /* Check if the policy has a WITH CHECK expr */ + valueDatum = heap_getattr(tuplePolicy, + Anum_pg_policy_polwithcheck, + RelationGetDescr(pgPolicyRel), + &attrIsNull); + if (!attrIsNull) + { + text *exprtext = DatumGetTextPP(valueDatum); + text *checkExpression = pg_get_expr_worker(exprtext, + policyForm->polrelid, + prettyFlags); + + get_formatted_string(&buf, prettyFlags, 1, "WITH CHECK (%s)", + text_to_cstring(checkExpression)); + } + + appendStringInfoChar(&buf, ';'); + + /* Clean up. */ + systable_endscan(sscan); + table_close(pgPolicyRel, AccessShareLock); + + return buf.data; +} diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index aaadfd8c748..50fb26f6b1e 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -4021,6 +4021,9 @@ proname => 'pg_get_function_sqlbody', provolatile => 's', prorettype => 'text', proargtypes => 'oid', prosrc => 'pg_get_function_sqlbody' }, +{ oid => '8811', descr => 'get CREATE statement for policy', + proname => 'pg_get_policy_ddl', prorettype => 'text', + proargtypes => 'regclass name bool', prosrc => 'pg_get_policy_ddl' }, { oid => '1686', descr => 'list of SQL keywords', proname => 'pg_get_keywords', procost => '10', prorows => '500', diff --git a/src/include/commands/policy.h b/src/include/commands/policy.h index f06aa1df439..40e45b738f4 100644 --- a/src/include/commands/policy.h +++ b/src/include/commands/policy.h @@ -35,4 +35,6 @@ extern ObjectAddress rename_policy(RenameStmt *stmt); extern bool relation_has_policies(Relation rel); +extern char *get_policy_cmd_name(char cmd); + #endif /* POLICY_H */ diff --git a/src/test/regress/expected/rowsecurity.out b/src/test/regress/expected/rowsecurity.out index c958ef4d70a..4ebe32711cd 100644 --- a/src/test/regress/expected/rowsecurity.out +++ b/src/test/regress/expected/rowsecurity.out @@ -5101,11 +5101,214 @@ reset rls_test.blah; drop function rls_f(text); drop table rls_t, test_t; -- +-- Test for pg_get_policy_ddl(tableName, policyName, pretty) function. +-- +CREATE TABLE rls_tbl_1 ( + did int primary key, + cid int, + dlevel int not null, + dauthor name, + dtitle text +); +GRANT ALL ON rls_tbl_1 TO public; +CREATE TABLE rls_tbl_2 ( + pguser name primary key, + seclv int +); +GRANT SELECT ON rls_tbl_2 TO public; +-- Test PERMISSIVE and RESTRICTIVE +CREATE POLICY rls_p1 ON rls_tbl_1 AS PERMISSIVE + USING (dlevel <= (SELECT seclv FROM rls_tbl_2 WHERE pguser = current_user)); +CREATE POLICY rls_p2 ON rls_tbl_1 AS RESTRICTIVE USING (cid <> 44 AND cid < 50); +-- Test FOR ALL | SELECT | INSERT | UPDATE | DELETE +CREATE POLICY rls_p3 ON rls_tbl_1 FOR ALL USING (dauthor = current_user); +CREATE POLICY rls_p4 ON rls_tbl_1 FOR SELECT USING (cid % 2 = 0); +CREATE POLICY rls_p5 ON rls_tbl_1 FOR INSERT WITH CHECK (cid % 2 = 1); +CREATE POLICY rls_p6 ON rls_tbl_1 FOR UPDATE USING (cid % 2 = 0); +CREATE POLICY rls_p7 ON rls_tbl_1 FOR DELETE USING (cid < 8); +-- Test TO { role_name ... } +CREATE POLICY rls_p8 ON rls_tbl_1 TO regress_rls_dave, regress_rls_alice USING (true); +CREATE POLICY rls_p9 ON rls_tbl_1 TO regress_rls_exempt_user WITH CHECK (cid = (SELECT seclv FROM rls_tbl_2)); +-- Test NULL value +SELECT pg_get_policy_ddl(NULL, 'rls_p1'); + pg_get_policy_ddl +------------------- + +(1 row) + +SELECT pg_get_policy_ddl('tab1', NULL); +ERROR: relation "tab1" does not exist +LINE 1: SELECT pg_get_policy_ddl('tab1', NULL); + ^ +SELECT pg_get_policy_ddl(NULL, NULL); + pg_get_policy_ddl +------------------- + +(1 row) + +-- Test -1 as table oid + SELECT pg_get_policy_ddl(-1, 'rls_p1'); + pg_get_policy_ddl +------------------- + +(1 row) + +-- Table does not exist +SELECT pg_get_policy_ddl('tab1', 'rls_p1'); +ERROR: relation "tab1" does not exist +LINE 1: SELECT pg_get_policy_ddl('tab1', 'rls_p1'); + ^ +-- Policy does not exist +SELECT pg_get_policy_ddl('rls_tbl_1', 'pol1'); +ERROR: policy "pol1" for table "regress_rls_schema.rls_tbl_1" does not exist +-- Without Pretty formatted +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p1'); + pg_get_policy_ddl +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + CREATE POLICY rls_p1 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR ALL TO PUBLIC USING ((dlevel <= (SELECT rls_tbl_2.seclv FROM rls_tbl_2 WHERE (rls_tbl_2.pguser = CURRENT_USER)))); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p2'); + pg_get_policy_ddl +----------------------------------------------------------------------------------------------------------------------------- + CREATE POLICY rls_p2 ON regress_rls_schema.rls_tbl_1 AS RESTRICTIVE FOR ALL TO PUBLIC USING (((cid <> 44) AND (cid < 50))); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p3'); + pg_get_policy_ddl +------------------------------------------------------------------------------------------------------------------------ + CREATE POLICY rls_p3 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR ALL TO PUBLIC USING ((dauthor = CURRENT_USER)); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p4'); + pg_get_policy_ddl +------------------------------------------------------------------------------------------------------------------ + CREATE POLICY rls_p4 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR SELECT TO PUBLIC USING (((cid % 2) = 0)); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p5'); + pg_get_policy_ddl +----------------------------------------------------------------------------------------------------------------------- + CREATE POLICY rls_p5 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR INSERT TO PUBLIC WITH CHECK (((cid % 2) = 1)); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p6', false); + pg_get_policy_ddl +------------------------------------------------------------------------------------------------------------------ + CREATE POLICY rls_p6 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR UPDATE TO PUBLIC USING (((cid % 2) = 0)); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p7', false); + pg_get_policy_ddl +------------------------------------------------------------------------------------------------------------ + CREATE POLICY rls_p7 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR DELETE TO PUBLIC USING ((cid < 8)); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p8', false); + pg_get_policy_ddl +--------------------------------------------------------------------------------------------------------------------------------- + CREATE POLICY rls_p8 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR ALL TO regress_rls_dave, regress_rls_alice USING (true); +(1 row) + +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p9', false); + pg_get_policy_ddl +--------------------------------------------------------------------------------------------------------------------------------------------------------------------- + CREATE POLICY rls_p9 ON regress_rls_schema.rls_tbl_1 AS PERMISSIVE FOR ALL TO regress_rls_exempt_user WITH CHECK ((cid = (SELECT rls_tbl_2.seclv FROM rls_tbl_2))); +(1 row) + +-- With Pretty formatted +\pset format unaligned +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p1', true); +pg_get_policy_ddl +CREATE POLICY rls_p1 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR ALL + TO PUBLIC + USING (dlevel <= (( SELECT rls_tbl_2.seclv + FROM rls_tbl_2 + WHERE rls_tbl_2.pguser = CURRENT_USER))); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p2', true); +pg_get_policy_ddl +CREATE POLICY rls_p2 ON regress_rls_schema.rls_tbl_1 + AS RESTRICTIVE + FOR ALL + TO PUBLIC + USING (cid <> 44 AND cid < 50); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p3', true); +pg_get_policy_ddl +CREATE POLICY rls_p3 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR ALL + TO PUBLIC + USING (dauthor = CURRENT_USER); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p4', true); +pg_get_policy_ddl +CREATE POLICY rls_p4 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR SELECT + TO PUBLIC + USING ((cid % 2) = 0); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p5', true); +pg_get_policy_ddl +CREATE POLICY rls_p5 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR INSERT + TO PUBLIC + WITH CHECK ((cid % 2) = 1); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p6', true); +pg_get_policy_ddl +CREATE POLICY rls_p6 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR UPDATE + TO PUBLIC + USING ((cid % 2) = 0); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p7', true); +pg_get_policy_ddl +CREATE POLICY rls_p7 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR DELETE + TO PUBLIC + USING (cid < 8); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p8', true); +pg_get_policy_ddl +CREATE POLICY rls_p8 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR ALL + TO regress_rls_dave, regress_rls_alice + USING (true); +(1 row) +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p9', true); +pg_get_policy_ddl +CREATE POLICY rls_p9 ON regress_rls_schema.rls_tbl_1 + AS PERMISSIVE + FOR ALL + TO regress_rls_exempt_user + WITH CHECK (cid = (( SELECT rls_tbl_2.seclv + FROM rls_tbl_2))); +(1 row) +-- Clean up objects created for testing pg_get_policy_ddl function. +DROP POLICY rls_p1 ON rls_tbl_1; +DROP POLICY rls_p2 ON rls_tbl_1; +DROP POLICY rls_p3 ON rls_tbl_1; +DROP POLICY rls_p4 ON rls_tbl_1; +DROP POLICY rls_p5 ON rls_tbl_1; +DROP POLICY rls_p6 ON rls_tbl_1; +DROP POLICY rls_p7 ON rls_tbl_1; +DROP POLICY rls_p8 ON rls_tbl_1; +DROP POLICY rls_p9 ON rls_tbl_1; +-- -- Clean up objects -- RESET SESSION AUTHORIZATION; DROP SCHEMA regress_rls_schema CASCADE; -NOTICE: drop cascades to 30 other objects +NOTICE: drop cascades to 32 other objects DETAIL: drop cascades to function f_leak(text) drop cascades to table uaccount drop cascades to table category @@ -5136,6 +5339,8 @@ drop cascades to table dep1 drop cascades to table dep2 drop cascades to table dob_t1 drop cascades to table dob_t2 +drop cascades to table rls_tbl_1 +drop cascades to table rls_tbl_2 DROP USER regress_rls_alice; DROP USER regress_rls_bob; DROP USER regress_rls_carol; diff --git a/src/test/regress/sql/rowsecurity.sql b/src/test/regress/sql/rowsecurity.sql index 5d923c5ca3b..b90f5309578 100644 --- a/src/test/regress/sql/rowsecurity.sql +++ b/src/test/regress/sql/rowsecurity.sql @@ -2542,6 +2542,86 @@ reset rls_test.blah; drop function rls_f(text); drop table rls_t, test_t; +-- +-- Test for pg_get_policy_ddl(tableName, policyName, pretty) function. +-- +CREATE TABLE rls_tbl_1 ( + did int primary key, + cid int, + dlevel int not null, + dauthor name, + dtitle text +); +GRANT ALL ON rls_tbl_1 TO public; +CREATE TABLE rls_tbl_2 ( + pguser name primary key, + seclv int +); +GRANT SELECT ON rls_tbl_2 TO public; + +-- Test PERMISSIVE and RESTRICTIVE +CREATE POLICY rls_p1 ON rls_tbl_1 AS PERMISSIVE + USING (dlevel <= (SELECT seclv FROM rls_tbl_2 WHERE pguser = current_user)); +CREATE POLICY rls_p2 ON rls_tbl_1 AS RESTRICTIVE USING (cid <> 44 AND cid < 50); + +-- Test FOR ALL | SELECT | INSERT | UPDATE | DELETE +CREATE POLICY rls_p3 ON rls_tbl_1 FOR ALL USING (dauthor = current_user); +CREATE POLICY rls_p4 ON rls_tbl_1 FOR SELECT USING (cid % 2 = 0); +CREATE POLICY rls_p5 ON rls_tbl_1 FOR INSERT WITH CHECK (cid % 2 = 1); +CREATE POLICY rls_p6 ON rls_tbl_1 FOR UPDATE USING (cid % 2 = 0); +CREATE POLICY rls_p7 ON rls_tbl_1 FOR DELETE USING (cid < 8); + +-- Test TO { role_name ... } +CREATE POLICY rls_p8 ON rls_tbl_1 TO regress_rls_dave, regress_rls_alice USING (true); +CREATE POLICY rls_p9 ON rls_tbl_1 TO regress_rls_exempt_user WITH CHECK (cid = (SELECT seclv FROM rls_tbl_2)); + +-- Test NULL value +SELECT pg_get_policy_ddl(NULL, 'rls_p1'); +SELECT pg_get_policy_ddl('tab1', NULL); +SELECT pg_get_policy_ddl(NULL, NULL); + +-- Test -1 as table oid + SELECT pg_get_policy_ddl(-1, 'rls_p1'); + +-- Table does not exist +SELECT pg_get_policy_ddl('tab1', 'rls_p1'); +-- Policy does not exist +SELECT pg_get_policy_ddl('rls_tbl_1', 'pol1'); + +-- Without Pretty formatted +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p1'); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p2'); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p3'); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p4'); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p5'); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p6', false); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p7', false); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p8', false); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p9', false); + +-- With Pretty formatted +\pset format unaligned +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p1', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p2', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p3', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p4', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p5', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p6', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p7', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p8', true); +SELECT pg_get_policy_ddl('rls_tbl_1', 'rls_p9', true); + +-- Clean up objects created for testing pg_get_policy_ddl function. +DROP POLICY rls_p1 ON rls_tbl_1; +DROP POLICY rls_p2 ON rls_tbl_1; +DROP POLICY rls_p3 ON rls_tbl_1; +DROP POLICY rls_p4 ON rls_tbl_1; +DROP POLICY rls_p5 ON rls_tbl_1; +DROP POLICY rls_p6 ON rls_tbl_1; +DROP POLICY rls_p7 ON rls_tbl_1; +DROP POLICY rls_p8 ON rls_tbl_1; +DROP POLICY rls_p9 ON rls_tbl_1; + -- -- Clean up objects -- -- 2.51.0
