Last active
February 6, 2024 20:01
-
-
Save jirutka/afa3ce62b1430abf7572 to your computer and use it in GitHub Desktop.
Some convenient scripts to manage ownerships and privileges in PostgreSQL.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
#!/bin/sh | |
# | |
# The MIT License | |
# | |
# Copyright 2014-2017 Jakub Jirutka <jakub@jirutka.cz>. | |
# | |
# Permission is hereby granted, free of charge, to any person obtaining a copy | |
# of this software and associated documentation files (the "Software"), to deal | |
# in the Software without restriction, including without limitation the rights | |
# to use, copy, modify, merge, publish, distribute, sublicense, and/or sell | |
# copies of the Software, and to permit persons to whom the Software is | |
# furnished to do so, subject to the following conditions: | |
# | |
# The above copyright notice and this permission notice shall be included in | |
# all copies or substantial portions of the Software. | |
# | |
# THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR | |
# IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, | |
# FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE | |
# AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER | |
# LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, | |
# OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN | |
# THE SOFTWARE. | |
# Credit: Based on http://stackoverflow.com/a/2686185/305019 by Alex Soto | |
usage() { | |
cat <<- EOF | |
usage: $0 options | |
This script changes ownership for all tables, views, sequences and functions in | |
a database schema and also owner of the schema itself. | |
Note: If you want to change the ownership of all objects, in the specified database, | |
owned by a database role, then you can simply use command "REASSIGN OWNED". | |
OPTIONS: | |
-h Show this message | |
-d Database name | |
-o New owner name | |
-s Schema (defaults to public) | |
EOF | |
} | |
pgexec() { | |
local cmd=$1 | |
psql --no-psqlrc --no-align --tuples-only --record-separator=\0 --quiet \ | |
--command="$cmd" "$DB_NAME" | |
} | |
pgexec_echo() { | |
local cmd=$1 | |
psql --no-psqlrc --no-align --tuples-only --record-separator=\0 --quiet \ | |
--echo-queries --command="$cmd" "$DB_NAME" | |
} | |
DB_NAME='' | |
NEW_OWNER='' | |
SCHEMA='public' | |
while getopts 'hd:o:s:' OPTION; do | |
case $OPTION in | |
h) usage; exit 1;; | |
d) DB_NAME=$OPTARG;; | |
o) NEW_OWNER=$OPTARG;; | |
s) SCHEMA=$OPTARG;; | |
esac | |
done | |
if [ -z "$DB_NAME" ] || [ -z "$NEW_OWNER" ]; then | |
usage | |
exit 1 | |
fi | |
# Using the NULL byte as the separator as its the only character disallowed from PG table names. | |
IFS=\0 | |
# Change owner of schema itself. | |
pgexec_echo "ALTER SCHEMA \"$SCHEMA\" OWNER TO \"$NEW_OWNER\";" | |
# Change owner of tables and views. | |
for tbl in $(pgexec "SELECT table_name FROM information_schema.tables WHERE table_schema = '$SCHEMA';") \ | |
$(pgexec "SELECT table_name FROM information_schema.views WHERE table_schema = '$SCHEMA';"); do | |
pgexec_echo "ALTER TABLE \"$SCHEMA\".\"$tbl\" OWNER TO $NEW_OWNER;" | |
done | |
# Change owner of sequences. | |
for seq in $(pgexec "SELECT sequence_name FROM information_schema.sequences WHERE sequence_schema = '$SCHEMA';"); do | |
pgexec_echo "ALTER SEQUENCE \"$SCHEMA\".\"$seq\" OWNER TO $NEW_OWNER;" | |
done | |
# Change owner of functions and procedures. | |
for func in $(pgexec "SELECT quote_ident(p.proname) || '(' || pg_catalog.pg_get_function_identity_arguments(p.oid) || ')' \ | |
FROM pg_catalog.pg_proc p JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace \ | |
WHERE n.nspname = '$SCHEMA';"); do | |
pgexec_echo "ALTER FUNCTION \"$SCHEMA\".$func OWNER TO $NEW_OWNER;" | |
done |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
#!/bin/sh | |
# | |
# The MIT License | |
# | |
# Copyright 2014-2017 Jakub Jirutka <jakub@jirutka.cz>. | |
# | |
# Permission is hereby granted, free of charge, to any person obtaining a copy | |
# of this software and associated documentation files (the "Software"), to deal | |
# in the Software without restriction, including without limitation the rights | |
# to use, copy, modify, merge, publish, distribute, sublicense, and/or sell | |
# copies of the Software, and to permit persons to whom the Software is | |
# furnished to do so, subject to the following conditions: | |
# | |
# The above copyright notice and this permission notice shall be included in | |
# all copies or substantial portions of the Software. | |
# | |
# THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR | |
# IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, | |
# FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE | |
# AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER | |
# LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, | |
# OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN | |
# THE SOFTWARE. | |
usage() { | |
cat <<- EOF | |
usage: $0 options | |
This script grants read-only privileges to a specified role on all tables, views | |
and sequences in a database schema and sets them as default. | |
OPTIONS: | |
-h Show this message | |
-d Database name | |
-u Role name | |
-s Schema (defaults to public) | |
EOF | |
} | |
pgexec() { | |
local cmd=$1 | |
psql --no-psqlrc --no-align --tuples-only --record-separator=\0 --quiet \ | |
--echo-queries --command="$cmd" "$DB_NAME" | |
} | |
DB_NAME='' | |
ROLE='' | |
SCHEMA='public' | |
while getopts 'hd:u:s:' OPTION; do | |
case $OPTION in | |
h) usage; exit 1;; | |
d) DB_NAME=$OPTARG;; | |
u) ROLE=$OPTARG;; | |
s) SCHEMA=$OPTARG;; | |
esac | |
done | |
if [ -z "$DB_NAME" ] || [ -z "$ROLE" ]; then | |
usage | |
exit 1 | |
fi | |
pgexec "GRANT CONNECT ON DATABASE $DB_NAME TO $ROLE; | |
GRANT USAGE ON SCHEMA $SCHEMA TO $ROLE; | |
GRANT SELECT ON ALL TABLES IN SCHEMA $SCHEMA TO $ROLE; | |
GRANT SELECT ON ALL SEQUENCES IN SCHEMA $SCHEMA TO $ROLE; | |
ALTER DEFAULT PRIVILEGES IN SCHEMA $SCHEMA GRANT SELECT ON TABLES TO $ROLE; | |
ALTER DEFAULT PRIVILEGES IN SCHEMA $SCHEMA GRANT SELECT ON SEQUENCES TO $ROLE;" | |
# Uncomment to also grant privileges on all functions/procedures in the schema. | |
# It's usually NOT what you want - functions can modify data! | |
#pgexec "GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA $SCHEMA TO $ROLE; | |
#ALTER DEFAULT PRIVILEGES IN SCHEMA $SCHEMA GRANT EXECUTE ON FUNCTIONS TO $ROLE;" |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment