forked from awslabs/amazon-redshift-utils
-
Notifications
You must be signed in to change notification settings - Fork 0
/
sp_controlled_access.sql
120 lines (110 loc) · 4.65 KB
/
sp_controlled_access.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
/**********************************************************************************************
Purpose: Provide controlled access to data without granting permission on the table/view
Notes:
Must set the SECURITY attribute set as DEFINER
An unprivileged user can run the procedure when granted the EXECUTE permission
Parameters:
select_cols : Text list of columns to be added to the SELECT clause
query_from : Schema qualified name of table/view to be queried
where_clause: Text of predicate criteria to be added to the WHERE clause
max_level : Maximum number of rows to be returned
result_set : Name of cursor used for output
Requirements:
Must have a table containing user authorizations with the following DDL:
CREATE TABLE $(auth_table)
( query_from VARCHAR,
, user_name VARCHAR,
, valid_until TIMESTAMP,
, max_rows INT );
History:
2019-11-09 - joeharris76 - Created
**********************************************************************************************/
-- DROP PROCEDURE sp_controlled_access(VARCHAR,VARCHAR,VARCHAR,INTEGER,REFCURSOR);
CREATE OR REPLACE PROCEDURE sp_controlled_access (
select_cols IN VARCHAR(256)
, query_from IN VARCHAR(128)
, where_clause IN VARCHAR(256)
, max_rows IN INTEGER
, result_set INOUT REFCURSOR )
AS $$
DECLARE
user_name VARCHAR(128);
sql VARCHAR(MAX) := '';
auth_table VARCHAR(256) := 'hr.access_authority';
rows_limit INTEGER := 0;
BEGIN
user_name = session_user;
-- Check the user is authorized for this query
sql := 'SELECT NVL(max_rows,1000) rows_limit FROM '||auth_table||
' WHERE query_from = '''||query_from||''' '||
' AND user_name = '''||user_name||''' '||
' AND (valid_until IS NULL OR valid_until >= '''||SYSDATE||''') ;';
EXECUTE sql INTO rows_limit;
IF NVL(rows_limit,0) = 0 THEN
RAISE EXCEPTION 'ERROR: Query Is Not Authorized';
ELSE
-- Compose the user query
IF select_cols <> '' THEN
sql := 'SELECT '||select_cols;
ELSE
sql := 'SELECT * ';
END IF;
sql := sql||' FROM '||query_from;
IF where_clause <> '' THEN
sql := sql||' WHERE '||where_clause||' ';
END IF;
IF rows_limit > max_rows THEN
rows_limit := max_rows;
END IF;
sql := sql||' LIMIT '||rows_limit||' ;';
-- Open the cursor and execute the SQL
RAISE INFO 'SQL: %', sql;
OPEN result_set FOR EXECUTE sql;
RAISE INFO 'AUTHORIZED: Query on `%` completed',query_from;
END IF;
END;
$$ LANGUAGE plpgsql
SECURITY DEFINER;
/* Usage Example:
SELECT current_user;
CREATE SCHEMA hr;
CREATE TABLE hr.employee ( title VARCHAR, emp INT, mgr INT, dept VARCHAR);
INSERT INTO hr.employee VALUES
('Chairman', 100, NULL, 'Board' )
, ('CEO' , 101, 100 , 'Board' )
, ('CTO' , 102, 101 , 'IT' )
, ('CMO' , 103, 101 , 'Sales/Mkt');
CREATE USER user_no_priv WITH PASSWORD DISABLE;
CREATE TABLE hr.access_authority ( query_from VARCHAR, user_name VARCHAR, valid_until TIMESTAMP, max_rows INT );
INSERT INTO hr.access_authority VALUES ('hr.employee','user_no_priv','2019-12-31',99);
GRANT ALL ON SCHEMA public TO user_no_priv;
GRANT EXECUTE ON PROCEDURE sp_controlled_access(VARCHAR,VARCHAR,VARCHAR,INTEGER,REFCURSOR) TO user_no_priv;
-- Change session to the new user
SET SESSION AUTHORIZATION user_no_priv;
SELECT current_user; -- user_no_priv
SELECT * FROM hr.employee; -- ERROR: permission denied
BEGIN; -- Call the stored procedure
CALL sp_controlled_access (
'title,emp,mgr,dept'::VARCHAR -- select_cols
, 'hr.employee'::VARCHAR -- query_from
, 'dept = ''Board'''::VARCHAR -- where_clause
, 10 -- max_rows
, 'employee_data' ); -- result_set
-- INFO: AUTHORIZED: Query on `hr.employee` completed
-- result_set
-- ---------------
-- employee_data
FETCH ALL FROM employee_data;
-- title | emp | mgr | dept
-- ----------+-----+-----+-------
-- Chairman | 100 | | Board
-- CEO | 101 | 100 | Board
END;
-- RESET SESSION AUTHORIZATION;
-- DROP TABLE hr.employee;
-- DROP TABLE hr.access_authority;
-- DROP SCHEMA hr;
-- REVOKE EXECUTE ON PROCEDURE sp_controlled_access(VARCHAR,VARCHAR,VARCHAR,INTEGER,REFCURSOR) FROM user_no_priv;
-- REVOKE ALL ON SCHEMA public FROM user_no_priv;
-- DROP USER user_no_priv;
*/