On Wed, 21 Aug 2024 at 10:08, jian he <jian.universality@gmail.com> wrote:
>
> the following setup is extract from src/test/regress/sql/updatable_views.sql
> you can search keywords: "-- ordinary view on top of security invoker
> view permissions"
>
> CREATE TABLE base_tbl(a int, b text, c float);
> INSERT INTO base_tbl VALUES (1, 'Row 1', 1.0);
>
> SET SESSION AUTHORIZATION regress_view_user1;
> CREATE VIEW rw_view1 AS SELECT b AS bb, c AS cc, a AS aa FROM base_tbl;
> ALTER VIEW rw_view1 SET (security_invoker = true);
>
> RESET SESSION AUTHORIZATION;
> GRANT SELECT(a,b) ON base_tbl TO regress_view_user1;
In updatable_views.sql that GRANT is actually
GRANT SELECT ON base_tbl TO regress_view_user1;
Without that, the view is effectively unusable by regress_view_user1
because it selects from column c of base_tbl, and regress_view_user1
lacks permissions on that column.
This is consistent with simple subqueries:
select a, b from (select a,b from base_tbl); -- ok
a | b
---+-------
1 | Row 1
(1 row)
select a, b from (select a,b,c from base_tbl); -- not allowed
ERROR: permission denied for table base_tbl
The user must have select permissions on all columns selected by the
subquery/view, because we don't go through the outer query to check
which columns are actually referred to. Now maybe we could, but I
suspect that would be quite a lot of effort because you'd need to be
sure that the column wasn't referred to anywhere in either the outer
query or the subquery itself (e.g., in WHERE clauses, etc.).
Regards,
Dean