├── .gitignore ├── check_access.control ├── Makefile ├── README.md └── sql ├── check_grants.sql └── check_access.sql /.gitignore: -------------------------------------------------------------------------------- 1 | ignore/* 2 | *.swp 3 | *.swo 4 | .deps/* 5 | *.o 6 | *.so 7 | sql/*.sql 8 | !sql/check_access.sql 9 | !sql/check_grants.sql 10 | 11 | -------------------------------------------------------------------------------- /check_access.control: -------------------------------------------------------------------------------- 1 | comment = 'Functions and views to facilitate PostgreSQL object access inspection' 2 | default_version = '0.1' 3 | relocatable = false 4 | 5 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = check_access 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \ 3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 4 | 5 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 6 | #DOCS = $(wildcard doc/*.md) 7 | PG_CONFIG = pg_config 8 | PG94 = $(shell $(PG_CONFIG) --version | egrep " 8\.| 9\.0| 9\.1| 9\.2| 9\.3" > /dev/null && echo no || echo yes) 9 | 10 | ifeq ($(PG94),yes) 11 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 12 | 13 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql sql/check_grants.sql 14 | cat $^ > $@ 15 | 16 | DATA = $(wildcard updates/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 17 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql 18 | endif 19 | 20 | PGXS := $(shell $(PG_CONFIG) --pgxs) 21 | include $(PGXS) 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # crunchy_check_access 2 | Functions and views to facilitate PostgreSQL object access inspection 3 | 4 | ## Overview 5 | Typically install this script as the database superuser. 6 | 7 | Once installed, to find all user privileges in the database while ignoring the system catalog and information schema, do: 8 | ``` 9 | SELECT * FROM all_access() WHERE base_role != CURRENT_USER; 10 | ``` 11 | 12 | To find all user privileges in the database including the system catalog and information schema, do: 13 | ``` 14 | SELECT * FROM all_access(true) WHERE base_role != CURRENT_USER; 15 | ``` 16 | 17 | By default, execute has been revoked from PUBLIC on the installed functions except ```my_privs()``` and ```my_privs_sys()``` and their corresponding convenience views ```my_privs``` and ```my_privs_sys```. These functions/views allow users to discover their own privileges. 18 | 19 | Note that the privileges are discovered by recursing through all roles accessable via a ```GRANT```, including non-inherited ones (need to specifically use ```SET ROLE``` to escalate and gain said privilege). The source path to a given privilege shown in the output is available in the ```role_path``` column. Each ancestor in the ```role_path``` is tagged with either ```(true)``` or ```(false)``` to indicate if privileges are inherited by that role. 20 | 21 | ```base_role``` was the entry point (initially logged in user), while ```as_role``` shows the role with the actual privilege. 22 | 23 | The ```all_access``` and ```check_access``` report grants that actually authorize actions against the referenced object. For example, a role may be granted SELECT privileges but will not be reported by the access functions unless it also has usage privilege on the schema. To allow for reporting of all grants the ```all_grants``` and ```check_grants``` function was added. These functions will report all grants and are useful for entitlement and audit reporting. -------------------------------------------------------------------------------- /sql/check_grants.sql: -------------------------------------------------------------------------------- 1 | create or replace function @extschema@.check_grants 2 | ( 3 | in luser text, 4 | in incl_sys bool, 5 | inout role_path text, 6 | out base_role text, 7 | out as_role text, 8 | out objtype text, 9 | out objid oid, 10 | out schemaname text, 11 | out objname text, 12 | out privname text, 13 | out grantable bool 14 | ) returns setof record 15 | as $$ 16 | declare 17 | schemaoid oid; 18 | colnum int; 19 | colrelname text; 20 | colname text; 21 | minatt text; 22 | priv text; 23 | grantopt text:= ' WITH GRANT OPTION'; 24 | grpname text; 25 | inh text; 26 | brole_path text; 27 | rec record; 28 | 29 | db_privs text[] := ARRAY['CREATE', 'CONNECT', 'TEMPORARY', 'TEMP']; 30 | tblspc_privs text[] := ARRAY['CREATE']; 31 | fdw_privs text[] := ARRAY['USAGE']; 32 | fdwsrv_privs text[] := ARRAY['USAGE']; 33 | lang_privs text[] := ARRAY['USAGE']; 34 | schema_privs text[] := ARRAY['CREATE', 'USAGE']; 35 | table_privs text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER']; 36 | column_privs text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'REFERENCES']; 37 | seq_privs text[] := ARRAY['USAGE', 'SELECT', 'UPDATE']; 38 | func_privs text[] := ARRAY['EXECUTE']; 39 | with_grant text[] := ARRAY['', ' WITH GRANT OPTION']; 40 | 41 | schemas_to_skip text; 42 | 43 | begin 44 | schemaname := NULL; 45 | 46 | if (role_path is null) then 47 | role_path := luser; 48 | end if; 49 | 50 | base_role := luser; 51 | as_role := luser; 52 | 53 | if (incl_sys) then 54 | schemas_to_skip := ''; 55 | else 56 | schemas_to_skip := $_$ where n.nspname !~ '^pg_' AND n.nspname not in ('information_schema')$_$; 57 | end if; 58 | 59 | -- check database privs 60 | objtype := 'database'; 61 | objid := oid from pg_database where datname = current_database(); 62 | objname := current_database()::text; 63 | foreach priv in array db_privs loop 64 | if (has_database_privilege(luser, current_database(), priv)) then 65 | privname := priv; 66 | grantable := has_database_privilege(luser, current_database(), priv || grantopt); 67 | return next; 68 | end if; 69 | end loop; 70 | 71 | -- check tablespace privs 72 | objtype := 'tablespace'; 73 | for objid, objname in select t.oid, t.spcname from pg_catalog.pg_tablespace t where t.spcname !~ '^pg_' order by 2,1 loop 74 | foreach priv in array tblspc_privs loop 75 | if (has_tablespace_privilege(luser, objname, priv)) then 76 | privname := priv; 77 | grantable := has_database_privilege(luser, objname, priv || grantopt); 78 | return next; 79 | end if; 80 | end loop; 81 | end loop; 82 | 83 | -- check foreign data wrapper privs 84 | objtype := 'fdw'; 85 | for objid, objname in select f.oid, f.fdwname from pg_catalog.pg_foreign_data_wrapper f order by 2,1 loop 86 | foreach priv in array fdw_privs loop 87 | if (has_foreign_data_wrapper_privilege(luser, objname, priv)) then 88 | privname := priv; 89 | grantable := has_foreign_data_wrapper_privilege(luser, objname, priv || grantopt); 90 | return next; 91 | end if; 92 | end loop; 93 | end loop; 94 | 95 | -- check foreign server privs 96 | objtype := 'server'; 97 | for objid, objname in select s.oid, s.srvname from pg_catalog.pg_foreign_server s order by 2,1 loop 98 | foreach priv in array fdwsrv_privs loop 99 | if (has_server_privilege(luser, objname, priv)) then 100 | privname := priv; 101 | grantable := has_server_privilege(luser, objname, priv || grantopt); 102 | return next; 103 | end if; 104 | end loop; 105 | end loop; 106 | 107 | -- check language privs 108 | objtype := 'language'; 109 | for objid, objname in select l.oid, l.lanname from pg_catalog.pg_language l order by 2,1 loop 110 | foreach priv in array lang_privs loop 111 | if (has_language_privilege(luser, objname, priv)) then 112 | -- still might not be true ... 113 | -- if a superuser, or language is trusted, we really do have access 114 | if ((select rolsuper from pg_catalog.pg_authid where rolname = luser) or 115 | (select l.lanpltrusted from pg_catalog.pg_language l where l.oid = objid)) then 116 | privname := priv; 117 | grantable := has_language_privilege(luser, objname, priv || grantopt); 118 | return next; 119 | end if; 120 | end if; 121 | end loop; 122 | end loop; 123 | 124 | -- check schema privs 125 | for schemaoid, schemaname in execute 'select n.oid, n.nspname::text from pg_catalog.pg_namespace n' || schemas_to_skip || ' order by 2,1' loop 126 | objtype := 'schema'; 127 | objid := schemaoid; 128 | objname := schemaname; 129 | foreach priv in array schema_privs loop 130 | if (has_schema_privilege(luser, schemaname, priv)) then 131 | privname := priv; 132 | grantable := has_schema_privilege(luser, schemaname, priv || grantopt); 133 | return next; 134 | end if; 135 | end loop; 136 | 137 | -- check function privs 138 | objtype := 'function'; 139 | for objid, objname in select p.oid, p.proname || '(' || proargtypes::text || ')' from pg_catalog.pg_proc p where p.pronamespace = schemaoid order by 2,1 loop 140 | foreach priv in array func_privs loop 141 | if (has_function_privilege(luser, objid, priv)) then 142 | privname := priv; 143 | grantable := has_function_privilege(luser, objid, priv || grantopt); 144 | return next; 145 | end if; 146 | end loop; 147 | end loop; 148 | 149 | -- check table privs 150 | for objid, objname in select c.oid, c.relname from pg_catalog.pg_class c where c.relnamespace = schemaoid and relkind in ('r') order by 2,1 loop 151 | foreach priv in array table_privs loop 152 | if (has_table_privilege(luser, objid, priv)) then 153 | objtype := 'table'; 154 | privname := priv; 155 | grantable := has_table_privilege(luser, objid, priv || grantopt); 156 | return next; 157 | else 158 | if priv = ANY (column_privs) then 159 | colrelname := objname; 160 | objtype := 'table.column'; 161 | if (has_any_column_privilege(luser, objid, priv)) then 162 | if (incl_sys) then 163 | minatt = ''; -- arbitrary, but ought to work for the forseeable future 164 | else 165 | minatt = ' and a.attnum > 0'; -- show only user columns 166 | end if; 167 | for colnum, colname in execute 168 | 'select a.attnum, a.attname from pg_catalog.pg_attribute a where a.attrelid = ' || objid::text || minatt || ' order by 1,2' loop 169 | if (has_column_privilege(luser, objid, colname, priv)) then 170 | objname := colrelname || '.' || colname; 171 | privname := priv; 172 | grantable := has_any_column_privilege(luser, objid, priv || grantopt); 173 | return next; 174 | end if; 175 | end loop; 176 | end if; 177 | objname := colrelname; 178 | end if; 179 | end if; 180 | end loop; 181 | end loop; 182 | 183 | -- check view privs 184 | for objid, objname in select c.oid, c.relname from pg_catalog.pg_class c where c.relnamespace = schemaoid and relkind in ('v') order by 2,1 loop 185 | foreach priv in array table_privs loop 186 | if (has_table_privilege(luser, objid, priv)) then 187 | objtype := 'view'; 188 | privname := priv; 189 | grantable := has_table_privilege(luser, objid, priv || grantopt); 190 | return next; 191 | else 192 | if priv = ANY (column_privs) then 193 | colrelname := objname; 194 | objtype := 'view.column'; 195 | if (has_any_column_privilege(luser, objid, priv)) then 196 | minatt = ' and a.attnum > 0'; -- VIEWs have no system columns 197 | for colnum, colname in execute 198 | 'select a.attnum, a.attname from pg_catalog.pg_attribute a where a.attrelid = ' || objid::text || minatt || ' order by 1,2' loop 199 | if (has_column_privilege(luser, objid, colname, priv)) then 200 | objname := colrelname || '.' || colname; 201 | privname := priv; 202 | grantable := has_column_privilege(luser, objid, colname, priv || grantopt); 203 | return next; 204 | end if; 205 | end loop; 206 | end if; 207 | objname := colrelname; 208 | end if; 209 | end if; 210 | end loop; 211 | end loop; 212 | 213 | -- check seq privs 214 | objtype := 'sequence'; 215 | for objid, objname in select c.oid, c.relname from pg_catalog.pg_class c where c.relnamespace = schemaoid and relkind in ('S') order by 2,1 loop 216 | foreach priv in array seq_privs loop 217 | if (has_sequence_privilege(luser, objid, priv)) then 218 | privname := priv; 219 | grantable := has_sequence_privilege(luser, objid, priv || grantopt); 220 | return next; 221 | end if; 222 | end loop; 223 | end loop; 224 | 225 | end loop; 226 | 227 | -- recurse into any granted roles 228 | brole_path := role_path; 229 | for grpname, inh in select a.rolname as group, '(' || u.rolinherit || ')' from pg_catalog.pg_authid a join pg_catalog.pg_auth_members m on a.oid = m.roleid join pg_authid u on m.member = u.oid where u.rolname = luser loop 230 | role_path := brole_path || inh || '.' || grpname; 231 | for rec in select * from @extschema@.check_grants(grpname, incl_sys, role_path) loop 232 | as_role := rec.as_role; 233 | role_path := rec.role_path; 234 | objtype := rec.objtype; 235 | objid := rec.objid; 236 | schemaname := rec.schemaname; 237 | objname := rec.objname; 238 | privname := rec.privname; 239 | grantable := rec.grantable; 240 | return next; 241 | end loop; 242 | end loop; 243 | 244 | return; 245 | end; 246 | $$ language plpgsql; 247 | 248 | revoke execute on function @extschema@.check_grants(text, bool, text) from public; 249 | 250 | create or replace function @extschema@.check_grants 251 | ( 252 | in luser text, 253 | in incl_sys bool, 254 | out role_path text, 255 | out base_role text, 256 | out as_role text, 257 | out objtype text, 258 | out objid oid, 259 | out schemaname text, 260 | out objname text, 261 | out privname text, 262 | out grantable bool 263 | ) 264 | returns setof record 265 | as $$ 266 | select * from @extschema@.check_grants($1, $2, NULL); 267 | $$ language sql; 268 | 269 | revoke execute on function @extschema@.check_grants(text, bool) from public; 270 | 271 | create or replace function @extschema@.all_grants 272 | ( 273 | in incl_sys bool, 274 | out role_path text, 275 | out base_role text, 276 | out as_role text, 277 | out objtype text, 278 | out objid oid, 279 | out schemaname text, 280 | out objname text, 281 | out privname text, 282 | out grantable bool 283 | ) 284 | returns setof record 285 | as $$ 286 | declare 287 | rec record; 288 | rname text; 289 | begin 290 | for rname in select a.rolname as group from pg_catalog.pg_authid a order by 1 loop 291 | for role_path, base_role, as_role, objtype, objid, schemaname, objname, privname, grantable in select * from @extschema@.check_grants(rname, incl_sys) loop 292 | return next; 293 | end loop; 294 | end loop; 295 | return; 296 | end; 297 | $$ language plpgsql; 298 | 299 | revoke execute on function @extschema@.all_grants(bool) from public; 300 | 301 | create or replace function @extschema@.all_grants 302 | ( 303 | out role_path text, 304 | out base_role text, 305 | out as_role text, 306 | out objtype text, 307 | out objid oid, 308 | out schemaname text, 309 | out objname text, 310 | out privname text, 311 | out grantable bool 312 | ) 313 | returns setof record 314 | as $$ 315 | select * from @extschema@.all_grants(false) 316 | $$ language sql; 317 | 318 | revoke execute on function @extschema@.all_grants() from public; 319 | -------------------------------------------------------------------------------- /sql/check_access.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * 3 | * Copyright 2015-2019 Crunchy Data Solutions, Inc. 4 | * Copyright 2009-2015 Joe Conway 5 | * 6 | * Permission to use, copy, modify, and distribute this software and its 7 | * documentation for any purpose, without fee, and without a written agreement 8 | * is hereby granted, provided that the above copyright notice and this 9 | * paragraph and the following two paragraphs appear in all copies. 10 | * 11 | * IN NO EVENT SHALL THE AUTHORS OR DISTRIBUTORS BE LIABLE TO ANY PARTY FOR 12 | * DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING 13 | * LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS 14 | * DOCUMENTATION, EVEN IF THE AUTHOR OR DISTRIBUTORS HAVE BEEN ADVISED OF THE 15 | * POSSIBILITY OF SUCH DAMAGE. 16 | * 17 | * THE AUTHORS AND DISTRIBUTORS SPECIFICALLY DISCLAIM ANY WARRANTIES, 18 | * INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY 19 | * AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS 20 | * ON AN "AS IS" BASIS, AND THE AUTHOR AND DISTRIBUTORS HAS NO OBLIGATIONS TO 21 | * PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 22 | * 23 | */ 24 | 25 | create or replace function @extschema@.check_access 26 | ( 27 | in luser text, 28 | in incl_sys bool, 29 | inout role_path text, 30 | out base_role text, 31 | out as_role text, 32 | out objtype text, 33 | out objid oid, 34 | out schemaname text, 35 | out objname text, 36 | out privname text 37 | ) returns setof record 38 | as $$ 39 | declare 40 | schemaoid oid; 41 | colnum int; 42 | colrelname text; 43 | colname text; 44 | minatt text; 45 | priv text; 46 | grantopt text; 47 | grpname text; 48 | inh text; 49 | brole_path text; 50 | rec record; 51 | 52 | db_privs text[] := ARRAY['CREATE', 'CONNECT', 'TEMPORARY', 'TEMP']; 53 | tblspc_privs text[] := ARRAY['CREATE']; 54 | fdw_privs text[] := ARRAY['USAGE']; 55 | fdwsrv_privs text[] := ARRAY['USAGE']; 56 | lang_privs text[] := ARRAY['USAGE']; 57 | schema_privs text[] := ARRAY['CREATE', 'USAGE']; 58 | table_privs text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER']; 59 | column_privs text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'REFERENCES']; 60 | seq_privs text[] := ARRAY['USAGE', 'SELECT', 'UPDATE']; 61 | func_privs text[] := ARRAY['EXECUTE']; 62 | with_grant text[] := ARRAY['', ' WITH GRANT OPTION']; 63 | 64 | -- domain privs? USAGE 65 | -- large object privs? SELECT | UPDATE 66 | -- has_type_privilege? USAGE 67 | 68 | schemas_to_skip text; 69 | 70 | begin 71 | schemaname := NULL; 72 | 73 | if (role_path is null) then 74 | role_path := luser; 75 | end if; 76 | 77 | base_role := luser; 78 | as_role := luser; 79 | 80 | if (incl_sys) then 81 | schemas_to_skip := ''; 82 | else 83 | schemas_to_skip := $_$ where n.nspname !~ '^pg_' AND n.nspname not in ('information_schema')$_$; 84 | end if; 85 | 86 | -- check database privs 87 | objtype := 'database'; 88 | objid := oid from pg_database where datname = current_database(); 89 | objname := current_database()::text; 90 | foreach grantopt in array with_grant loop 91 | foreach priv in array db_privs loop 92 | if (has_database_privilege(luser, current_database(), priv || grantopt)) then 93 | privname := priv || grantopt; 94 | return next; 95 | end if; 96 | end loop; 97 | end loop; 98 | 99 | -- check tablespace privs 100 | objtype := 'tablespace'; 101 | for objid, objname in select t.oid, t.spcname from pg_catalog.pg_tablespace t where t.spcname !~ '^pg_' order by 2,1 loop 102 | foreach grantopt in array with_grant loop 103 | foreach priv in array tblspc_privs loop 104 | if (has_tablespace_privilege(luser, objname, priv || grantopt)) then 105 | privname := priv || grantopt; 106 | return next; 107 | end if; 108 | end loop; 109 | end loop; 110 | end loop; 111 | 112 | -- check foreign data wrapper privs 113 | objtype := 'fdw'; 114 | for objid, objname in select f.oid, f.fdwname from pg_catalog.pg_foreign_data_wrapper f order by 2,1 loop 115 | foreach grantopt in array with_grant loop 116 | foreach priv in array fdw_privs loop 117 | if (has_foreign_data_wrapper_privilege(luser, objname, priv || grantopt)) then 118 | privname := priv || grantopt; 119 | return next; 120 | end if; 121 | end loop; 122 | end loop; 123 | end loop; 124 | 125 | -- check foreign server privs 126 | objtype := 'server'; 127 | for objid, objname in select s.oid, s.srvname from pg_catalog.pg_foreign_server s order by 2,1 loop 128 | foreach grantopt in array with_grant loop 129 | foreach priv in array fdwsrv_privs loop 130 | if (has_server_privilege(luser, objname, priv || grantopt)) then 131 | privname := priv || grantopt; 132 | return next; 133 | end if; 134 | end loop; 135 | end loop; 136 | end loop; 137 | 138 | -- check language privs 139 | objtype := 'language'; 140 | for objid, objname in select l.oid, l.lanname from pg_catalog.pg_language l order by 2,1 loop 141 | foreach grantopt in array with_grant loop 142 | foreach priv in array lang_privs loop 143 | if (has_language_privilege(luser, objname, priv || grantopt)) then 144 | -- still might not be true ... 145 | -- if a superuser, or language is trusted, we really do have access 146 | if ((select rolsuper from pg_catalog.pg_roles where rolname = luser) or 147 | (select l.lanpltrusted from pg_catalog.pg_language l where l.oid = objid)) then 148 | privname := priv || grantopt; 149 | return next; 150 | end if; 151 | end if; 152 | end loop; 153 | end loop; 154 | end loop; 155 | 156 | -- check schema privs 157 | for schemaoid, schemaname in execute 'select n.oid, n.nspname::text from pg_catalog.pg_namespace n' || schemas_to_skip || ' order by 2,1' loop 158 | objtype := 'schema'; 159 | objid := schemaoid; 160 | objname := schemaname; 161 | foreach grantopt in array with_grant loop 162 | foreach priv in array schema_privs loop 163 | if (has_schema_privilege(luser, schemaname, priv || grantopt)) then 164 | privname := priv || grantopt; 165 | return next; 166 | end if; 167 | end loop; 168 | end loop; 169 | 170 | if (has_schema_privilege(luser, schemaname, 'usage')) then 171 | 172 | -- check function privs 173 | objtype := 'function'; 174 | for objid, objname in select p.oid, p.proname || '(' || pg_catalog.pg_get_function_arguments(p.oid) || ')' from pg_catalog.pg_proc p where p.pronamespace = schemaoid order by 2,1 loop 175 | foreach grantopt in array with_grant loop 176 | foreach priv in array func_privs loop 177 | if (has_function_privilege(luser, objid, priv || grantopt)) then 178 | privname := priv || grantopt; 179 | return next; 180 | end if; 181 | end loop; 182 | end loop; 183 | end loop; 184 | 185 | -- check table privs 186 | for objid, objname in select c.oid, c.relname from pg_catalog.pg_class c where c.relnamespace = schemaoid and relkind in ('r') order by 2,1 loop 187 | foreach grantopt in array with_grant loop 188 | foreach priv in array table_privs loop 189 | if (has_table_privilege(luser, objid, priv || grantopt)) then 190 | objtype := 'table'; 191 | privname := priv || grantopt; 192 | return next; 193 | else 194 | if priv = ANY (column_privs) then 195 | colrelname := objname; 196 | objtype := 'table.column'; 197 | if (has_any_column_privilege(luser, objid, priv || grantopt)) then 198 | if (incl_sys) then 199 | minatt = ''; -- arbitrary, but ought to work for the forseeable future 200 | else 201 | minatt = ' and a.attnum > 0'; -- show only user columns 202 | end if; 203 | for colnum, colname in execute 204 | 'select a.attnum, a.attname from pg_catalog.pg_attribute a where a.attrelid = ' || objid::text || minatt || ' order by 1,2' loop 205 | if (has_column_privilege(luser, objid, colname, priv || grantopt)) then 206 | objname := colrelname || '.' || colname; 207 | privname := priv || grantopt; 208 | return next; 209 | end if; 210 | end loop; 211 | end if; 212 | objname := colrelname; 213 | end if; 214 | end if; 215 | end loop; 216 | end loop; 217 | end loop; 218 | 219 | -- check view privs 220 | for objid, objname in select c.oid, c.relname from pg_catalog.pg_class c where c.relnamespace = schemaoid and relkind in ('v') order by 2,1 loop 221 | foreach grantopt in array with_grant loop 222 | foreach priv in array table_privs loop 223 | if (has_table_privilege(luser, objid, priv || grantopt)) then 224 | objtype := 'view'; 225 | privname := priv || grantopt; 226 | return next; 227 | else 228 | if priv = ANY (column_privs) then 229 | colrelname := objname; 230 | objtype := 'view.column'; 231 | if (has_any_column_privilege(luser, objid, priv || grantopt)) then 232 | minatt = ' and a.attnum > 0'; -- VIEWs have no system columns 233 | for colnum, colname in execute 234 | 'select a.attnum, a.attname from pg_catalog.pg_attribute a where a.attrelid = ' || objid::text || minatt || ' order by 1,2' loop 235 | if (has_column_privilege(luser, objid, colname, priv || grantopt)) then 236 | objname := colrelname || '.' || colname; 237 | privname := priv || grantopt; 238 | return next; 239 | end if; 240 | end loop; 241 | end if; 242 | objname := colrelname; 243 | end if; 244 | end if; 245 | end loop; 246 | end loop; 247 | end loop; 248 | 249 | -- check seq privs 250 | objtype := 'sequence'; 251 | for objid, objname in select c.oid, c.relname from pg_catalog.pg_class c where c.relnamespace = schemaoid and relkind in ('S') order by 2,1 loop 252 | foreach grantopt in array with_grant loop 253 | foreach priv in array seq_privs loop 254 | if (has_sequence_privilege(luser, objid, priv || grantopt)) then 255 | privname := priv || grantopt; 256 | return next; 257 | end if; 258 | end loop; 259 | end loop; 260 | end loop; 261 | 262 | end if; 263 | end loop; 264 | 265 | -- recurse into any granted roles 266 | brole_path := role_path; 267 | for grpname, inh in select a.rolname as group, '(' || u.rolinherit || ')' from pg_catalog.pg_roles a join pg_catalog.pg_auth_members m on a.oid = m.roleid join pg_roles u on m.member = u.oid where u.rolname = luser loop 268 | role_path := brole_path || inh || '.' || grpname; 269 | for rec in select * from @extschema@.check_access(grpname, incl_sys, role_path) loop 270 | as_role := rec.as_role; 271 | role_path := rec.role_path; 272 | objtype := rec.objtype; 273 | objid := rec.objid; 274 | schemaname := rec.schemaname; 275 | objname := rec.objname; 276 | privname := rec.privname; 277 | return next; 278 | end loop; 279 | end loop; 280 | 281 | return; 282 | end; 283 | $$ language plpgsql; 284 | 285 | revoke execute on function @extschema@.check_access(text, bool, text) from public; 286 | 287 | create or replace function @extschema@.check_access 288 | ( 289 | in luser text, 290 | in incl_sys bool, 291 | out role_path text, 292 | out base_role text, 293 | out as_role text, 294 | out objtype text, 295 | out objid oid, 296 | out schemaname text, 297 | out objname text, 298 | out privname text 299 | ) 300 | returns setof record 301 | as $$ 302 | select * from @extschema@.check_access($1, $2, NULL); 303 | $$ language sql; 304 | 305 | revoke execute on function @extschema@.check_access(text, bool) from public; 306 | 307 | create or replace function @extschema@.all_access 308 | ( 309 | in incl_sys bool, 310 | out role_path text, 311 | out base_role text, 312 | out as_role text, 313 | out objtype text, 314 | out objid oid, 315 | out schemaname text, 316 | out objname text, 317 | out privname text 318 | ) 319 | returns setof record 320 | as $$ 321 | declare 322 | rec record; 323 | rname text; 324 | begin 325 | for rname in select a.rolname as group from pg_catalog.pg_roles a order by 1 loop 326 | for role_path, base_role, as_role, objtype, objid, schemaname, objname, privname in select * from @extschema@.check_access(rname, incl_sys) loop 327 | return next; 328 | end loop; 329 | end loop; 330 | return; 331 | end; 332 | $$ language plpgsql; 333 | 334 | revoke execute on function @extschema@.all_access(bool) from public; 335 | 336 | create or replace function @extschema@.all_access 337 | ( 338 | out role_path text, 339 | out base_role text, 340 | out as_role text, 341 | out objtype text, 342 | out objid oid, 343 | out schemaname text, 344 | out objname text, 345 | out privname text 346 | ) 347 | returns setof record 348 | as $$ 349 | select * from @extschema@.all_access(false) 350 | $$ language sql; 351 | 352 | revoke execute on function @extschema@.all_access() from public; 353 | 354 | create or replace function @extschema@.my_privs 355 | ( 356 | out role_path text, 357 | out base_role text, 358 | out as_role text, 359 | out objtype text, 360 | out objid oid, 361 | out schemaname text, 362 | out objname text, 363 | out privname text 364 | ) 365 | returns setof record 366 | SECURITY DEFINER 367 | as $$ 368 | select * from @extschema@.all_access(false) where base_role = SESSION_USER 369 | $$ language sql; 370 | 371 | grant execute on function @extschema@.my_privs() to public; 372 | 373 | create or replace view @extschema@.my_privs as select * from @extschema@.my_privs(); 374 | grant select on @extschema@.my_privs to public; 375 | 376 | create or replace function @extschema@.my_privs_sys 377 | ( 378 | out role_path text, 379 | out base_role text, 380 | out as_role text, 381 | out objtype text, 382 | out objid oid, 383 | out schemaname text, 384 | out objname text, 385 | out privname text 386 | ) 387 | returns setof record 388 | SECURITY DEFINER 389 | as $$ 390 | select * from @extschema@.all_access(true) where base_role = SESSION_USER 391 | $$ language sql; 392 | 393 | grant execute on function @extschema@.my_privs_sys() to public; 394 | 395 | create or replace view @extschema@.my_privs_sys as select * from @extschema@.my_privs_sys(); 396 | grant select on @extschema@.my_privs_sys to public; 397 | 398 | --------------------------------------------------------------------------------