Skip to content

Commit

Permalink
Permission-related views (#10)
Browse files Browse the repository at this point in the history
* Remove duplicate user model

* Add base models

* Add new views for permission management

* Add num_columns to table_stats

* Use quotes in full_object_name. Small tweaks to formatting
  • Loading branch information
clrcrl authored and drewbanin committed Mar 10, 2018
1 parent 71213a2 commit 01326ff
Show file tree
Hide file tree
Showing 6 changed files with 100 additions and 6 deletions.
9 changes: 9 additions & 0 deletions models/base/pg_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
select
schemaname as schema_name
, tablename as table_name
, tableowner as table_owner
, tablespace as table_space
, hasindexes as has_indexes
, hasrules as has_rules
, hastriggers as has_triggers
from pg_tables
5 changes: 5 additions & 0 deletions models/base/pg_views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
select
schemaname as schema_name
, viewname as view_name
, viewowner as view_owner
from pg_views
6 changes: 0 additions & 6 deletions models/base/users.sql

This file was deleted.

2 changes: 2 additions & 0 deletions models/views/table_stats.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@ with unsorted_by_table as (
, min(sort_key) as sort_key
, max(attsortkeyord) as num_sort_keys
, (max(attencodingtype) > 0) as is_encoded
, max(attnum) as num_columns
from {{ref('pg_attribute')}}
group by 1

Expand Down Expand Up @@ -84,6 +85,7 @@ select
, (table_attributes.sort_key is not null) as is_sorted
, table_attributes.sort_key
, table_attributes.num_sort_keys
, table_attributes.num_columns

, table_sizes.size_in_megabytes
, {{percentage('table_sizes.size_in_megabytes',
Expand Down
38 changes: 38 additions & 0 deletions models/views/users_schema_permissions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
with tables as (

select * from {{ref('pg_tables')}}

), views as (

select * from {{ref('pg_views')}}

), users as (

select * from {{ref('pg_user')}}

), schemas as (

select
distinct(schema_name)
from tables
where schema_name not in ('pg_catalog', 'information_schema')

union

select
distinct(schema_name)
from views

where schema_name not in ('pg_catalog', 'information_schema')

)


select
schemas.schema_name
, users.username
, has_schema_privilege(users.username, schemas.schema_name, 'usage') AS has_usage_privilege
, has_schema_privilege(users.username, schemas.schema_name, 'create') AS has_create_privilege
from schemas
cross join users
order by schemas.schema_name, users.username
46 changes: 46 additions & 0 deletions models/views/users_table_view_permissions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
with tables as (

select * from {{ref('pg_tables')}}

), views as (

select * from {{ref('pg_views')}}

), users as (

select * from {{ref('pg_user')}}

), objects as (

select
schema_name
, 'table' as object_type
, table_name as object_name
, '"' || schema_name || '"."' || table_name || '"' as full_object_name
from tables
where schema_name not in ('pg_catalog', 'information_schema')

union

select
schema_name
, 'view' as object_type
, view_name as object_name
, '"' || schema_name || '"."' || view_name || '"' as full_object_name
from views
where schema_name not in ('pg_catalog', 'information_schema')

)

select
objects.schema_name
, objects.object_name
, users.username
, has_table_privilege(users.username, objects.full_object_name, 'select') as has_select_privilege
, has_table_privilege(users.username, objects.full_object_name, 'insert') as has_insert_privilege
, has_table_privilege(users.username, objects.full_object_name, 'update') as has_update_privilege
, has_table_privilege(users.username, objects.full_object_name, 'delete') as has_delete_privilege
, has_table_privilege(users.username, objects.full_object_name, 'references') as has_references_privilege
from objects
cross join users
order by objects.full_object_name, users.username

0 comments on commit 01326ff

Please sign in to comment.