├── CODE_OF_CONDUCT.md ├── CONTRIBUTING.md ├── LICENSE ├── README.md ├── pr_migrate_groups_to_roles.sql ├── query_column_group_grants.sql ├── query_column_role_grants.sql ├── query_create_model_group_grants.sql ├── query_create_model_role_grants.sql ├── query_database_group_grants.sql ├── query_database_role_grants.sql ├── query_datashare_group_grants.sql ├── query_datashare_role_grants.sql ├── query_defaults_group_grants.sql ├── query_defaults_role_grants.sql ├── query_language_group_grants.sql ├── query_language_role_grants.sql ├── query_model_group_grants.sql ├── query_model_role_grants.sql ├── query_routine_group_grants.sql ├── query_routine_role_grants.sql ├── query_schema_group_grants.sql ├── query_schema_role_grants.sql ├── query_table_group_grants.sql ├── query_table_role_grants.sql ├── query_users_in_groups.sql └── query_users_in_roles.sql /CODE_OF_CONDUCT.md: -------------------------------------------------------------------------------- 1 | ## Code of Conduct 2 | This project has adopted the [Amazon Open Source Code of Conduct](https://aws.github.io/code-of-conduct). 3 | For more information see the [Code of Conduct FAQ](https://aws.github.io/code-of-conduct-faq) or contact 4 | opensource-codeofconduct@amazon.com with any additional questions or comments. 5 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributing Guidelines 2 | 3 | Thank you for your interest in contributing to our project. Whether it's a bug report, new feature, correction, or additional 4 | documentation, we greatly value feedback and contributions from our community. 5 | 6 | Please read through this document before submitting any issues or pull requests to ensure we have all the necessary 7 | information to effectively respond to your bug report or contribution. 8 | 9 | 10 | ## Reporting Bugs/Feature Requests 11 | 12 | We welcome you to use the GitHub issue tracker to report bugs or suggest features. 13 | 14 | When filing an issue, please check existing open, or recently closed, issues to make sure somebody else hasn't already 15 | reported the issue. Please try to include as much information as you can. Details like these are incredibly useful: 16 | 17 | * A reproducible test case or series of steps 18 | * The version of our code being used 19 | * Any modifications you've made relevant to the bug 20 | * Anything unusual about your environment or deployment 21 | 22 | 23 | ## Contributing via Pull Requests 24 | Contributions via pull requests are much appreciated. Before sending us a pull request, please ensure that: 25 | 26 | 1. You are working against the latest source on the *main* branch. 27 | 2. You check existing open, and recently merged, pull requests to make sure someone else hasn't addressed the problem already. 28 | 3. You open an issue to discuss any significant work - we would hate for your time to be wasted. 29 | 30 | To send us a pull request, please: 31 | 32 | 1. Fork the repository. 33 | 2. Modify the source; please focus on the specific change you are contributing. If you also reformat all the code, it will be hard for us to focus on your change. 34 | 3. Ensure local tests pass. 35 | 4. Commit to your fork using clear commit messages. 36 | 5. Send us a pull request, answering any default questions in the pull request interface. 37 | 6. Pay attention to any automated CI failures reported in the pull request, and stay involved in the conversation. 38 | 39 | GitHub provides additional document on [forking a repository](https://help.github.com/articles/fork-a-repo/) and 40 | [creating a pull request](https://help.github.com/articles/creating-a-pull-request/). 41 | 42 | 43 | ## Finding contributions to work on 44 | Looking at the existing issues is a great way to find something to contribute on. As our projects, by default, use the default GitHub issue labels (enhancement/bug/duplicate/help wanted/invalid/question/wontfix), looking at any 'help wanted' issues is a great place to start. 45 | 46 | 47 | ## Code of Conduct 48 | This project has adopted the [Amazon Open Source Code of Conduct](https://aws.github.io/code-of-conduct). 49 | For more information see the [Code of Conduct FAQ](https://aws.github.io/code-of-conduct-faq) or contact 50 | opensource-codeofconduct@amazon.com with any additional questions or comments. 51 | 52 | 53 | ## Security issue notifications 54 | If you discover a potential security issue in this project we ask that you notify AWS/Amazon Security via our [vulnerability reporting page](http://aws.amazon.com/security/vulnerability-reporting/). Please do **not** create a public github issue. 55 | 56 | 57 | ## Licensing 58 | 59 | See the [LICENSE](LICENSE) file for our project's licensing. We will ask you to confirm the licensing of your contribution. 60 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright Amazon.com, Inc. or its affiliates. All Rights Reserved. 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy of 4 | this software and associated documentation files (the "Software"), to deal in 5 | the Software without restriction, including without limitation the rights to 6 | use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of 7 | the Software, and to permit persons to whom the Software is furnished to do so. 8 | 9 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 10 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS 11 | FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR 12 | COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER 13 | IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN 14 | CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 15 | 16 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # redshift-roles 2 | Scripts, SQL queries, and Stored Procedures that are useful in using and adopting the use of using ROLE for security access in Redshift. 3 | 4 | ## Contents 5 | - pr_migrate_groups_to_roles.sql - Stored procedure that creates roles based on the existing groups and performs the grants needed to replace groups in favor of roles. 6 | - Parameter: dryrun boolean 7 | true: indicates that the stored procedure will NOT create any roles or perform any grants. Instead, the procedure will only output through RAISE INFO, the commands that will be executed when dryrun is false. 8 | false: indicates that the stored proceudre WILL create roles and perform grants. The procedure also outputs the commands being executed with RAISE INFO. 9 | 10 | - Queries to display grants to groups and roles: 11 | - query_create_model_group_grants.sql 12 | - query_create_model_role_grants.sql 13 | - query_database_group_grants.sql 14 | - query_database_role_grants.sql 15 | - query_datashare_group_grants.sql 16 | - query_datashare_role_grants.sql 17 | - query_defaults_group_grants.sql 18 | - query_defaults_role_grants.sql 19 | - query_language_group_grants.sql 20 | - query_language_role_grants.sql 21 | - query_model_group_grants.sql 22 | - query_model_role_grants.sql 23 | - query_routine_group_grants.sql 24 | - query_routine_role_grants.sql 25 | - query_schema_group_grants.sql 26 | - query_schema_role_grants.sql 27 | - query_table_group_grants.sql 28 | - query_table_role_grants.sql 29 | - query_users_in_groups.sql 30 | - query_users_in_roles.sql 31 | 32 | ## Security 33 | 34 | See [CONTRIBUTING](CONTRIBUTING.md#security-issue-notifications) for more information. 35 | 36 | ## License 37 | 38 | This library is licensed under the MIT-0 License. See the LICENSE file. 39 | -------------------------------------------------------------------------------- /pr_migrate_groups_to_roles.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PROCEDURE public.pr_migrate_groups_to_roles(dryrun boolean) AS 2 | $$ 3 | /* 4 | -- Name: pr_migrate_groups_to_roles 5 | -- Author: Jon Roberts 6 | -- Parameter: 7 | -- dryrun: True means the procedure will not execute any DDL and only RAISE INFO the commands that will be executed. False means that it is not a dryrun so the procedrue will execute the DDL commands. 8 | -- 9 | -- Revisions: 10 | -- 2022-12-30: Initial development 11 | -- 2023-01-04: Added defaults and exception handling 12 | -- 2023-01-05: Added suppport for datashares and models 13 | -- 2023-02-15: Fixed defaults 14 | -- 2023-02-27: Fixed DROP default permission 15 | -- 2023-05-09: Added column level security grants 16 | -- 2023-11-13: Fix for column level security grants 17 | -- Actions: 18 | -- Create Roles 19 | -- Assign users to Roles 20 | -- Databases to Roles 21 | -- Schemas to Roles 22 | -- Tables to Roles 23 | -- Routines (Procedures and Functions) to Roles 24 | -- Languages to Roles 25 | -- Default privileges to schemas and users 26 | -- Models to Roles including CREATE 27 | -- Datashares to Roles 28 | -- Columns to Roles 29 | -- Important Notes: 30 | -- The procedure is intended to simplify the migration of Groups to Roles. It creates the Roles and executes the grants so that the new Roles match the existing grants to Groups. This procedure does NOT revoke permissions from Roles so if you call this procedure, then revoke permission to a Group, and then run this procedure again, the Role will NOT have the grant revoked. 31 | */ 32 | DECLARE 33 | v_procedure varchar(255) := 'pr_migrate_groups_to_roles'; 34 | v_location int; 35 | v_now timestamp; 36 | v_rec record; 37 | v_sql varchar(max); 38 | v_i int; 39 | v_counter int; 40 | v_grant varchar(1); 41 | v_action varchar(20); 42 | v_grant_count int; 43 | v_routine_type varchar(10); 44 | v_previous_datashare_name varchar(128) := ''; 45 | v_previous_identity_name varchar(128) := ''; 46 | v_columns varchar(max) := ''; 47 | v_target varchar(max) := ''; 48 | v_grants varchar(max) := ''; 49 | BEGIN 50 | --Create Roles 51 | v_location := 1000; 52 | FOR v_rec IN SELECT g.groname FROM pg_group g LEFT OUTER JOIN svv_roles r ON g.groname = r.role_name WHERE r.role_id IS NULL ORDER BY 1 LOOP 53 | v_sql := 'CREATE ROLE "' || v_rec.groname || '"'; 54 | RAISE INFO '%', v_sql; 55 | IF dryrun IS NOT TRUE THEN 56 | EXECUTE v_sql; 57 | END IF; 58 | END LOOP; 59 | 60 | --Grant Users to Roles 61 | v_location := 2000; 62 | FOR v_rec IN SELECT u.usename, g.groname FROM (SELECT groname, grolist, generate_series(1, array_upper(grolist, 1)) AS i FROM pg_group) AS g JOIN pg_user u ON g.grolist[i] = u.usesysid ORDER BY u.usename, g.groname LOOP 63 | v_sql := 'GRANT ROLE "' || v_rec.groname || '" TO "' || v_rec.usename || '";'; 64 | RAISE INFO '%', v_sql; 65 | IF dryrun IS NOT TRUE THEN 66 | EXECUTE v_sql; 67 | END IF; 68 | END LOOP; 69 | 70 | --Databases 71 | v_location := 3000; 72 | <> 73 | FOR v_rec IN SELECT sub.datname, split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT d.datname, split_part(split_part(array_to_string(d.datacl, ','), ',', i), ' ', 2) AS acl FROM (SELECT datname, generate_series(1, array_upper(datacl, 1)) AS i, datacl FROM pg_database) AS d WHERE split_part(array_to_string(d.datacl, ','), ',', i) LIKE 'group %') AS sub ORDER BY 1, 2 LOOP 74 | v_grant_count := len(v_rec.grogrant); 75 | v_counter := 0; 76 | <> 77 | FOR v_i IN 1..v_grant_count LOOP 78 | v_grant := substring(v_rec.grogrant, v_i, 1); 79 | IF v_grant = 'C' THEN 80 | v_action := 'CREATE'; 81 | ELSIF v_grant = 'T' THEN 82 | v_action := 'TEMPORARY'; 83 | END IF; 84 | v_counter := v_counter + 1; 85 | IF v_counter = 1 THEN 86 | v_sql := 'GRANT ' || v_action; 87 | ELSE 88 | v_sql := v_sql || ', ' || v_action; 89 | END IF; 90 | END LOOP grants; 91 | IF v_counter > 0 THEN 92 | v_sql := v_sql || ' ON DATABASE ' || v_rec.datname || ' TO ROLE "' || v_rec.groname || '";'; 93 | RAISE INFO '%', v_sql; 94 | IF dryrun IS NOT TRUE THEN 95 | EXECUTE v_sql; 96 | END IF; 97 | END IF; 98 | END LOOP databases; 99 | 100 | --Schemas to Roles 101 | v_location := 4000; 102 | <> 103 | FOR v_rec IN SELECT sub.nspname, split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT n.nspname, split_part(split_part(array_to_string(nspacl, ','), ',', i), ' ', 2) AS acl FROM (SELECT nspname, generate_series(1, array_upper(nspacl, 1)) AS i, nspacl FROM pg_namespace) AS n WHERE split_part(array_to_string(nspacl, ','), ',', i) LIKE 'group %') AS sub ORDER BY 1, 2 LOOP 104 | v_grant_count := len(v_rec.grogrant); 105 | v_counter := 0; 106 | <> 107 | FOR v_i IN 1..v_grant_count LOOP 108 | v_grant := substring(v_rec.grogrant, v_i, 1); 109 | IF v_grant = 'U' THEN 110 | v_action := 'USAGE'; 111 | ELSIF v_grant = 'C' THEN 112 | v_action := 'CREATE'; 113 | END IF; 114 | v_counter := v_counter + 1; 115 | IF v_counter = 1 THEN 116 | v_sql := 'GRANT ' || v_action; 117 | ELSE 118 | v_sql := v_sql || ', ' || v_action; 119 | END IF; 120 | END LOOP grants; 121 | IF v_counter > 0 THEN 122 | v_sql := v_sql || ' ON SCHEMA "' || v_rec.nspname || '" TO ROLE "' || v_rec.groname || '";'; 123 | RAISE INFO '%', v_sql; 124 | IF dryrun IS NOT TRUE THEN 125 | EXECUTE v_sql; 126 | END IF; 127 | END IF; 128 | END LOOP schemas; 129 | 130 | --Tables to Roles 131 | v_location := 5000; 132 | <> 133 | FOR v_rec IN SELECT sub2.nspname, sub2.relname, split_part(sub2.acl, '=', 1) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT sub.nspname, sub.relname, split_part(split_part(array_to_string(sub.relacl, ','), ',', i), ' ', 2) AS acl FROM (SELECT n.nspname, c.relname, generate_series(1, array_upper(c.relacl, 1)) AS i, c.relacl FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid) AS sub WHERE split_part(array_to_string(sub.relacl, ','), ',', i) LIKE 'group %') AS sub2 ORDER BY 1, 2 LOOP 134 | v_grant_count := len(v_rec.grogrant); 135 | v_counter := 0; 136 | <> 137 | FOR v_i IN 1..v_grant_count LOOP 138 | v_grant := substring(v_rec.grogrant, v_i, 1); 139 | IF v_grant = 'a' THEN 140 | v_action := 'INSERT'; 141 | ELSIF v_grant = 'w' THEN 142 | v_action := 'UPDATE'; 143 | ELSIF v_grant = 'd' THEN 144 | v_action := 'DELETE'; 145 | ELSIF v_grant = 'r' THEN 146 | v_action := 'SELECT'; 147 | ELSIF v_grant = 'x' THEN 148 | v_action := 'REFERENCES'; 149 | ELSIF v_grant = 't' THEN 150 | v_action := 'TRIGGER'; 151 | ELSIF v_grant = 'R' THEN 152 | v_action := 'RULE'; 153 | END IF; 154 | v_counter := v_counter + 1; 155 | IF v_counter = 1 THEN 156 | v_sql := 'GRANT ' || v_action; 157 | ELSE 158 | v_sql := v_sql || ', ' || v_action; 159 | END IF; 160 | END LOOP grants; 161 | IF v_counter > 0 THEN 162 | v_sql := v_sql || ' ON "' || v_rec.nspname || '"."' || v_rec.relname || '" TO ROLE "' || v_rec.groname || '";'; 163 | RAISE INFO '%', v_sql; 164 | IF dryrun IS NOT TRUE THEN 165 | EXECUTE v_sql; 166 | END IF; 167 | END IF; 168 | END LOOP tables; 169 | 170 | --Routines 171 | v_location := 6000; 172 | <> 173 | FOR v_rec IN SELECT sub2.nspname, sub2.proname, sub2.lanname, sub2.proargs, split_part(sub2.acl, '=', 1) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT sub.nspname, sub.proname, sub.lanname, sub.proargs, split_part(split_part(array_to_string(sub.proacl, ','), ',', i), ' ', 2) AS acl FROM (SELECT n.nspname, p.proname, l.lanname, oidvectortypes(p.proargtypes) proargs, generate_series(1, array_upper(p.proacl, 1)) as i, p.proacl FROM pg_proc p JOIN pg_namespace n ON p.pronamespace = n.oid JOIN pg_language l ON p.prolang = l.oid JOIN pg_user u ON p.proowner = u.usesysid WHERE l.lanname <> 'mlfunc' AND u.usename <> 'rdsdb' AND p.proacl IS NOT NULL) AS sub WHERE split_part(array_to_string(sub.proacl, ','), ',', i) LIKE 'group %') AS sub2 ORDER BY 1, 2 LOOP 174 | v_grant_count := len(v_rec.grogrant); 175 | v_counter := 0; 176 | IF v_rec.lanname = 'plpgsql' THEN 177 | v_routine_type := 'PROCEDURE'; 178 | ELSIF v_rec.lanname = 'sql' OR v_rec.lanname = 'plpythonu' THEN 179 | v_routine_type := 'FUNCTION'; 180 | END IF; 181 | <> 182 | FOR v_i IN 1..v_grant_count LOOP 183 | v_grant := substring(v_rec.grogrant, v_i, 1); 184 | IF v_grant = 'X' THEN 185 | v_action := 'EXECUTE'; 186 | END IF; 187 | v_counter := v_counter + 1; 188 | IF v_counter = 1 THEN 189 | v_sql := 'GRANT ' || v_action; 190 | ELSE 191 | v_sql := v_sql || ', ' || v_action; 192 | END IF; 193 | END LOOP grants; 194 | IF v_counter > 0 THEN 195 | v_sql := v_sql || ' ON ' || v_routine_type || ' "' || v_rec.nspname || '"."' || v_rec.proname || '"(' || v_rec.proargs || ') TO ROLE "' || v_rec.groname || '";'; 196 | RAISE INFO '%', v_sql; 197 | IF dryrun IS NOT TRUE THEN 198 | EXECUTE v_sql; 199 | END IF; 200 | END IF; 201 | END LOOP routines; 202 | 203 | --Languages 204 | v_location := 7000; 205 | <> 206 | FOR v_rec IN SELECT sub.lanname, split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT l.lanname, split_part(split_part(array_to_string(l.lanacl, ','), ',', i), ' ', 2) AS acl FROM (SELECT lanname, generate_series(1, array_upper(lanacl, 1)) AS i, lanacl FROM pg_language) AS l WHERE l.lanname <> 'mlfunc' AND split_part(array_to_string(l.lanacl, ','), ',', i) LIKE 'group %') AS sub ORDER BY 1, 2 LOOP 207 | v_grant_count := len(v_rec.grogrant); 208 | v_counter := 0; 209 | <> 210 | FOR v_i IN 1..v_grant_count LOOP 211 | v_grant := substring(v_rec.grogrant, v_i, 1); 212 | IF v_grant = 'U' THEN 213 | v_action := 'USAGE'; 214 | END IF; 215 | v_counter := v_counter + 1; 216 | IF v_counter = 1 THEN 217 | v_sql := 'GRANT ' || v_action; 218 | ELSE 219 | v_sql := v_sql || ', ' || v_action; 220 | END IF; 221 | END LOOP grants; 222 | IF v_counter > 0 THEN 223 | v_sql := v_sql || ' ON LANGUAGE ' || v_rec.lanname || ' TO ROLE "' || v_rec.groname || '";'; 224 | RAISE INFO '%', v_sql; 225 | IF dryrun IS NOT TRUE THEN 226 | EXECUTE v_sql; 227 | END IF; 228 | END IF; 229 | END LOOP languages; 230 | 231 | --Datashares 232 | v_location := 8000; 233 | v_counter := 0; 234 | <> 235 | FOR v_rec IN SELECT datashare_name, identity_name, privilege_type FROM svv_datashare_privileges WHERE identity_type = 'group' ORDER BY 1, 2, 3 LOOP 236 | IF v_previous_datashare_name = v_rec.datashare_name AND v_previous_identity_name = v_rec.identity_name THEN 237 | v_sql := v_sql || ', ' || v_rec.privilege_type; 238 | ELSE 239 | IF v_counter > 0 THEN 240 | v_sql := v_sql || ' ON DATASHARE ' || v_previous_datashare_name || ' TO ROLE "' || v_previous_identity_name || '";'; 241 | RAISE INFO '%', v_sql; 242 | IF dryrun IS NOT TRUE THEN 243 | EXECUTE v_sql; 244 | END IF; 245 | END IF; 246 | v_sql := 'GRANT ' || v_rec.privilege_type; 247 | END IF; 248 | v_previous_datashare_name := v_rec.datashare_name; 249 | v_previous_identity_name := v_rec.identity_name; 250 | v_counter := v_counter + 1; 251 | END LOOP datashares; 252 | IF v_counter > 0 THEN 253 | v_sql := v_sql || ' ON DATASHARE ' || v_previous_datashare_name || ' TO ROLE "' || v_previous_identity_name || '";'; 254 | RAISE INFO '%', v_sql; 255 | IF dryrun IS NOT TRUE THEN 256 | EXECUTE v_sql; 257 | END IF; 258 | END IF; 259 | 260 | --Models 261 | v_location := 9000; 262 | <> 263 | FOR v_rec IN SELECT namespace_name, model_name, identity_name, privilege_type FROM svv_ml_model_privileges WHERE identity_type = 'group' ORDER BY 1, 2, 3 LOOP 264 | v_sql := 'GRANT ' || v_rec.privilege_type || ' ON MODEL "' || v_rec.namespace_name || '"."' || v_rec.model_name || '" TO ROLE "' || v_rec.identity_name || '"'; 265 | RAISE INFO '%', v_sql; 266 | IF dryrun IS NOT TRUE THEN 267 | EXECUTE v_sql; 268 | END IF; 269 | END LOOP models; 270 | 271 | v_location := 9500; 272 | <> 273 | FOR v_rec IN SELECT split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT l.lanname, split_part(split_part(array_to_string(l.lanacl, ','), ',', i), ' ', 2) AS acl FROM (SELECT lanname, generate_series(1, array_upper(lanacl, 1)) AS i, lanacl FROM pg_language WHERE lanname = 'mlfunc') AS l WHERE split_part(array_to_string(l.lanacl, ','), ',', l.i) LIKE 'group %') AS sub ORDER BY 1, 2 LOOP 274 | v_grant_count := len(v_rec.grogrant); 275 | v_counter := 0; 276 | <> 277 | FOR v_i IN 1..v_grant_count LOOP 278 | v_grant := substring(v_rec.grogrant, v_i, 1); 279 | IF v_grant = 'U' THEN 280 | v_action := 'CREATE MODEL'; 281 | END IF; 282 | v_counter := v_counter + 1; 283 | IF v_counter = 1 THEN 284 | v_sql := 'GRANT ' || v_action; 285 | ELSE 286 | v_sql := v_sql || ', ' || v_action; 287 | END IF; 288 | END LOOP grants; 289 | IF v_counter > 0 THEN 290 | v_sql := v_sql || ' TO ROLE "' || v_rec.groname || '";'; 291 | RAISE INFO '%', v_sql; 292 | IF dryrun IS NOT TRUE THEN 293 | EXECUTE v_sql; 294 | END IF; 295 | END IF; 296 | END LOOP model_create; 297 | 298 | --Defaults to Schemas 299 | v_location := 10000; 300 | <> 301 | FOR v_rec IN 302 | SELECT sub2.usename, sub2.nspname, sub2.defaclobjtype, split_part(split_part(sub2.acl, '=', 1), ' ', 2) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant FROM (SELECT sub.defaclobjtype, sub.usename, sub.nspname, split_part(array_to_string(sub.defaclacl, ','), ',', i) AS acl FROM (SELECT u.usename, n.nspname, d.defaclobjtype, generate_series(1, array_upper(d.defaclacl, 1)) AS i, d.defaclacl FROM pg_default_acl d JOIN pg_namespace n ON d.defaclnamespace = n.oid JOIN pg_user u ON u.usesysid = d.defacluser) AS sub WHERE split_part(array_to_string(sub.defaclacl, ','), ',', i) LIKE 'group %') AS sub2 ORDER BY 2, 3, 4 LOOP 303 | v_grant_count := len(v_rec.grogrant); 304 | v_counter := 0; 305 | <> 306 | FOR v_i IN 1..v_grant_count LOOP 307 | v_grant := substring(v_rec.grogrant, v_i, 1); 308 | --r=tables 309 | IF v_rec.defaclobjtype = 'r' THEN 310 | IF v_grant = 'a' THEN 311 | v_action := 'INSERT'; 312 | ELSIF v_grant = 'w' THEN 313 | v_action := 'UPDATE'; 314 | ELSIF v_grant = 'd' THEN 315 | v_action := 'DELETE'; 316 | ELSIF v_grant = 'r' THEN 317 | v_action := 'SELECT'; 318 | ELSIF v_grant = 'x' THEN 319 | v_action := 'REFERENCES'; 320 | ELSIF v_grant = 'D' THEN 321 | v_action := 'DROP'; 322 | ELSIF v_grant = 't' THEN 323 | v_action := 'TRIGGER'; 324 | ELSIF v_grant = 'R' THEN 325 | v_action := 'RULE'; 326 | END IF; 327 | --f=functions; p=procedures 328 | ELSIF v_rec.defaclobjtype = 'f' OR v_rec.defaclobjtype = 'p' THEN 329 | IF v_grant = 'X' THEN 330 | v_action := 'EXECUTE'; 331 | END IF; 332 | END IF; 333 | v_counter := v_counter + 1; 334 | IF v_counter = 1 THEN 335 | v_sql := 'ALTER DEFAULT PRIVILEGES FOR USER "' || v_rec.usename || '" IN SCHEMA "' || v_rec.nspname || '" GRANT '|| v_action; 336 | ELSE 337 | v_sql := v_sql || ', ' || v_action; 338 | END IF; 339 | END LOOP grants; 340 | IF v_counter > 0 THEN 341 | IF v_rec.defaclobjtype = 'r' THEN 342 | v_sql := v_sql || ' ON TABLES TO ROLE "' || v_rec.groname || '";'; 343 | ELSIF v_rec.defaclobjtype = 'f' THEN 344 | v_sql := v_sql || ' ON FUNCTIONS TO ROLE "' || v_rec.groname || '";'; 345 | ELSIF v_rec.defaclobjtype = 'p' THEN 346 | v_sql := v_sql || ' ON PROCEDURES TO ROLE "' || v_rec.groname || '";'; 347 | END IF; 348 | RAISE INFO '%', v_sql; 349 | IF dryrun IS NOT TRUE THEN 350 | EXECUTE v_sql; 351 | END IF; 352 | END IF; 353 | END LOOP defaults; 354 | 355 | --Columns to Roles 356 | v_location := 11000; 357 | <> 358 | FOR v_rec IN 359 | SELECT sub3.groname, sub3.nspname, sub3.relname, sub3.attname, sub3.grogrant 360 | FROM ( 361 | SELECT sub2.nspname, sub2.relname, sub2.attname, split_part(sub2.acl, '=', 1) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant 362 | FROM ( 363 | SELECT sub.nspname, sub.relname, sub.attname, split_part(split_part(array_to_string(sub.attacl, ','), ',', i), ' ', 2) AS acl 364 | FROM ( 365 | SELECT n.nspname, c.relname, a.attname, generate_series(1, array_upper(a.attacl, 1)) AS i, a.attacl 366 | FROM pg_class c 367 | JOIN pg_namespace n ON c.relnamespace = n.oid 368 | JOIN pg_attribute_info a ON c.oid = a.attrelid 369 | WHERE a.attacl IS NOT NULL 370 | ) AS sub 371 | WHERE split_part(array_to_string(sub.attacl, ','), ',', i) LIKE 'group %' 372 | ) AS sub2 373 | ) AS sub3 374 | ORDER BY 1, 2, 3 LOOP 375 | v_grant_count := len(v_rec.grogrant); 376 | <> 377 | FOR v_i IN 1..v_grant_count LOOP 378 | v_grant := substring(v_rec.grogrant, v_i, 1); 379 | IF v_grant = 'w' THEN 380 | v_action := 'UPDATE'; 381 | ELSIF v_grant = 'r' THEN 382 | v_action := 'SELECT'; 383 | END IF; 384 | v_sql := 'GRANT ' || v_action || ' ("' || v_rec.attname || '") ON "' || v_rec.nspname || '"."' || v_rec.relname || '" TO ROLE "' || v_rec.groname || '";'; 385 | 386 | RAISE INFO '%', v_sql; 387 | IF dryrun IS NOT TRUE THEN 388 | EXECUTE v_sql; 389 | END IF; 390 | END LOOP grants; 391 | END LOOP columns; 392 | EXCEPTION 393 | WHEN OTHERS THEN 394 | v_now := timeofday(); 395 | RAISE EXCEPTION '(%:%:%:%)', v_location, v_now, v_procedure, sqlerrm; 396 | END; 397 | $$ 398 | LANGUAGE plpgsql 399 | SECURITY DEFINER; 400 | -------------------------------------------------------------------------------- /query_column_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub4.nspname AS schema_name, sub4.relname AS table_name, sub4.attname AS column_name, 2 | CASE 3 | WHEN substring(sub4.grogrant, pos, 1) = 'w' THEN 'UPDATE' 4 | WHEN substring(sub4.grogrant, pos, 1) = 'r' THEN 'SELECT' END AS privilege_type, sub4.groname AS group_name 5 | FROM ( 6 | SELECT sub3.nspname, sub3.relname, sub3.attname, generate_series(1, length(sub3.grogrant)) AS pos, sub3.groname, sub3.grogrant 7 | FROM ( 8 | SELECT sub2.nspname, sub2.relname, sub2.attname, split_part(sub2.acl, '=', 1) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant 9 | FROM ( 10 | SELECT sub.nspname, sub.relname, sub.attname, split_part(split_part(array_to_string(sub.attacl, ','), ',', i), ' ', 2) AS acl 11 | FROM ( 12 | SELECT n.nspname, c.relname, a.attname, generate_series(1, array_upper(a.attacl, 1)) AS i, a.attacl 13 | FROM pg_class c 14 | JOIN pg_namespace n ON c.relnamespace = n.oid 15 | JOIN pg_attribute_info a ON c.oid = a.attrelid 16 | WHERE a.attacl IS NOT NULL 17 | ) AS sub 18 | WHERE split_part(array_to_string(sub.attacl, ','), ',', i) LIKE 'group %' 19 | ) AS sub2 20 | ) AS sub3 21 | ) AS sub4 22 | ORDER BY 1, 2, 3; 23 | -------------------------------------------------------------------------------- /query_column_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT namespace_name AS schema_name, relation_name AS table_name, column_name, privilege_type, identity_name AS role_name 2 | FROM svv_column_privileges 3 | WHERE identity_type = 'role' 4 | ORDER BY 1, 2, 3, 5, 4; 5 | -------------------------------------------------------------------------------- /query_create_model_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT CASE WHEN substring(sub3.grogrant, pos, 1) = 'U' THEN 'CREATE MODEL' END AS privilege_type, sub3.groname AS group_name 2 | FROM ( 3 | SELECT sub2.groname, generate_series(1, length(sub2.grogrant)) AS pos, sub2.grogrant 4 | FROM ( 5 | SELECT split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant 6 | FROM ( 7 | SELECT l.lanname, split_part(split_part(array_to_string(l.lanacl, ','), ',', i), ' ', 2) AS acl 8 | FROM ( 9 | SELECT lanname, generate_series(1, array_upper(lanacl, 1)) AS i, lanacl 10 | FROM pg_language 11 | WHERE lanname = 'mlfunc' 12 | ) AS l 13 | WHERE split_part(array_to_string(l.lanacl, ','), ',', l.i) LIKE 'group %' 14 | ) AS sub 15 | ) AS sub2 16 | ) AS sub3 17 | ORDER BY 2, 1; 18 | -------------------------------------------------------------------------------- /query_create_model_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT 'CREATE MODEL' as privilege_type, identity_name 2 | FROM svv_language_privileges 3 | WHERE identity_type = 'role' AND language_name = 'mlfunc' 4 | ORDER BY 2, 1; 5 | -------------------------------------------------------------------------------- /query_database_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub3.datname AS database_name, CASE WHEN substring(sub3.grogrant, pos, 1) = 'C' THEN 'CREATE' WHEN substring(sub3.grogrant, pos, 1) = 'T' THEN 'TEMP' END AS privilege_type, sub3.groname AS group_name 2 | FROM ( 3 | SELECT sub2.datname, generate_series(1, length(sub2.grogrant)) AS pos, sub2.groname, sub2.grogrant 4 | FROM ( 5 | SELECT sub.datname, split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant 6 | FROM ( 7 | SELECT d.datname, split_part(split_part(array_to_string(d.datacl, ','), ',', i), ' ', 2) AS acl 8 | FROM ( 9 | SELECT datname, generate_series(1, array_upper(datacl, 1)) AS i, datacl 10 | FROM pg_database 11 | ) AS d 12 | WHERE split_part(array_to_string(d.datacl, ','), ',', i) LIKE 'group %' 13 | ) AS sub 14 | ) AS sub2 15 | ) AS sub3 16 | ORDER BY 1, 3, 2; 17 | -------------------------------------------------------------------------------- /query_database_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT database_name, privilege_type, identity_name AS role_name 2 | FROM svv_database_privileges 3 | WHERE identity_type = 'role' 4 | ORDER BY 1, 3, 2; 5 | -------------------------------------------------------------------------------- /query_datashare_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT datashare_name, identity_name AS group_name, privilege_type 2 | FROM svv_datashare_privileges 3 | WHERE identity_type = 'group' 4 | ORDER BY 1, 3, 2; 5 | -------------------------------------------------------------------------------- /query_datashare_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT datashare_name, identity_name AS role_name, privilege_type 2 | FROM svv_datashare_privileges 3 | WHERE identity_type = 'role' 4 | ORDER BY 1, 3, 2; 5 | -------------------------------------------------------------------------------- /query_defaults_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub4.usename AS owner_name, sub4.nspname AS schema_name, 2 | CASE WHEN sub4.defaclobjtype = 'r' THEN 3 | CASE WHEN substring(sub4.grogrant, pos, 1) = 'a' THEN 'INSERT' 4 | WHEN substring(sub4.grogrant, pos, 1) = 'w' THEN 'UPDATE' 5 | WHEN substring(sub4.grogrant, pos, 1) = 'd' THEN 'DELETE' 6 | WHEN substring(sub4.grogrant, pos, 1) = 'D' THEN 'TRUNCATE' 7 | WHEN substring(sub4.grogrant, pos, 1) = 'r' THEN 'SELECT' 8 | WHEN substring(sub4.grogrant, pos, 1) = 'x' THEN 'REFERENCES' 9 | WHEN substring(sub4.grogrant, pos, 1) = 't' THEN 'TRIGGER' 10 | WHEN substring(sub4.grogrant, pos, 1) = 'R' THEN 'RULE' END 11 | WHEN sub4.defaclobjtype = 'f' OR sub4.defaclobjtype = 'p' THEN 12 | CASE WHEN substring(sub4.grogrant, pos, 1) = 'X' THEN 'EXECUTE' END END AS privilege_type, sub4.groname AS group_name 13 | FROM ( 14 | SELECT sub3.usename, sub3.nspname, sub3.defaclobjtype, generate_series(1, length(sub3.grogrant)) AS pos, sub3.groname, sub3.grogrant 15 | FROM ( 16 | SELECT sub2.usename, sub2.nspname, sub2.defaclobjtype, split_part(split_part(sub2.acl, '=', 1), ' ', 2) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant 17 | FROM ( 18 | SELECT sub.defaclobjtype, sub.usename, sub.nspname, split_part(array_to_string(sub.defaclacl, ','), ',', i) AS acl 19 | FROM ( 20 | SELECT u.usename, n.nspname, d.defaclobjtype, generate_series(1, array_upper(d.defaclacl, 1)) AS i, d.defaclacl 21 | FROM pg_default_acl d 22 | JOIN pg_namespace n ON d.defaclnamespace = n.oid 23 | JOIN pg_user u ON u.usesysid = d.defacluser 24 | ) AS sub 25 | WHERE split_part(array_to_string(sub.defaclacl, ','), ',', i) LIKE 'group %' 26 | ) AS sub2 27 | ) AS sub3 28 | ) AS sub4 29 | ORDER BY 1, 2, 4, 3; 30 | -------------------------------------------------------------------------------- /query_defaults_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT owner_name, schema_name, privilege_type, grantee_name AS role_name 2 | FROM svv_default_privileges 3 | WHERE grantee_type = 'role' AND schema_name IS NOT NULL 4 | ORDER BY 1, 2, 4, 3; 5 | -------------------------------------------------------------------------------- /query_language_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub3.lanname AS language_name, CASE WHEN substring(sub3.grogrant, pos, 1) = 'U' THEN 'USAGE' END as privilege_type, sub3.groname AS group_name 2 | FROM ( 3 | SELECT sub2.lanname, generate_series(1, length(sub2.grogrant)) AS pos, sub2.groname, sub2.grogrant 4 | FROM ( 5 | SELECT sub.lanname, split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant 6 | FROM ( 7 | SELECT l.lanname, split_part(split_part(array_to_string(l.lanacl, ','), ',', i), ' ', 2) AS acl 8 | FROM ( 9 | SELECT lanname, generate_series(1, array_upper(lanacl, 1)) AS i, lanacl 10 | FROM pg_language 11 | ) AS l 12 | WHERE l.lanname <> 'mlfunc' AND split_part(array_to_string(l.lanacl, ','), ',', i) LIKE 'group %' 13 | ) AS sub 14 | ) AS sub2 15 | ) AS sub3 16 | ORDER BY 1, 3, 2; 17 | -------------------------------------------------------------------------------- /query_language_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT language_name, privilege_type, identity_name 2 | FROM svv_language_privileges 3 | WHERE identity_type = 'role' AND language_name <> 'mlfunc' 4 | ORDER BY 1, 3, 2; 5 | -------------------------------------------------------------------------------- /query_model_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT namespace_name AS schema_name, model_name, identity_name AS group_name, privilege_type 2 | FROM svv_ml_model_privileges 3 | WHERE identity_type = 'group' 4 | ORDER BY 1, 2, 4, 3; 5 | -------------------------------------------------------------------------------- /query_model_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT namespace_name AS schema_name, model_name, identity_name AS role_name, privilege_type 2 | FROM svv_ml_model_privileges 3 | WHERE identity_type = 'role' 4 | ORDER BY 1, 2, 4, 3; 5 | -------------------------------------------------------------------------------- /query_routine_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub4.routine_type, sub4.nspname AS schema_name, sub4.routine_name, CASE WHEN substring(sub4.grogrant, pos, 1) = 'X' THEN 'EXECUTE' END AS privilege_type, sub4.groname AS group_name 2 | FROM ( 3 | SELECT sub3.nspname, sub3.routine_name, generate_series(1, length(sub3.grogrant)) AS pos, sub3.routine_type, sub3.groname, sub3.grogrant 4 | FROM ( 5 | SELECT sub2.nspname, sub2.proname || '(' || sub2.proargs || ')' AS routine_name, sub2.routine_type, split_part(sub2.acl, '=', 1) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant 6 | FROM ( 7 | SELECT sub.nspname, sub.proname, sub.routine_type, sub.proargs, split_part(split_part(array_to_string(sub.proacl, ','), ',', i), ' ', 2) AS acl 8 | FROM ( 9 | SELECT n.nspname, p.proname, CASE WHEN l.lanname = 'plpgsql' THEN 'PROCEDURE' ELSE 'FUNCTION' END AS routine_type, oidvectortypes(p.proargtypes) proargs, generate_series(1, array_upper(p.proacl, 1)) as i, p.proacl 10 | FROM pg_proc p 11 | JOIN pg_namespace n ON p.pronamespace = n.oid 12 | JOIN pg_language l ON p.prolang = l.oid 13 | JOIN pg_user u ON p.proowner = u.usesysid 14 | WHERE l.lanname <> 'mlfunc' AND u.usename <> 'rdsdb' AND p.proacl IS NOT NULL 15 | ) AS sub 16 | WHERE split_part(array_to_string(sub.proacl, ','), ',', i) LIKE 'group %' 17 | ) AS sub2 18 | ) AS sub3 19 | ) AS sub4 20 | ORDER BY 1, 2, 3, 5, 4; 21 | -------------------------------------------------------------------------------- /query_routine_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT CASE WHEN l.lanname = 'plpgsql' THEN 'PROCEDURE' ELSE 'FUNCTION' END AS routine_type, f.namespace_name AS schema_name, f.function_name || '(' || f.argument_types || ')', f.privilege_type, f.identity_name AS role_name 2 | FROM svv_function_privileges f 3 | JOIN pg_namespace n ON n.nspname = f.namespace_name 4 | JOIN pg_proc p ON p.proname = f.function_name AND oidvectortypes(p.proargtypes) = f.argument_types AND p.pronamespace = n.oid 5 | JOIN pg_language l ON p.prolang = l.oid 6 | WHERE f.identity_type = 'role' AND l.lanname <> 'mlfunc' 7 | ORDER BY 1, 2, 3, 5, 4; 8 | -------------------------------------------------------------------------------- /query_schema_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub3.nspname AS schema_name, CASE WHEN substring(sub3.grogrant, pos, 1) = 'C' THEN 'CREATE' WHEN substring(sub3.grogrant, pos, 1) = 'U' THEN 'USAGE' END AS privilege_type, sub3.groname AS group_name 2 | FROM ( 3 | SELECT sub2.nspname, generate_series(1, length(sub2.grogrant)) AS pos, sub2.groname, sub2.grogrant 4 | FROM ( 5 | SELECT sub.nspname, split_part(sub.acl, '=', 1) AS groname, split_part(split_part(sub.acl, '=', 2), '/', 1) AS grogrant 6 | FROM ( 7 | SELECT n.nspname, split_part(split_part(array_to_string(nspacl, ','), ',', i), ' ', 2) AS acl 8 | FROM ( 9 | SELECT nspname, generate_series(1, array_upper(nspacl, 1)) AS i, nspacl 10 | FROM pg_namespace 11 | ) AS n 12 | WHERE split_part(array_to_string(nspacl, ','), ',', i) LIKE 'group %' 13 | ) AS sub 14 | ) AS sub2 15 | ) AS sub3 16 | ORDER BY 1, 3, 2; 17 | -------------------------------------------------------------------------------- /query_schema_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT namespace_name AS schema_name, privilege_type, identity_name AS role_name 2 | FROM svv_schema_privileges 3 | WHERE identity_type = 'role' 4 | ORDER BY 1, 3, 2; 5 | -------------------------------------------------------------------------------- /query_table_group_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT sub4.nspname AS schema_name, sub4.relname AS table_name, 2 | CASE WHEN substring(sub4.grogrant, pos, 1) = 'a' THEN 'INSERT' 3 | WHEN substring(sub4.grogrant, pos, 1) = 'w' THEN 'UPDATE' 4 | WHEN substring(sub4.grogrant, pos, 1) = 'd' THEN 'DELETE' 5 | WHEN substring(sub4.grogrant, pos, 1) = 'r' THEN 'SELECT' 6 | WHEN substring(sub4.grogrant, pos, 1) = 'x' THEN 'REFERENCES' 7 | WHEN substring(sub4.grogrant, pos, 1) = 't' THEN 'TRIGGER' 8 | WHEN substring(sub4.grogrant, pos, 1) = 'R' THEN 'RULE' END AS privilege_type, sub4.groname AS group_name 9 | FROM ( 10 | SELECT sub3.nspname, sub3.relname, generate_series(1, length(sub3.grogrant)) AS pos, sub3.groname, sub3.grogrant 11 | FROM ( 12 | SELECT sub2.nspname, sub2.relname, split_part(sub2.acl, '=', 1) AS groname, split_part(split_part(sub2.acl, '=', 2), '/', 1) AS grogrant 13 | FROM ( 14 | SELECT sub.nspname, sub.relname, split_part(split_part(array_to_string(sub.relacl, ','), ',', i), ' ', 2) AS acl 15 | FROM ( 16 | SELECT n.nspname, c.relname, generate_series(1, array_upper(c.relacl, 1)) AS i, c.relacl 17 | FROM pg_class c 18 | JOIN pg_namespace n ON c.relnamespace = n.oid 19 | ) AS sub 20 | WHERE split_part(array_to_string(sub.relacl, ','), ',', i) LIKE 'group %' 21 | ) AS sub2 22 | ) AS sub3 23 | ) AS sub4 24 | ORDER BY 1, 2, 4, 3; 25 | -------------------------------------------------------------------------------- /query_table_role_grants.sql: -------------------------------------------------------------------------------- 1 | SELECT namespace_name AS schema_name, relation_name AS table_name, privilege_type, identity_name AS role_name 2 | FROM svv_relation_privileges 3 | WHERE identity_type = 'role' 4 | ORDER BY 1, 2, 4, 3; 5 | -------------------------------------------------------------------------------- /query_users_in_groups.sql: -------------------------------------------------------------------------------- 1 | SELECT u.usesysid AS user_id, u.usename AS user_name, g.grosysid AS group_id, g.groname AS group_name 2 | FROM pg_group g 3 | JOIN pg_user u ON u.usesysid = ANY(g.grolist) 4 | ORDER BY g.groname, u.usesysid; 5 | -------------------------------------------------------------------------------- /query_users_in_roles.sql: -------------------------------------------------------------------------------- 1 | SELECT user_id, user_name, role_id, role_name 2 | FROM svv_user_grants 3 | ORDER BY role_name, user_name; 4 | --------------------------------------------------------------------------------