Skip to content

Commit

Permalink
#80: Addressed edge case for objects with names containing '.'
Browse files Browse the repository at this point in the history
  • Loading branch information
Christopherson committed May 25, 2016
1 parent f943cbd commit c7b3653
Show file tree
Hide file tree
Showing 3 changed files with 10 additions and 8 deletions.
10 changes: 5 additions & 5 deletions src/AdminViews/v_generate_user_object_permissions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,11 +10,11 @@ SELECT
schemaname
,objectname
,usename
,REVERSE(SUBSTRING(REVERSE(CASE WHEN sel IS TRUE THEN 'GRANT SELECT ON ' + schemaname + '.' + objectname + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN ins IS TRUE THEN 'GRANT INSERT ON ' + schemaname + '.' + objectname + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN upd IS TRUE THEN 'GRANT UPDATE ON ' + schemaname + '.' + objectname + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN del IS TRUE THEN 'GRANT DELETE ON ' + schemaname + '.' + objectname + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN ref IS TRUE THEN 'GRANT REFERENCES ON ' + schemaname + '.' + objectname + ' TO ' + usename + ';\n' ELSE '' END), 2)) AS ddl
,REVERSE(SUBSTRING(REVERSE(CASE WHEN sel IS TRUE THEN 'GRANT SELECT ON ' + QUOTE_IDENT(schemaname) + '.' + QUOTE_IDENT(objectname) + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN ins IS TRUE THEN 'GRANT INSERT ON ' + QUOTE_IDENT(schemaname) + '.' + QUOTE_IDENT(objectname) + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN upd IS TRUE THEN 'GRANT UPDATE ON ' + QUOTE_IDENT(schemaname) + '.' + QUOTE_IDENT(objectname) + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN del IS TRUE THEN 'GRANT DELETE ON ' + QUOTE_IDENT(schemaname) + '.' + QUOTE_IDENT(objectname) + ' TO ' + usename + ';\n' ELSE '' END +
CASE WHEN ref IS TRUE THEN 'GRANT REFERENCES ON ' + QUOTE_IDENT(schemaname) + '.' + QUOTE_IDENT(objectname) + ' TO ' + usename + ';\n' ELSE '' END), 2)) AS ddl
FROM
admin.v_get_obj_priv_by_user
;
5 changes: 3 additions & 2 deletions src/AdminViews/v_get_obj_priv_by_user.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@
Purpose: View to get the table/views that a user has access to
History:
2013-10-29 jjschmit Created
2016-05-24 chriz-bigdata addressed edge case for objects with names containing '.'
**********************************************************************************************/
CREATE OR REPLACE VIEW admin.v_get_obj_priv_by_user
AS
Expand All @@ -20,10 +21,10 @@ FROM
,HAS_TABLE_PRIVILEGE(usrs.usename, fullobj, 'references') AS ref
FROM
(
SELECT schemaname, 't' AS obj_type, tablename AS objectname, schemaname + '.' + tablename AS fullobj FROM pg_tables
SELECT schemaname, 't' AS obj_type, tablename AS objectname, QUOTE_IDENT(schemaname) || '.' || QUOTE_IDENT(tablename) AS fullobj FROM pg_tables
WHERE schemaname not in ('pg_internal')
UNION
SELECT schemaname, 'v' AS obj_type, viewname AS objectname, schemaname + '.' + viewname AS fullobj FROM pg_views
SELECT schemaname, 'v' AS obj_type, viewname AS objectname, QUOTE_IDENT(schemaname) || '.' || QUOTE_IDENT(viewname) AS fullobj FROM pg_views
WHERE schemaname not in ('pg_internal')
) AS objs
,(SELECT * FROM pg_user) AS usrs
Expand Down
3 changes: 2 additions & 1 deletion src/AdminViews/v_get_view_priv_by_user.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@
Purpose: View to get the views that a user has access to
History:
2013-10-29 jjschmit Created
2016-05-24 chriz-bigdata addressed edge case for objects with names containing '.'
**********************************************************************************************/
CREATE OR REPLACE VIEW admin.v_get_view_priv_by_user
AS
Expand All @@ -19,7 +20,7 @@ FROM
,HAS_TABLE_PRIVILEGE(usrs.usename, obj, 'delete') AS del
,HAS_TABLE_PRIVILEGE(usrs.usename, obj, 'references') AS ref
FROM
(SELECT schemaname, viewname, ('"' + schemaname + '"."' + viewname + '"') AS obj FROM pg_views ) AS objs
(SELECT schemaname, viewname, QUOTE_IDENT(schemaname) || '.' || QUOTE_IDENT(viewname) AS obj FROM pg_views ) AS objs
INNER JOIN
(SELECT * FROM pg_user) AS usrs
ON 1 = 1
Expand Down

0 comments on commit c7b3653

Please sign in to comment.