doc/src/sgml/ref/alter_view.sgml | 20 ++ doc/src/sgml/ref/create_view.sgml | 24 +++ doc/src/sgml/rules.sgml | 95 ++++++++++ src/backend/access/common/reloptions.c | 15 ++- src/backend/commands/tablecmds.c | 3 +- src/backend/commands/view.c | 30 +++- src/backend/nodes/copyfuncs.c | 1 + src/backend/nodes/equalfuncs.c | 1 + src/backend/nodes/outfuncs.c | 1 + src/backend/nodes/readfuncs.c | 1 + src/backend/optimizer/path/allpaths.c | 7 + src/backend/optimizer/prep/prepjointree.c | 1 + src/backend/parser/gram.y | 10 +- src/backend/rewrite/rewriteHandler.c | 1 + src/backend/utils/cache/relcache.c | 1 + src/bin/pg_dump/pg_dump.c | 6 +- src/include/access/reloptions.h | 3 +- src/include/nodes/parsenodes.h | 5 + src/include/utils/rel.h | 9 + src/test/regress/expected/create_view.out | 55 ++++++- src/test/regress/expected/select_views_1.out | 255 ++++++++++++++++++++++++++ src/test/regress/sql/create_view.sql | 32 ++++ src/test/regress/sql/select_views.sql | 126 +++++++++++++ 23 files changed, 686 insertions(+), 16 deletions(-) diff --git a/doc/src/sgml/ref/alter_view.sgml b/doc/src/sgml/ref/alter_view.sgml index c383905..3340856 100644 --- a/doc/src/sgml/ref/alter_view.sgml +++ b/doc/src/sgml/ref/alter_view.sgml @@ -26,6 +26,8 @@ ALTER VIEW name ALTER [ COLUMN ] name OWNER TO new_owner ALTER VIEW name RENAME TO new_name ALTER VIEW name SET SCHEMA new_schema +ALTER VIEW name SET ( parameter [= value] [, ... ] ) +ALTER VIEW name RESET ( parameter [, ... ] ) @@ -102,6 +104,24 @@ ALTER VIEW name SET SCHEMA + + + parameter + + + Name of the view option to be set. + + + + + + value + + + The new value for the view option. + + + diff --git a/doc/src/sgml/ref/create_view.sgml b/doc/src/sgml/ref/create_view.sgml index 417f8c3..9dba6a5 100644 --- a/doc/src/sgml/ref/create_view.sgml +++ b/doc/src/sgml/ref/create_view.sgml @@ -22,6 +22,7 @@ PostgreSQL documentation CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW name [ ( column_name [, ...] ) ] + [ WITH ( parameter [= value] [, ... ] ) ] AS query @@ -99,6 +100,29 @@ CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW n + WITH (parameter [= value]) + + + This clause allows to specify optional parameters for a view. + + + If security_barrier=TRUE is specified, this view + shall performs as security barrier that prevent unexpected information + leaks. It is a recommendable configuration when the view is defined + to apply row-level security, in spite of performance trade-off. + + + It is a commonly-used technique that using views to filter out + tuple to be invisible to particular users, however, please note + that here is a known-problem that allows malicious users to + reference invisible tuples using a function with side-effect + because of interaction with query optimization. + See for more detailed scenario. + + + + + query diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index 1b06519..421d777 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -1854,7 +1854,102 @@ SELECT * FROM phone_number WHERE tricky(person, phone); similar attacks. (For example, most casting functions include their input values in the error messages they produce.) + + In addition, another scenarios is also known to leak invisible tuples + unlike fair expectations. + +CREATE VIEW my_credit_cards AS + SELECT a.rolname, c.number, c.expire + FROM pg_authid a JOIN credit_cards c ON a.oid = c.id + WHERE a.rolname = current_user; + + This view may also look secure, because all the references to the + my_credit_cards are restricted to the tuples that + satisfies a.rolname = current_user, so it shall + prevent to reference the card numbers of other persons. + + + Note that this view contains a join loop. If user provides + WHERE clause a function that references only + one-side of the join loop, the query planner distributes this + qualifier inside of the join loop to minimize the number of tuples + to be joined. + It is an example to break the row-level security implemented with + my_credit_cards view: + +postgres=> SELECT * FROM my_credit_cards WHERE tricky(number, expire); +NOTICE: 1111-2222-3333-4444 => Jan-01 +NOTICE: 5555-6666-7777-8888 => Feb-02 +NOTICE: 1234-5678-9012-3456 => Mar-03 + rolname | number | expire +---------+---------------------+-------- + alice | 5555-6666-7777-8888 | Feb-02 +(1 row) + + + + The output of EXPLAIN shows us obvious reason + of the unpredicated result. + +postgres=> EXPLAIN SELECT * FROM my_credit_cards WHERE tricky(number, expire); + QUERY PLAN +------------------------------------------------------------------------ + Hash Join (cost=1.03..20.38 rows=1 width=128) + Hash Cond: (c.id = a.oid) + -> Seq Scan on credit_cards c (cost=0.00..18.30 rows=277 width=68) + Filter: tricky(number, expire) + -> Hash (cost=1.01..1.01 rows=1 width=68) + -> Seq Scan on pg_authid a (cost=0.00..1.01 rows=1 width=68) + Filter: (rolname = "current_user"()) +(7 rows) + + The supplied tricky references + only number and expire columns + of credit_cards relation, however, the qualifier + to restrict invisible tuples performs at another side on the join loop. + In the result, the query planner distributes the supplied + tricky on the sequential scan plan on the + credit_cards table, then the query executor launches + this query towards all the tuples and it allows to raise messages + that contains information to be invisible. + + + PostgreSQL provides a countermeasure of + these scenarios. If a particular sub-query originated a view with + security_barrier option, the planner does not + push down qualifiers originated from outside of the view, although + it has a trade-off between performance and stable security. + + The security_barrier option shall modify the query + plan of the above example of my_credit_cards as + follows. You may see the tricky is launched + after all the invisible tuples being filtered out, if this option + was added in the view definition. + +postgres=> SELECT * FROM my_credit_cards WHERE tricky(number, expire); +NOTICE: 1111-2222-3333-4444 => Jan-01 + rolname | number | expire +---------+---------------------+-------- + alice | 1111-2222-3333-4444 | Jan-01 +(1 row) + +postgres=> EXPLAIN SELECT * FROM my_credit_cards WHERE tricky(number, expire); + QUERY PLAN +------------------------------------------------------------------------------ + Subquery Scan on my_credit_cards (cost=1.03..22.52 rows=1 width=128) + Filter: tricky(my_credit_cards.number, my_credit_cards.expire) + -> Hash Join (cost=1.03..22.48 rows=4 width=128) + Hash Cond: (c.id = a.oid) + -> Seq Scan on credit_cards c (cost=0.00..18.30 rows=830 width=68) + -> Hash (cost=1.01..1.01 rows=1 width=68) + -> Seq Scan on pg_authid a (cost=0.00..1.01 rows=1 width=68) + Filter: (rolname = "current_user"()) +(8 rows) + + So, we recommend to append this option when views are defined to + provide row-level security for unprivileged users. + Similar considerations apply to update rules. In the examples of the previous section, the owner of the tables in the example diff --git a/src/backend/access/common/reloptions.c b/src/backend/access/common/reloptions.c index 240e178..78a06b8 100644 --- a/src/backend/access/common/reloptions.c +++ b/src/backend/access/common/reloptions.c @@ -66,6 +66,14 @@ static relopt_bool boolRelOpts[] = }, true }, + { + { + "security_barrier", + "Prevent pushing down qualifiers come from outside of the view", + RELOPT_KIND_VIEW + }, + false + }, /* list terminator */ {{NULL}} }; @@ -772,6 +780,7 @@ extractRelOptions(HeapTuple tuple, TupleDesc tupdesc, Oid amoptions) { case RELKIND_RELATION: case RELKIND_TOASTVALUE: + case RELKIND_VIEW: case RELKIND_UNCATALOGED: options = heap_reloptions(classForm->relkind, datum, false); break; @@ -1130,7 +1139,9 @@ default_reloptions(Datum reloptions, bool validate, relopt_kind kind) {"autovacuum_vacuum_scale_factor", RELOPT_TYPE_REAL, offsetof(StdRdOptions, autovacuum) +offsetof(AutoVacOpts, vacuum_scale_factor)}, {"autovacuum_analyze_scale_factor", RELOPT_TYPE_REAL, - offsetof(StdRdOptions, autovacuum) +offsetof(AutoVacOpts, analyze_scale_factor)} + offsetof(StdRdOptions, autovacuum) +offsetof(AutoVacOpts, analyze_scale_factor)}, + {"security_barrier", RELOPT_TYPE_BOOL, + offsetof(StdRdOptions, security_barrier)}, }; options = parseRelOptions(reloptions, validate, kind, &numoptions); @@ -1172,6 +1183,8 @@ heap_reloptions(char relkind, Datum reloptions, bool validate) return (bytea *) rdopts; case RELKIND_RELATION: return default_reloptions(reloptions, validate, RELOPT_KIND_HEAP); + case RELKIND_VIEW: + return default_reloptions(reloptions, validate, RELOPT_KIND_VIEW); default: /* other relkinds are not supported */ return NULL; diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index c4622c0..b2e8487 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -2985,7 +2985,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, break; case AT_SetRelOptions: /* SET (...) */ case AT_ResetRelOptions: /* RESET (...) */ - ATSimplePermissions(rel, ATT_TABLE | ATT_INDEX); + ATSimplePermissions(rel, ATT_TABLE | ATT_INDEX | ATT_VIEW); /* This command never recurses */ /* No command-specific prep needed */ pass = AT_PASS_MISC; @@ -8100,6 +8100,7 @@ ATExecSetRelOptions(Relation rel, List *defList, bool isReset, LOCKMODE lockmode { case RELKIND_RELATION: case RELKIND_TOASTVALUE: + case RELKIND_VIEW: (void) heap_reloptions(rel->rd_rel->relkind, newOptions, true); break; case RELKIND_INDEX: diff --git a/src/backend/commands/view.c b/src/backend/commands/view.c index b238199..2fd8cd0 100644 --- a/src/backend/commands/view.c +++ b/src/backend/commands/view.c @@ -32,6 +32,7 @@ #include "utils/builtins.h" #include "utils/lsyscache.h" #include "utils/rel.h" +#include "utils/syscache.h" static void checkViewTupleDesc(TupleDesc newdesc, TupleDesc olddesc); @@ -98,7 +99,7 @@ isViewOnTempTable_walker(Node *node, void *context) */ static Oid DefineVirtualRelation(const RangeVar *relation, List *tlist, bool replace, - Oid namespaceId) + Oid namespaceId, List *options) { Oid viewOid; CreateStmt *createStmt = makeNode(CreateStmt); @@ -166,6 +167,8 @@ DefineVirtualRelation(const RangeVar *relation, List *tlist, bool replace, { Relation rel; TupleDesc descriptor; + List *atcmds = NIL; + AlterTableCmd *atcmd; /* * Yes. Get exclusive lock on the existing view ... @@ -210,14 +213,11 @@ DefineVirtualRelation(const RangeVar *relation, List *tlist, bool replace, */ if (list_length(attrList) > rel->rd_att->natts) { - List *atcmds = NIL; ListCell *c; int skip = rel->rd_att->natts; foreach(c, attrList) { - AlterTableCmd *atcmd; - if (skip > 0) { skip--; @@ -228,10 +228,25 @@ DefineVirtualRelation(const RangeVar *relation, List *tlist, bool replace, atcmd->def = (Node *) lfirst(c); atcmds = lappend(atcmds, atcmd); } - AlterTableInternal(viewOid, atcmds, true); } /* + * If view options were explicitly provided by users, + * existing values of the view being replaced are overrided, + * elseehere, rest of values shall be preserved, if exists. + */ + if (options != NIL) + { + atcmd = makeNode(AlterTableCmd); + atcmd->subtype = AT_SetRelOptions; + atcmd->def = (Node *)options; + atcmds = lappend(atcmds, atcmd); + } + + if (atcmds != NIL) + AlterTableInternal(viewOid, atcmds, true); + + /* * Seems okay, so return the OID of the pre-existing view. */ relation_close(rel, NoLock); /* keep the lock! */ @@ -255,6 +270,9 @@ DefineVirtualRelation(const RangeVar *relation, List *tlist, bool replace, createStmt->tablespacename = NULL; createStmt->if_not_exists = false; + if (options != NIL) + createStmt->options = list_concat(createStmt->options, options); + /* * finally create the relation (this will error out if there's an * existing view, so we don't need more code to complain if "replace" @@ -513,7 +531,7 @@ DefineView(ViewStmt *stmt, const char *queryString) * aborted. */ viewOid = DefineVirtualRelation(view, viewParse->targetList, - stmt->replace, namespaceId); + stmt->replace, namespaceId, stmt->options); /* * The relation we have just created is not visible to any other commands diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c index c70a5bd..dd809ef 100644 --- a/src/backend/nodes/copyfuncs.c +++ b/src/backend/nodes/copyfuncs.c @@ -1965,6 +1965,7 @@ _copyRangeTblEntry(RangeTblEntry *from) COPY_SCALAR_FIELD(relid); COPY_SCALAR_FIELD(relkind); COPY_NODE_FIELD(subquery); + COPY_SCALAR_FIELD(security_barrier); COPY_SCALAR_FIELD(jointype); COPY_NODE_FIELD(joinaliasvars); COPY_NODE_FIELD(funcexpr); diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c index f490a7a..4fe94de 100644 --- a/src/backend/nodes/equalfuncs.c +++ b/src/backend/nodes/equalfuncs.c @@ -2228,6 +2228,7 @@ _equalRangeTblEntry(RangeTblEntry *a, RangeTblEntry *b) COMPARE_SCALAR_FIELD(relid); COMPARE_SCALAR_FIELD(relkind); COMPARE_NODE_FIELD(subquery); + COMPARE_SCALAR_FIELD(security_barrier); COMPARE_SCALAR_FIELD(jointype); COMPARE_NODE_FIELD(joinaliasvars); COMPARE_NODE_FIELD(funcexpr); diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c index 31af47f..85e3219 100644 --- a/src/backend/nodes/outfuncs.c +++ b/src/backend/nodes/outfuncs.c @@ -2321,6 +2321,7 @@ _outRangeTblEntry(StringInfo str, RangeTblEntry *node) break; case RTE_SUBQUERY: WRITE_NODE_FIELD(subquery); + WRITE_BOOL_FIELD(security_barrier); break; case RTE_JOIN: WRITE_ENUM_FIELD(jointype, JoinType); diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c index 3de20ad..fa9ad16 100644 --- a/src/backend/nodes/readfuncs.c +++ b/src/backend/nodes/readfuncs.c @@ -1192,6 +1192,7 @@ _readRangeTblEntry(void) break; case RTE_SUBQUERY: READ_NODE_FIELD(subquery); + READ_BOOL_FIELD(security_barrier); break; case RTE_JOIN: READ_ENUM_FIELD(jointype, JoinType); diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c index 815b996..288cca3 100644 --- a/src/backend/optimizer/path/allpaths.c +++ b/src/backend/optimizer/path/allpaths.c @@ -744,6 +744,12 @@ set_subquery_pathlist(PlannerInfo *root, RelOptInfo *rel, * pseudoconstant clauses; better to have the gating node above the * subquery. * + * In the case when the sub-query has "security_barrier" flag, it means + * the sub-query originated from a particular view that was defined for + * row-level security purpose. Thus, we need to take care the order to + * launch qualifiers to avoid accidental information leaks using functions + * with side-effects, in this situation. + * * Non-pushed-down clauses will get evaluated as qpquals of the * SubqueryScan node. * @@ -763,6 +769,7 @@ set_subquery_pathlist(PlannerInfo *root, RelOptInfo *rel, Node *clause = (Node *) rinfo->clause; if (!rinfo->pseudoconstant && + !rte->security_barrier && qual_is_pushdown_safe(subquery, rti, clause, differentTypes)) { /* Push it down */ diff --git a/src/backend/optimizer/prep/prepjointree.c b/src/backend/optimizer/prep/prepjointree.c index 8bb011b..35ed887 100644 --- a/src/backend/optimizer/prep/prepjointree.c +++ b/src/backend/optimizer/prep/prepjointree.c @@ -543,6 +543,7 @@ pull_up_subqueries(PlannerInfo *root, Node *jtnode, */ if (rte->rtekind == RTE_SUBQUERY && is_simple_subquery(rte->subquery) && + !rte->security_barrier && (containing_appendrel == NULL || is_safe_append_member(rte->subquery))) return pull_up_simple_subquery(root, jtnode, rte, diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 2a497d1..9c792eb 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -7281,26 +7281,28 @@ transaction_mode_list_or_empty: * *****************************************************************************/ -ViewStmt: CREATE OptTemp VIEW qualified_name opt_column_list +ViewStmt: CREATE OptTemp VIEW qualified_name opt_column_list opt_reloptions AS SelectStmt opt_check_option { ViewStmt *n = makeNode(ViewStmt); n->view = $4; n->view->relpersistence = $2; n->aliases = $5; - n->query = $7; + n->query = $8; n->replace = false; + n->options = $6; $$ = (Node *) n; } - | CREATE OR REPLACE OptTemp VIEW qualified_name opt_column_list + | CREATE OR REPLACE OptTemp VIEW qualified_name opt_column_list opt_reloptions AS SelectStmt opt_check_option { ViewStmt *n = makeNode(ViewStmt); n->view = $6; n->view->relpersistence = $4; n->aliases = $7; - n->query = $9; + n->query = $10; n->replace = true; + n->options = $8; $$ = (Node *) n; } ; diff --git a/src/backend/rewrite/rewriteHandler.c b/src/backend/rewrite/rewriteHandler.c index a6f4141..8448226 100644 --- a/src/backend/rewrite/rewriteHandler.c +++ b/src/backend/rewrite/rewriteHandler.c @@ -1382,6 +1382,7 @@ ApplyRetrieveRule(Query *parsetree, rte->rtekind = RTE_SUBQUERY; rte->relid = InvalidOid; + rte->security_barrier = RelationIsSecurityView(relation); rte->subquery = rule_action; rte->inh = false; /* must not be set for a subquery */ diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c index 603e4c1..d93e079 100644 --- a/src/backend/utils/cache/relcache.c +++ b/src/backend/utils/cache/relcache.c @@ -374,6 +374,7 @@ RelationParseRelOptions(Relation relation, HeapTuple tuple) case RELKIND_RELATION: case RELKIND_TOASTVALUE: case RELKIND_INDEX: + case RELKIND_VIEW: break; default: return; diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c index 916939c..d09a862 100644 --- a/src/bin/pg_dump/pg_dump.c +++ b/src/bin/pg_dump/pg_dump.c @@ -12291,8 +12291,10 @@ dumpTableSchema(Archive *fout, TableInfo *tbinfo) if (binary_upgrade) binary_upgrade_set_pg_class_oids(q, tbinfo->dobj.catId.oid, false); - appendPQExpBuffer(q, "CREATE VIEW %s AS\n %s\n", - fmtId(tbinfo->dobj.name), viewdef); + appendPQExpBuffer(q, "CREATE VIEW %s", fmtId(tbinfo->dobj.name)); + if (tbinfo->reloptions && strlen(tbinfo->reloptions) > 0) + appendPQExpBuffer(q, " WITH (%s)", tbinfo->reloptions); + appendPQExpBuffer(q, " AS\n %s\n", viewdef); appendPQExpBuffer(labelq, "VIEW %s", fmtId(tbinfo->dobj.name)); diff --git a/src/include/access/reloptions.h b/src/include/access/reloptions.h index 14f5034..57595b0 100644 --- a/src/include/access/reloptions.h +++ b/src/include/access/reloptions.h @@ -42,8 +42,9 @@ typedef enum relopt_kind RELOPT_KIND_GIST = (1 << 5), RELOPT_KIND_ATTRIBUTE = (1 << 6), RELOPT_KIND_TABLESPACE = (1 << 7), + RELOPT_KIND_VIEW = (1 << 8), /* if you add a new kind, make sure you update "last_default" too */ - RELOPT_KIND_LAST_DEFAULT = RELOPT_KIND_TABLESPACE, + RELOPT_KIND_LAST_DEFAULT = RELOPT_KIND_VIEW, /* some compilers treat enums as signed ints, so we can't use 1 << 31 */ RELOPT_KIND_MAX = (1 << 30) } relopt_kind; diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 9e277c5..1880e8a 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -707,6 +707,10 @@ typedef struct RangeTblEntry */ Query *subquery; /* the sub-query */ + bool security_barrier; /* True, if the sub-query was originated + * from a view with security-barrier + * attribute. False, elsewhere. + */ /* * Fields valid for a join RTE (else NULL/zero): * @@ -2275,6 +2279,7 @@ typedef struct ViewStmt List *aliases; /* target column names */ Node *query; /* the SELECT query */ bool replace; /* replace an existing view? */ + List *options; /* options from WITH clause */ } ViewStmt; /* ---------------------- diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h index 173dc16..c2961da 100644 --- a/src/include/utils/rel.h +++ b/src/include/utils/rel.h @@ -194,6 +194,7 @@ typedef struct StdRdOptions int32 vl_len_; /* varlena header (do not touch directly!) */ int fillfactor; /* page fill factor in percent (0..100) */ AutoVacOpts autovacuum; /* autovacuum-related options */ + bool security_barrier; /* performs as security-barrier view */ } StdRdOptions; #define HEAP_MIN_FILLFACTOR 10 @@ -222,6 +223,14 @@ typedef struct StdRdOptions (BLCKSZ * (100 - RelationGetFillFactor(relation, defaultff)) / 100) /* + * RelationIsSecurityView + * Returns whether the relation is security view, or not + */ +#define RelationIsSecurityView(relation) \ + ((relation)->rd_options ? \ + ((StdRdOptions *) (relation)->rd_options)->security_barrier : false) + +/* * RelationIsValid * True iff relation descriptor is valid. */ diff --git a/src/test/regress/expected/create_view.out b/src/test/regress/expected/create_view.out index f9490a3..432642a 100644 --- a/src/test/regress/expected/create_view.out +++ b/src/test/regress/expected/create_view.out @@ -239,6 +239,55 @@ And relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname LIKE 'pg_temp%') 1 (1 row) +-- +-- CREATE VIEW and WITH(...) clause +-- +CREATE VIEW mysecview1 + AS SELECT * FROM tbl1 WHERE a = 0; +CREATE VIEW mysecview2 WITH (security_barrier=true) + AS SELECT * FROM tbl1 WHERE a > 0; +CREATE VIEW mysecview3 WITH (security_barrier=false) + AS SELECT * FROM tbl1 WHERE a < 0; +CREATE VIEW mysecview4 WITH (security_barrier) + AS SELECT * FROM tbl1 WHERE a <> 0; +CREATE VIEW mysecview5 WITH (security_barrier=100) -- Error + AS SELECT * FROM tbl1 WHERE a > 100; +ERROR: invalid value for boolean option "security_barrier": 100 +CREATE VIEW mysecview6 WITH (invalid_option) -- Error + AS SELECT * FROM tbl1 WHERE a < 100; +ERROR: unrecognized parameter "invalid_option" +SELECT relname, relkind, reloptions FROM pg_class + WHERE oid in ('mysecview1'::regclass, 'mysecview2'::regclass, + 'mysecview3'::regclass, 'mysecview4'::regclass); + relname | relkind | reloptions +------------+---------+-------------------------- + mysecview1 | v | + mysecview2 | v | {security_barrier=true} + mysecview3 | v | {security_barrier=false} + mysecview4 | v | {security_barrier=true} +(4 rows) + +-- reloptions should be preserved +CREATE OR REPLACE VIEW mysecview1 + AS SELECT * FROM tbl1 WHERE a = 256; +CREATE OR REPLACE VIEW mysecview2 + AS SELECT * FROM tbl1 WHERE a > 256; +-- reloptions should be turned on/off +CREATE OR REPLACE VIEW mysecview3 WITH (security_barrier=true) + AS SELECT * FROM tbl1 WHERE a < 256; +CREATE OR REPLACE VIEW mysecview4 WITH (security_barrier=false) + AS SELECT * FROM tbl1 WHERE a <> 256; +SELECT relname, relkind, reloptions FROM pg_class + WHERE oid in ('mysecview1'::regclass, 'mysecview2'::regclass, + 'mysecview3'::regclass, 'mysecview4'::regclass); + relname | relkind | reloptions +------------+---------+-------------------------- + mysecview1 | v | + mysecview2 | v | {security_barrier=true} + mysecview3 | v | {security_barrier=true} + mysecview4 | v | {security_barrier=false} +(4 rows) + DROP SCHEMA temp_view_test CASCADE; NOTICE: drop cascades to 22 other objects DETAIL: drop cascades to table temp_view_test.base_table @@ -264,7 +313,7 @@ drop cascades to view temp_view_test.v8 drop cascades to sequence temp_view_test.seq1 drop cascades to view temp_view_test.v9 DROP SCHEMA testviewschm2 CASCADE; -NOTICE: drop cascades to 16 other objects +NOTICE: drop cascades to 20 other objects DETAIL: drop cascades to table t1 drop cascades to view temporal1 drop cascades to view temporal2 @@ -281,4 +330,8 @@ drop cascades to table tbl3 drop cascades to table tbl4 drop cascades to view mytempview drop cascades to view pubview +drop cascades to view mysecview1 +drop cascades to view mysecview2 +drop cascades to view mysecview3 +drop cascades to view mysecview4 SET search_path to public; diff --git a/src/test/regress/expected/select_views_1.out b/src/test/regress/expected/select_views_1.out index 9a972cf..c6f75af 100644 --- a/src/test/regress/expected/select_views_1.out +++ b/src/test/regress/expected/select_views_1.out @@ -1247,3 +1247,258 @@ SELECT * FROM toyemp WHERE name = 'sharon'; sharon | 25 | (15,12) | 12000 (1 row) +-- +-- Test for Leaky view scenario +-- +CREATE USER alice; +CREATE FUNCTION f_leak (text) + RETURNS bool LANGUAGE 'plpgsql' COST 0.0000001 + AS 'BEGIN RAISE NOTICE ''f_leak => %'', $1; RETURN true; END'; +CREATE TABLE customer ( + cid int primary key, + name text not null, + tel text, + passwd text +); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "customer_pkey" for table "customer" +CREATE TABLE credit_card ( + cid int references customer(cid), + cnum text, + climit int +); +CREATE TABLE credit_usage ( + cid int references customer(cid), + ymd date, + usage int +); +INSERT INTO customer + VALUES (101, 'alice', '+81-12-3456-7890', 'passwd123'), + (102, 'bob', '+01-234-567-8901', 'beafsteak'), + (103, 'eve', '+49-8765-43210', 'hamburger'); +INSERT INTO credit_card + VALUES (101, '1111-2222-3333-4444', 4000), + (102, '5555-6666-7777-8888', 3000), + (103, '9801-2345-6789-0123', 2000); +INSERT INTO credit_usage + VALUES (101, '2011-09-15', 120), + (101, '2011-10-05', 90), + (101, '2011-10-18', 110), + (101, '2011-10-21', 200), + (101, '2011-11-10', 80), + (102, '2011-09-22', 300), + (102, '2011-10-12', 120), + (102, '2011-10-28', 200), + (103, '2011-10-15', 480); +CREATE VIEW my_property_normal AS + SELECT * FROM customer WHERE name = current_user; +CREATE VIEW my_property_secure WITH (security_barrier) AS + SELECT * FROM customer WHERE name = current_user; +CREATE VIEW my_credit_card_normal AS + SELECT * FROM customer l NATURAL JOIN credit_card r + WHERE l.name = current_user; +CREATE VIEW my_credit_card_secure WITH (security_barrier) AS + SELECT * FROM customer l NATURAL JOIN credit_card r + WHERE l.name = current_user; +CREATE VIEW my_credit_card_usage_normal AS + SELECT * FROM my_credit_card_secure l NATURAL JOIN credit_usage r; +CREATE VIEW my_credit_card_usage_secure WITH (security_barrier) AS + SELECT * FROM my_credit_card_secure l NATURAL JOIN credit_usage r; +GRANT SELECT ON my_property_normal TO public; +GRANT SELECT ON my_property_secure TO public; +GRANT SELECT ON my_credit_card_normal TO public; +GRANT SELECT ON my_credit_card_secure TO public; +GRANT SELECT ON my_credit_card_usage_normal TO public; +GRANT SELECT ON my_credit_card_usage_secure TO public; +-- +-- Run leaky view scenarios +-- +SET SESSION AUTHORIZATION alice; +-- +-- scenario: if a qualifier with tiny-cost is given, it shall be launched +-- prior to the security policy of the view. +-- +SELECT * FROM my_property_normal WHERE f_leak(passwd); +NOTICE: f_leak => passwd123 +NOTICE: f_leak => beafsteak +NOTICE: f_leak => hamburger + cid | name | tel | passwd +-----+-------+------------------+----------- + 101 | alice | +81-12-3456-7890 | passwd123 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM my_property_normal WHERE f_leak(passwd); + QUERY PLAN +------------------------------------------------------------------ + Seq Scan on customer + Filter: (f_leak(passwd) AND (name = ("current_user"())::text)) +(2 rows) + +SELECT * FROM my_property_secure WHERE f_leak(passwd); +NOTICE: f_leak => passwd123 + cid | name | tel | passwd +-----+-------+------------------+----------- + 101 | alice | +81-12-3456-7890 | passwd123 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM my_property_secure WHERE f_leak(passwd); + QUERY PLAN +--------------------------------------------------- + Subquery Scan on my_property_secure + Filter: f_leak(my_property_secure.passwd) + -> Seq Scan on customer + Filter: (name = ("current_user"())::text) +(4 rows) + +-- +-- scenario: if a qualifier references only one-side of a particular join- +-- tree, it shall be distributed to the most deep scan plan as +-- possible as we can. +-- +SELECT * FROM my_credit_card_normal WHERE f_leak(cnum); +NOTICE: f_leak => 1111-2222-3333-4444 +NOTICE: f_leak => 5555-6666-7777-8888 +NOTICE: f_leak => 9801-2345-6789-0123 + cid | name | tel | passwd | cnum | climit +-----+-------+------------------+-----------+---------------------+-------- + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_normal WHERE f_leak(cnum); + QUERY PLAN +--------------------------------------------------------- + Hash Join + Hash Cond: (r.cid = l.cid) + -> Seq Scan on credit_card r + Filter: f_leak(cnum) + -> Hash + -> Seq Scan on customer l + Filter: (name = ("current_user"())::text) +(7 rows) + +SELECT * FROM my_credit_card_secure WHERE f_leak(cnum); +NOTICE: f_leak => 1111-2222-3333-4444 + cid | name | tel | passwd | cnum | climit +-----+-------+------------------+-----------+---------------------+-------- + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_secure WHERE f_leak(cnum); + QUERY PLAN +--------------------------------------------------------------- + Subquery Scan on my_credit_card_secure + Filter: f_leak(my_credit_card_secure.cnum) + -> Hash Join + Hash Cond: (r.cid = l.cid) + -> Seq Scan on credit_card r + -> Hash + -> Seq Scan on customer l + Filter: (name = ("current_user"())::text) +(8 rows) + +-- +-- scenario: an external qualifier can be pushed-down by in-front-of the +-- views with "security_barrier" attribute +-- +SELECT * FROM my_credit_card_usage_normal + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; +NOTICE: f_leak => 1111-2222-3333-4444 + cid | name | tel | passwd | cnum | climit | ymd | usage +-----+-------+------------------+-----------+---------------------+--------+------------+------- + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 | 10-05-2011 | 90 + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 | 10-18-2011 | 110 + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 | 10-21-2011 | 200 +(3 rows) + +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_usage_normal + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; + QUERY PLAN +------------------------------------------------------------------------------ + Nested Loop + Join Filter: (l.cid = r.cid) + -> Seq Scan on credit_usage r + Filter: ((ymd >= '10-01-2011'::date) AND (ymd < '11-01-2011'::date)) + -> Materialize + -> Subquery Scan on l + Filter: f_leak(l.cnum) + -> Hash Join + Hash Cond: (r.cid = l.cid) + -> Seq Scan on credit_card r + -> Hash + -> Seq Scan on customer l + Filter: (name = ("current_user"())::text) +(13 rows) + +SELECT * FROM my_credit_card_usage_secure + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; +NOTICE: f_leak => 1111-2222-3333-4444 +NOTICE: f_leak => 1111-2222-3333-4444 +NOTICE: f_leak => 1111-2222-3333-4444 +NOTICE: f_leak => 1111-2222-3333-4444 +NOTICE: f_leak => 1111-2222-3333-4444 + cid | name | tel | passwd | cnum | climit | ymd | usage +-----+-------+------------------+-----------+---------------------+--------+------------+------- + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 | 10-05-2011 | 90 + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 | 10-18-2011 | 110 + 101 | alice | +81-12-3456-7890 | passwd123 | 1111-2222-3333-4444 | 4000 | 10-21-2011 | 200 +(3 rows) + +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_usage_secure + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Subquery Scan on my_credit_card_usage_secure + Filter: (f_leak(my_credit_card_usage_secure.cnum) AND (my_credit_card_usage_secure.ymd >= '10-01-2011'::date) AND (my_credit_card_usage_secure.ymd < '11-01-2011'::date)) + -> Hash Join + Hash Cond: (r.cid = l.cid) + -> Seq Scan on credit_usage r + -> Hash + -> Hash Join + Hash Cond: (r.cid = l.cid) + -> Seq Scan on credit_card r + -> Hash + -> Seq Scan on customer l + Filter: (name = ("current_user"())::text) +(12 rows) + +-- +-- Test for the case when security_barrier gets changed between rewriter +-- and planner stage. +-- +PREPARE p1 AS SELECT * FROM my_property_normal WHERE f_leak(passwd); +PREPARE p2 AS SELECT * FROM my_property_secure WHERE f_leak(passwd); +EXECUTE p1; +NOTICE: f_leak => passwd123 +NOTICE: f_leak => beafsteak +NOTICE: f_leak => hamburger + cid | name | tel | passwd +-----+-------+------------------+----------- + 101 | alice | +81-12-3456-7890 | passwd123 +(1 row) + +EXECUTE p2; +NOTICE: f_leak => passwd123 + cid | name | tel | passwd +-----+-------+------------------+----------- + 101 | alice | +81-12-3456-7890 | passwd123 +(1 row) + +RESET SESSION AUTHORIZATION; +ALTER VIEW my_property_normal SET (security_barrier=true); +ALTER VIEW my_property_secure SET (security_barrier=false); +SET SESSION AUTHORIZATION alice; +EXECUTE p1; -- To be perform as a view with security-barrier +NOTICE: f_leak => passwd123 + cid | name | tel | passwd +-----+-------+------------------+----------- + 101 | alice | +81-12-3456-7890 | passwd123 +(1 row) + +EXECUTE p2; -- To be perform as a view without security-barrier +NOTICE: f_leak => passwd123 +NOTICE: f_leak => beafsteak +NOTICE: f_leak => hamburger + cid | name | tel | passwd +-----+-------+------------------+----------- + 101 | alice | +81-12-3456-7890 | passwd123 +(1 row) + diff --git a/src/test/regress/sql/create_view.sql b/src/test/regress/sql/create_view.sql index 86cfc51..657e676 100644 --- a/src/test/regress/sql/create_view.sql +++ b/src/test/regress/sql/create_view.sql @@ -191,6 +191,38 @@ AND NOT EXISTS (SELECT g FROM tbl4 LEFT JOIN tmptbl ON tbl4.h = tmptbl.j); SELECT count(*) FROM pg_class where relname LIKE 'mytempview' And relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname LIKE 'pg_temp%'); +-- +-- CREATE VIEW and WITH(...) clause +-- +CREATE VIEW mysecview1 + AS SELECT * FROM tbl1 WHERE a = 0; +CREATE VIEW mysecview2 WITH (security_barrier=true) + AS SELECT * FROM tbl1 WHERE a > 0; +CREATE VIEW mysecview3 WITH (security_barrier=false) + AS SELECT * FROM tbl1 WHERE a < 0; +CREATE VIEW mysecview4 WITH (security_barrier) + AS SELECT * FROM tbl1 WHERE a <> 0; +CREATE VIEW mysecview5 WITH (security_barrier=100) -- Error + AS SELECT * FROM tbl1 WHERE a > 100; +CREATE VIEW mysecview6 WITH (invalid_option) -- Error + AS SELECT * FROM tbl1 WHERE a < 100; +SELECT relname, relkind, reloptions FROM pg_class + WHERE oid in ('mysecview1'::regclass, 'mysecview2'::regclass, + 'mysecview3'::regclass, 'mysecview4'::regclass); +-- reloptions should be preserved +CREATE OR REPLACE VIEW mysecview1 + AS SELECT * FROM tbl1 WHERE a = 256; +CREATE OR REPLACE VIEW mysecview2 + AS SELECT * FROM tbl1 WHERE a > 256; +-- reloptions should be turned on/off +CREATE OR REPLACE VIEW mysecview3 WITH (security_barrier=true) + AS SELECT * FROM tbl1 WHERE a < 256; +CREATE OR REPLACE VIEW mysecview4 WITH (security_barrier=false) + AS SELECT * FROM tbl1 WHERE a <> 256; +SELECT relname, relkind, reloptions FROM pg_class + WHERE oid in ('mysecview1'::regclass, 'mysecview2'::regclass, + 'mysecview3'::regclass, 'mysecview4'::regclass); + DROP SCHEMA temp_view_test CASCADE; DROP SCHEMA testviewschm2 CASCADE; diff --git a/src/test/regress/sql/select_views.sql b/src/test/regress/sql/select_views.sql index 14f1be8..4b2dac9 100644 --- a/src/test/regress/sql/select_views.sql +++ b/src/test/regress/sql/select_views.sql @@ -8,3 +8,129 @@ SELECT * FROM street; SELECT name, #thepath FROM iexit ORDER BY 1, 2; SELECT * FROM toyemp WHERE name = 'sharon'; + +-- +-- Test for Leaky view scenario +-- +CREATE USER alice; + +CREATE FUNCTION f_leak (text) + RETURNS bool LANGUAGE 'plpgsql' COST 0.0000001 + AS 'BEGIN RAISE NOTICE ''f_leak => %'', $1; RETURN true; END'; + +CREATE TABLE customer ( + cid int primary key, + name text not null, + tel text, + passwd text +); + +CREATE TABLE credit_card ( + cid int references customer(cid), + cnum text, + climit int +); + +CREATE TABLE credit_usage ( + cid int references customer(cid), + ymd date, + usage int +); + +INSERT INTO customer + VALUES (101, 'alice', '+81-12-3456-7890', 'passwd123'), + (102, 'bob', '+01-234-567-8901', 'beafsteak'), + (103, 'eve', '+49-8765-43210', 'hamburger'); +INSERT INTO credit_card + VALUES (101, '1111-2222-3333-4444', 4000), + (102, '5555-6666-7777-8888', 3000), + (103, '9801-2345-6789-0123', 2000); +INSERT INTO credit_usage + VALUES (101, '2011-09-15', 120), + (101, '2011-10-05', 90), + (101, '2011-10-18', 110), + (101, '2011-10-21', 200), + (101, '2011-11-10', 80), + (102, '2011-09-22', 300), + (102, '2011-10-12', 120), + (102, '2011-10-28', 200), + (103, '2011-10-15', 480); + +CREATE VIEW my_property_normal AS + SELECT * FROM customer WHERE name = current_user; +CREATE VIEW my_property_secure WITH (security_barrier) AS + SELECT * FROM customer WHERE name = current_user; + +CREATE VIEW my_credit_card_normal AS + SELECT * FROM customer l NATURAL JOIN credit_card r + WHERE l.name = current_user; +CREATE VIEW my_credit_card_secure WITH (security_barrier) AS + SELECT * FROM customer l NATURAL JOIN credit_card r + WHERE l.name = current_user; + +CREATE VIEW my_credit_card_usage_normal AS + SELECT * FROM my_credit_card_secure l NATURAL JOIN credit_usage r; +CREATE VIEW my_credit_card_usage_secure WITH (security_barrier) AS + SELECT * FROM my_credit_card_secure l NATURAL JOIN credit_usage r; + +GRANT SELECT ON my_property_normal TO public; +GRANT SELECT ON my_property_secure TO public; +GRANT SELECT ON my_credit_card_normal TO public; +GRANT SELECT ON my_credit_card_secure TO public; +GRANT SELECT ON my_credit_card_usage_normal TO public; +GRANT SELECT ON my_credit_card_usage_secure TO public; + +-- +-- Run leaky view scenarios +-- +SET SESSION AUTHORIZATION alice; + +-- +-- scenario: if a qualifier with tiny-cost is given, it shall be launched +-- prior to the security policy of the view. +-- +SELECT * FROM my_property_normal WHERE f_leak(passwd); +EXPLAIN (COSTS OFF) SELECT * FROM my_property_normal WHERE f_leak(passwd); + +SELECT * FROM my_property_secure WHERE f_leak(passwd); +EXPLAIN (COSTS OFF) SELECT * FROM my_property_secure WHERE f_leak(passwd); + +-- +-- scenario: if a qualifier references only one-side of a particular join- +-- tree, it shall be distributed to the most deep scan plan as +-- possible as we can. +-- +SELECT * FROM my_credit_card_normal WHERE f_leak(cnum); +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_normal WHERE f_leak(cnum); + +SELECT * FROM my_credit_card_secure WHERE f_leak(cnum); +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_secure WHERE f_leak(cnum); + +-- +-- scenario: an external qualifier can be pushed-down by in-front-of the +-- views with "security_barrier" attribute +-- +SELECT * FROM my_credit_card_usage_normal + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_usage_normal + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; + +SELECT * FROM my_credit_card_usage_secure + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; +EXPLAIN (COSTS OFF) SELECT * FROM my_credit_card_usage_secure + WHERE f_leak(cnum) AND ymd >= '2011-10-01' AND ymd < '2011-11-01'; + +-- +-- Test for the case when security_barrier gets changed between rewriter +-- and planner stage. +-- +PREPARE p1 AS SELECT * FROM my_property_normal WHERE f_leak(passwd); +PREPARE p2 AS SELECT * FROM my_property_secure WHERE f_leak(passwd); +EXECUTE p1; +EXECUTE p2; +RESET SESSION AUTHORIZATION; +ALTER VIEW my_property_normal SET (security_barrier=true); +ALTER VIEW my_property_secure SET (security_barrier=false); +SET SESSION AUTHORIZATION alice; +EXECUTE p1; -- To be perform as a view with security-barrier +EXECUTE p2; -- To be perform as a view without security-barrier