702 lines
28 KiB
Bash
Executable File
702 lines
28 KiB
Bash
Executable File
#!/bin/bash
|
|
#
|
|
# Restores a PostgreSQL database from a native or dockerized RDBMS instance
|
|
# accessible from this box. Also creates an owner user for this database
|
|
# (if it doesn't exist) and grants the appropriate privileges.
|
|
#
|
|
# Mainly, this is a pretty fatty wrapper script to the pg_restore command.
|
|
#
|
|
# Needs PostgreSQL v9.5 (or later).
|
|
# To restore a database with the necessary user management and grants,
|
|
# needs the superuser privileges on RDBMS.
|
|
# * If the RDBMS runs dockerized you need call this script as a Docker manager
|
|
# user (member of the docker Linux group).
|
|
# * If we're using a native PostgreSQL, you need call this script as a Linux
|
|
# user whom the superuser role has been already granted within PostgreSQL,
|
|
# or you need provide the superuser credentials as well. You must enable
|
|
# th desired connection in pg_hba file.
|
|
#
|
|
# Accepts few pg_restore options as well as the optional database password
|
|
# and database admin credentials with the optional output pathname:
|
|
#
|
|
# $0 [-U dbuser] [-P dbpass] [-h dbhost] [-p dbport]
|
|
# [-A dbadminuser] [-a dbadminpass] [-r dbreadonlyrole] [-R]
|
|
# [-C container] [-d database] [-f dumpfile ] [-F dumpformat]
|
|
# [database (if not in -d)] [dumpfile (if not in -f)]
|
|
#
|
|
# Author: Kovács Zoltán <kovacs.zoltan@smartfront.hu>
|
|
# Kovács Zoltán <kovacsz@marcusconsulting.hu>
|
|
# License: GNU/GPL v3+ (https://www.gnu.org/licenses/gpl-3.0.en.html)
|
|
# 2023-06-18 v1.0
|
|
# new: forked from the "SMARTERP_skeleton" repository.
|
|
# 2022-12-01 v0.9
|
|
# fix: Coworker user's support.
|
|
# The reassign function has been totally rewritten. Now considers only
|
|
# that object what has been actually changed. Does nothing when the
|
|
# owner is already the designated role, so doesn't disturb the ERP's
|
|
# own functionality (e.g doesn't cause deadlocks).
|
|
# While now isn't strictly necessary, transferring the event triggers
|
|
# to the postgres user has remained, because of better portability.
|
|
# 2022-11-11 v0.8
|
|
# new: Coworker users' support.
|
|
# An event trigger automatism has been set to ensure, the owner of the
|
|
# objects to be created by coworkers is the database owner. This avoids
|
|
# permission problems when a foreign role (e.g a DBA or a coworker user)
|
|
# creates new objects.
|
|
# fix: Reassigning the restored objects failed, when an object have to
|
|
# owned by a DBA user (e.g an event trigger). Now we transfer
|
|
# these objects' ownership (actually the event trigger objects' only)
|
|
# to the postgres user before trying the global reassign.
|
|
# 2022-11-03 v0.7
|
|
# new: Automatic DB username and password generation if them had not
|
|
# specified. NOTE: if the user has just been created, the password appears
|
|
# in the log as a plain text - even if it was given (so it is known).
|
|
# new: Added a new parameter: -R to create a non-login R/O role, named same
|
|
# as DB username with a -ro suffix. The R/O privileges will be granted
|
|
# automatically to this role. This works same as -r parameter but
|
|
# you doesn't need to specify the role name.
|
|
# mod: Now prefers the TCP authentication over the peer authentication.
|
|
# mod: Improved notification messages.
|
|
# 2022-04-21 v0.6
|
|
# mod: R/O role doesn't created by default but on demand only.
|
|
# mod: Enhanced REASSIGN on the just loaded DB to avoid shared memory
|
|
# exhaustion.
|
|
# 2022-01-24 v0.5
|
|
# new: Creates a R/O role as well if it doesn't exist yet.
|
|
# 2021-10-25 v0.4
|
|
# fix: A typo has blocked receiving DB admin username from the environment.
|
|
# 2021-06-27 v0.3
|
|
# fix: Honors properly the given DBA credentials.
|
|
# fix: Handles given but empty parameters better.
|
|
# mod: Slash is allowed in hostname for Unix sockets.
|
|
# 2021-01-11 v0.2
|
|
# fix: The --no-acl option has been added to the pg_restore call.
|
|
# mod: Honors the DB locale settings (if any) included into dumpfile.
|
|
# mod: The minimum PostgreSQL version has been relaxed to 9.5.
|
|
# 2020-12-17 v0.1 Initial release
|
|
|
|
# Accepted environment variables and their defaults.
|
|
#
|
|
PGCONTAINER=${PGCONTAINER-""} # Docker container's name
|
|
PGDATABASE=${PGDATABASE-""} # Database name to restore
|
|
PGDBAUSER=${PGDBAUSER:-""} # Database admin superuser
|
|
PGDBAPASSWORD=${PGDBAPASSWORD:-""} # Credentials for the DBA user
|
|
PGDUMP=${PGDUMP-""} # Dump file pathname
|
|
PGDUMPFORMAT=${PGDUMPFORMAT:-"c"} # Dump file format
|
|
PGHOST=${PGHOST:-"localhost"} # Connection parameter
|
|
PGOPTIONS=${PGOPTIONS-""} # Options to pass to pg_dump
|
|
PGPASSWORD=${PGPASSWORD-""} # Credential for the DB owner
|
|
PGPORT=${PGPORT:-"5432"} # Connection parameter
|
|
PGROROLE=${PGROROLE:-""} # R/O role to the restored DB
|
|
PGUSER=${PGUSER:-""} # Owner of the restored DB
|
|
|
|
### Temporailly ignored! Need to sanitize.
|
|
PGOPTIONS=""
|
|
|
|
# Basic environment settings.
|
|
#
|
|
LANG=C
|
|
LC_ALL=C
|
|
|
|
# Other initialisations.
|
|
#
|
|
LOGSTAMP="\"\$DATE\" +%Y-%m-%d\ %H:%M:%S" # Timestamp format for logs
|
|
postgres='postgres' # Main DBA user
|
|
vetodatabases="postgres template0 template1" # Tech DBs aren't to restore
|
|
# Sets the flag: we need a R/O role as well.
|
|
[[ -n "$PGROROLE" ]] && PGRONEED='yes' || PGRONEED=''
|
|
|
|
# Messages.
|
|
#
|
|
MSG_BADDBTYPE="Unknown database type"
|
|
MSG_BADDUMP="Doesn't exist or doesn't a dumpfile:"
|
|
MSG_BADOPT="Invalid option"
|
|
MSG_BADPARAM="Doubtful parameter:"
|
|
MSG_BLOCKING="This is a fatal error - restore has been aborted."
|
|
MSG_CONNTERM="DB connection(s) have forced to terminate"
|
|
MSG_DOCKERGRPNEED="You must be a member of the docker group."
|
|
MSG_DOESNOTRUN="Doesn't run the database container"
|
|
MSG_EVTCHGFAIL="Failed to change ownership of the event trigger "
|
|
MSG_EXISTING="did not create exisiting object"
|
|
MSG_FAILCONN="Failed to connect the RDBMS."
|
|
MSG_MISSINGDEP="Fatal: missing dependency"
|
|
MSG_NEWPASS="a new password has been set:"
|
|
MSG_NEWROLE="a new role has been generated:"
|
|
MSG_NONBLOCKING="Recoverable error - restore is continuing."
|
|
MSG_OLDRDBMS="RDBMS version is too old"
|
|
MSG_PEERAUTH="Peer authentication has been used."
|
|
MSG_PERCENT="Hint: you may use percent-encoding (e.g %40 instead of @)"
|
|
MSG_SUPERNEED="user must have DBA (database superuser) privileges."
|
|
|
|
MSG_USAGE="Usage: $0 [options] [database [dump_pathname]]\n"
|
|
MSG_USAGE+="Option:\tENVVAR:\n"
|
|
MSG_USAGE+=" -A\tPGDBAUSER \tPostgres DB admin superuser\n"
|
|
MSG_USAGE+=" -a\tPGDBAPASSWORD \tPostgres DB admin password\n"
|
|
MSG_USAGE+=" -C\tPGCONTAINER \tPostgres Docker container's name\n"
|
|
MSG_USAGE+=" -d\tPGDATABASE \tPostgres database to restore\n"
|
|
MSG_USAGE+=" -f\tPGDUMPFILE \tDumpfile pathname\n"
|
|
#MSG_USAGE+=" -F\tPGDUMPFORMAT \tDumpfile format ($PGDUMPFORMAT)\n"
|
|
MSG_USAGE+=" -h\tPGHOST \tHostname or IP to connect (localhost)\n"
|
|
MSG_USAGE+=" -p\tPGPORT \tTCP port to connect (5432)\n"
|
|
MSG_USAGE+=" -P\tPGPASSWORD \tPostgres password\n"
|
|
MSG_USAGE+=" -r\tPGROROLE \tPostgres R/O rolename\n"
|
|
MSG_USAGE+=" -R\t \tPostgres R/O role (names it)\n"
|
|
MSG_USAGE+=" -U\tPGUSER \tPostgres username\n"
|
|
|
|
# Getting options.
|
|
#
|
|
while getopts ":-:a:A:C:d:D:f:F:h:H:p:P:r:Ru:U:" option
|
|
do
|
|
case ${option} in
|
|
"-" )
|
|
if [ "$OPTARG" = "help" ]; then echo -e "$MSG_USAGE" >&2; exit
|
|
else echo "$MSG_BADOPT --$OPTARG" >&2; exit 1
|
|
fi
|
|
;;
|
|
"A" ) PGDBAUSER="$OPTARG" ;;
|
|
"a" ) PGDBAPASSWORD="$OPTARG" ;;
|
|
"C" ) PGCONTAINER="$OPTARG" ;;
|
|
"d" | "D" ) PGDATABASE="$OPTARG" ;;
|
|
"f" ) PGDUMPFILE="$OPTARG" ;;
|
|
"F" ) PGDUMPFORMAT="$OPTARG" ;;
|
|
"h" | "H" ) PGHOST="$OPTARG" ;;
|
|
"P" ) PGPASSWORD="$OPTARG" ;;
|
|
"p" ) PGPORT="$OPTARG" ;;
|
|
"r" ) PGRONEED="yes"; PGROROLE="$OPTARG" ;;
|
|
"R" ) PGRONEED="yes" ;;
|
|
"u" | "U" ) PGUSER="$OPTARG" ;;
|
|
\? ) echo "$MSG_BADOPT -$OPTARG" >&2; exit 1
|
|
;;
|
|
esac
|
|
done; shift $((OPTIND -1))
|
|
# All options has been processed.
|
|
|
|
# Checks the dependencies.
|
|
#
|
|
# Conditional dependencies (according to native or dockerized environment).
|
|
[[ -z "$PGCONTAINER" ]] \
|
|
&& additem="psql pg_restore" \
|
|
|| additem="docker"
|
|
# Common dependencies.
|
|
TR=$(which tr 2>/dev/null)
|
|
if [ -z "$TR" ]; then echo "$MSG_MISSINGDEP tr."; exit 1 ; fi
|
|
for item in basename cat cut dd date dirname grep head id locale readlink sed \
|
|
tail tee $additem
|
|
do
|
|
if [ -n "$(which $item)" ]
|
|
then export $(echo $item | "$TR" '[:lower:]' '[:upper:]')=$(which $item)
|
|
else echo "$MSG_MISSINGDEP $item." >&2; exit 1; fi
|
|
done
|
|
# All dependencies are available via "$THECOMMAND" (upper case) call.
|
|
|
|
# Sanitizing the parameters.
|
|
#
|
|
# https://www.postgresql.org/docs/current/sql-syntax-lexical.html (modded)
|
|
[[ -n "$PGDBAUSER" ]] && [[ ! "$PGDBAUSER" =~ ^([[:alnum:]]|[.-_\\+])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGDBAUSER\n$MSG_USAGE" >&2 && exit 1
|
|
# This is only an arbitrary restriction, partially enforces percent-encoding.
|
|
[[ -n "$PGDBAPASSWORD" ]] && [[ ! "$PGDBAPASSWORD" =~ ^([[:alnum:]]|[ !~&#$<>()%+-_.])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGDBAPASSWORD\n$MSG_PERCENT\n$MSG_USAGE" >&2 && exit 1
|
|
# https://www.postgresql.org/docs/current/sql-syntax-lexical.html (modded)
|
|
[[ -n "$PGCONTAINER" ]] && [[ ! "$PGCONTAINER" =~ ^([[:alnum:]]|[-_])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGCONTAINER\n$MSG_USAGE" >&2 && exit 1
|
|
# https://www.postgresql.org/docs/current/sql-syntax-lexical.html (modded)
|
|
[[ -n "$PGDATABASE" ]] && [[ ! "$PGDATABASE" =~ ^([[:alnum:]]|[_])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGDATABASE\n$MSG_USAGE" >&2 && exit 1
|
|
# This is only an arbitrary restriction.
|
|
[[ -n "$PGDUMPFILE" ]] && [[ ! "$PGDUMPFILE" =~ ^([[:alnum:]]|[ .-_/])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGDUMPFILE\n$MSG_USAGE" >&2 && exit 1
|
|
# https://tools.ietf.org/html/rfc1123#page-13 (relaxed)
|
|
[[ -n "$PGHOST" ]] && [[ ! "$PGHOST" =~ ^([[:alnum:]]|[.-/])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGHOST\n$MSG_USAGE" >&2 && exit 1
|
|
# https://tools.ietf.org/html/rfc6056 (relaxed)
|
|
[[ -z "$PGPORT" ]] && PGPORT="5432"
|
|
[[ -n "$PGPORT" ]] && [[ ! "$PGPORT" =~ ^[1-9]([[:digit:]]){0,4}$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGPORT\n$MSG_USAGE" >&2 && exit 1
|
|
# This is only an arbitrary restriction, partially enforces percent-encoding.
|
|
[[ -n "$PGPASSWORD" ]] && [[ ! "$PGPASSWORD" =~ ^([[:alnum:]]|[ !~&#$<>()%+-_.])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGPASSWORD\n$MSG_PERCENT\n$MSG_USAGE" >&2 && exit 1
|
|
# https://www.postgresql.org/docs/current/sql-syntax-lexical.html (modded)
|
|
[[ -n "$PGROROLE" ]] && [[ ! "$PGROROLE" =~ ^([[:alnum:]]|[.-_\\+])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGROROLE\n$MSG_USAGE" >&2 && exit 1
|
|
# https://www.postgresql.org/docs/current/sql-syntax-lexical.html (modded)
|
|
[[ -n "$PGUSER" ]] && [[ ! "$PGUSER" =~ ^([[:alnum:]]|[.-_\\+])*$ ]] \
|
|
&& echo -e "$MSG_BADPARAM $PGUSER\n$MSG_USAGE" >&2 && exit 1
|
|
# We've at least a minimally checked parameters.
|
|
|
|
# Need to be root or a Docker manager user if the DB runs in a container.
|
|
#
|
|
[[ -n "$PGCONTAINER" ]] && [[ "$USER" != 'root' ]] \
|
|
&& [[ -z "$(echo "$("$ID" -Gn "$USER") " | "$GREP" ' docker ')" ]] \
|
|
&& echo "$MSG_DOCKERGRPNEED" >&2 && exit 1 #"
|
|
|
|
# If the PostgreSQL is dockerized the container must be running.
|
|
#
|
|
[[ -n "$PGCONTAINER" ]] \
|
|
&& [[ -z "$("$DOCKER" ps -q -f name=$PGCONTAINER)" ]] \
|
|
&& echo "$MSG_DOESNOTRUN $PGCONTAINER" >&2 && exit 1
|
|
|
|
# Determines the database to restore.
|
|
#
|
|
# Lack of -d the 1st non-option parameter is the database's name.
|
|
if [ -z "$PGDATABASE" -a -n "$1" ]; then PGDATABASE="$1"; shift; fi
|
|
# The database's name is mandatory.
|
|
if [ -z "$PGDATABASE" ]
|
|
then echo -e "$MSG_USAGE" >&2; exit 1; fi
|
|
# A humble sanitization.
|
|
if [[ ! "$PGDATABASE" =~ ^([[:alnum:]]|[_])*$ ]]
|
|
then echo -e "$MSG_USAGE" >&2; exit 1; fi
|
|
# Silently refuses the PostgreSQL internal databases.
|
|
for veto in $vetodatabases ""
|
|
do
|
|
[[ "$PGDATABASE" = "$veto" ]] && exit 0
|
|
done
|
|
# We've a database name to restore.
|
|
|
|
# Determines the database owner's username.
|
|
#
|
|
# If it isn't given we suppose the name is identical to the database
|
|
if [ -z "$PGUSER" ]; then
|
|
PGUSER="$PGDATABASE"
|
|
# We'll generate a random password for this user. This will be relevant only
|
|
# when it doesn't exist and we need to create it.
|
|
if [ -z "$PGPASSWORD" ]; then
|
|
PGPASSWORD=$("$DD" if=/dev/urandom bs=64 count=1 2>/dev/null | "$TR" -dc 'a-zA-Z0-9')
|
|
PGPASSWORD=${PGPASSWORD:0:16}
|
|
fi
|
|
fi
|
|
# We've the database owner's username.
|
|
|
|
# Determines the R/O database role's username.
|
|
#
|
|
# If it isn't given we use the owner's name appended with a "_ro" postfix.
|
|
[[ -z "$PGROROLE" ]] && PGROROLE="${PGUSER}_ro"
|
|
# We've the R/O role's name (but maybe we will not use it).
|
|
|
|
# Determines the dumpfile.
|
|
#
|
|
# Lack of -f the 2nd non-option parameter is the dumpfile's pathname.
|
|
if [ -z "$PGDUMPFILE" -a -n "$1" ]; then PGDUMPFILE="$1"; shift; fi
|
|
# The dumpfile is mandatory.
|
|
if [ -z "$PGDUMPFILE" ]
|
|
then echo -e "$MSG_USAGE" >&2; exit 1; fi
|
|
# The PGDUMPFILE must point to a readable file.
|
|
# If it is an existing symlink dereferences it to ensure, it points to a file.
|
|
if [ -h "$PGDUMPFILE" ]; then
|
|
if [[ "$("$READLINK" "$PGDUMPFILE")" != /* ]]
|
|
# relative path in symlink
|
|
then PGDUMPFILE="$("$DIRNAME" "$PGDUMPFILE")/$("$READLINK" "$PGDUMPFILE")"
|
|
# absolute path in symlink
|
|
else PGDUMPFILE="$("$READLINK" "$PGDUMPFILE")"; fi
|
|
fi
|
|
# Let's check it!
|
|
if [ ! -r "$PGDUMPFILE" -o ! -f "$PGDUMPFILE" ]
|
|
then echo -e "$MSG_BADDUMP $PGDUMPFILE"; exit 1; fi
|
|
# We've an existing dumpfile.
|
|
|
|
# Tries to get the locale settings of this dump.
|
|
#
|
|
PGDUMPPROPS=""
|
|
LOCALES=$("$LOCALE" -a | "$TR" [:upper:] [:lower:])
|
|
[[ -z "$PG_RESTORE" ]] && PG_RESTORE="$(which pg_restore)"
|
|
if [ -n "$PG_RESTORE" -a -x "$PG_RESTORE" ]; then
|
|
# Gets the CREATE DATABASE line and parses it.
|
|
createline=$("$PG_RESTORE" -C -s -f - "$PGDUMPFILE" | \
|
|
"$GREP" -i 'create database')
|
|
# Encoding (always).
|
|
property=$(echo "$createline" | \
|
|
"$SED" -n "s/^CREATE DATABASE .* ENCODING = \('*[[:alnum:]]*'*\).*$/\1/ip")
|
|
[[ -n "$property" ]] && \
|
|
PGDUMPPROPS+=" ENCODING = $property"
|
|
# Collation (only if it is available in current locales).
|
|
property=$(echo "$createline" | \
|
|
"$SED" -n "s/^CREATE DATABASE .* LC_COLLATE = \('*[[:alnum:]._-]*'*\).*$/\1/ip")
|
|
# Tricky because of slightly different locale naming in Linux and Postgres.
|
|
[[ -n "$property" ]] && \
|
|
[[ " $(echo $LOCALES) " =~ " $(echo "$property" | "$SED" 's/utf-8/utf8/i' | \
|
|
"$TR" -d \' | "$TR" [:upper:] [:lower:]) " ]] && \
|
|
PGDUMPPROPS+=" LC_COLLATE = $property"
|
|
# CType (only if it is available in current locales).
|
|
property=$(echo "$createline" | \
|
|
"$SED" -n "s/^CREATE DATABASE .* LC_CTYPE = \('*[[:alnum:]._-]*'*\).*$/\1/ip")
|
|
# Tricky because of slightly different locale naming in Linux and Postgres.
|
|
[[ -n "$property" ]] && \
|
|
[[ " $(echo $LOCALES) " =~ " $(echo "$property" | "$SED" 's/utf-8/utf8/i' | \
|
|
"$TR" -d \' | "$TR" [:upper:] [:lower:]) " ]] && \
|
|
PGDUMPPROPS+=" LC_CTYPE = $property"
|
|
fi
|
|
# Maybe we have a guess about the dump's encoding.
|
|
|
|
# Finds the LOGFILE to use.
|
|
#
|
|
# If the folder containing the PGDUMPFILE is writable, we will use a
|
|
# logfile with the same name as the dumpfile but with .log extension.
|
|
[[ -w "$("$DIRNAME" "$PGDUMPFILE")" ]] \
|
|
&& LOGFILE="${PGDUMPFILE%.*}.log" \
|
|
|| LOGFILE="/dev/null"
|
|
# We've a suitable logfile.
|
|
|
|
# Opens the log and takes care to close it when finish.
|
|
#
|
|
echo "$(eval $LOGSTAMP) Starting job #$$ $("$TR" '\0' ' ' < /proc/$$/cmdline)" | \
|
|
"$TEE" -a "$LOGFILE"
|
|
# Sets a trap to make always a corresponding exit log entry as well.
|
|
function close_log() {
|
|
echo -e "$(eval $LOGSTAMP) Finished job #$$ $("$TR" '\0' ' ' < /proc/$$/cmdline)\n" | \
|
|
"$TEE" -a "$LOGFILE"
|
|
}
|
|
trap -- 'close_log' EXIT
|
|
# We started logging.
|
|
|
|
# Prepopulates the SQL command skeleton (macro).
|
|
#
|
|
# This skeleton makes the SQL calls independent to the environment
|
|
# (native or dockerized) and credentials. We need only actualize the
|
|
# CONNECT, DATABASE and SQLVERB clauses then eval $DO_SQLVERB.
|
|
# Warning: the parameters must had been sanitized!
|
|
DO_SQLVERB=""
|
|
DO_SQLVERB+="export PGPASSWORD=\"\$PGDBAPASSWORD\"; "
|
|
DO_SQLVERB+="echo -e \"\$SQLVERB\" | "
|
|
DO_SQLVERB+="\"\$PSQL\" \$CONNECT -t -d \$DATABASE "
|
|
# We've a suitable SQL macro.
|
|
|
|
# Do we connect the database as a DBA?
|
|
#
|
|
DATABASE="postgres"
|
|
SQLVERB="SELECT 1;"
|
|
# Sets the default DBA username for dockerized and native RDBMS as well.
|
|
if [ -z "$PGDBAUSER" ]; then
|
|
[[ -n "$PGACONTAINER" ]] \
|
|
&& PGDBAUSER="postgres" \
|
|
|| PGDBAUSER="$USER"
|
|
fi
|
|
#
|
|
# We'll try the TCP connection first.
|
|
CONNECT="-U $PGDBAUSER -w -h $PGHOST -p $PGPORT"
|
|
result=$(eval "$DO_SQLVERB" 2>/dev/null)
|
|
result="${result//[[:space:]]/}"
|
|
if [ "$result" != "1" ]; then
|
|
# On failure we'll try the local connection (Unix-domain socket) as well.
|
|
CONNECT=""
|
|
result=$(eval "$DO_SQLVERB" 2>/dev/null); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ "$result" != "1" ]] \
|
|
&& echo -e "$MSG_FAILCONN" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
# Leaves a warning about using the peer authentication.
|
|
echo -e "$MSG_PEERAUTH" | "$TEE" -a "$LOGFILE" >&2
|
|
fi
|
|
# We've a valid CONNECT clause.
|
|
|
|
# Checks the superuser privilege.
|
|
#
|
|
DATABASE="postgres"
|
|
SQLVERB="SHOW is_superuser;"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
[[ "$result" != "on" ]] \
|
|
&& echo -e "$PGDBAUSER $MSG_SUPERNEED" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
# We're a DB superuser.
|
|
|
|
# Checks the PostgreSQL version - 9.5 or later needed.
|
|
#
|
|
DATABASE="postgres"
|
|
SQLVERB="SELECT current_setting('server_version_num')::INTEGER;"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
(( result < 90500 )) \
|
|
&& echo -e "$MSG_OLDRDBMS: $result" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
# RDBMS version is proper.
|
|
|
|
# Creates the database user (owner) if it doesn't exist.
|
|
#
|
|
echo -e "CREATE ROLE" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="postgres"
|
|
SQLVERB="
|
|
DO LANGUAGE plpgsql \$\$
|
|
BEGIN
|
|
IF NOT EXISTS (SELECT * FROM pg_user WHERE usename = '$PGUSER') THEN
|
|
CREATE ROLE $PGUSER WITH LOGIN ENCRYPTED PASSWORD '$PGPASSWORD';
|
|
RAISE NOTICE '$MSG_NEWROLE $PGUSER';
|
|
RAISE NOTICE '$MSG_NEWPASS $PGPASSWORD';
|
|
ELSE
|
|
RAISE NOTICE '$MSG_EXISTING $PGUSER';
|
|
END IF;
|
|
END;
|
|
\$\$;"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
# We've the database user.
|
|
|
|
# On demand creates a (non-login) R/O role as well if it doesn't exist.
|
|
#
|
|
if [ -n "$PGRONEED" ]; then
|
|
echo -e "CREATE ROLE (R/O)" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="postgres"
|
|
SQLVERB="
|
|
DO LANGUAGE plpgsql \$\$
|
|
BEGIN
|
|
IF NOT EXISTS (SELECT * FROM pg_roles WHERE rolname = '$PGROROLE') THEN
|
|
CREATE ROLE $PGROROLE
|
|
NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE NOREPLICATION;
|
|
RAISE NOTICE '$MSG_NEWROLE $PGROROLE';
|
|
ELSE
|
|
RAISE NOTICE '$MSG_EXISTING $PGROROLE';
|
|
END IF;
|
|
END;
|
|
\$\$; "
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
# We don't consider the failure as blocking.
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# We hope that we've the R/O role defined.
|
|
fi
|
|
|
|
# Drops all existing connections to the database being restored,
|
|
# then (re)creates the database from scratch using template0.
|
|
#
|
|
echo -e "DROP DATABASE" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="postgres"
|
|
SQLVERB="
|
|
DO LANGUAGE plpgsql \$\$
|
|
DECLARE conn_terminated SMALLINT;
|
|
BEGIN
|
|
SELECT COUNT(pg_terminate_backend(pid))
|
|
FROM pg_stat_activity
|
|
INTO conn_terminated
|
|
WHERE datname='$PGDATABASE';
|
|
IF conn_terminated > 0 THEN
|
|
RAISE NOTICE '% $MSG_CONNTERM', conn_terminated ;
|
|
END IF;
|
|
END
|
|
\$\$; "
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
#
|
|
# Drops the database.
|
|
#
|
|
DATABASE="postgres"
|
|
SQLVERB="DROP DATABASE IF EXISTS $PGDATABASE; "
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
#
|
|
# Recreates the database, honors the locale properties (if any).
|
|
#
|
|
echo -e "CREATE DATABASE" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="postgres"
|
|
SQLVERB="CREATE DATABASE $PGDATABASE "
|
|
SQLVERB+="WITH TEMPLATE = template0 OWNER = $PGUSER $PGDUMPPROPS; "
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_BLOCKING" | "$TEE" -a "$LOGFILE" >&2 \
|
|
&& exit 1
|
|
# We've an empty database.
|
|
|
|
# Grants all privileges on this database, and transfers the public
|
|
# schema's ownership to the database user.
|
|
#
|
|
echo -e "GRANT" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="$PGDATABASE"
|
|
SQLVERB="GRANT ALL PRIVILEGES ON DATABASE $PGDATABASE TO $PGUSER; "
|
|
SQLVERB+="ALTER SCHEMA public OWNER TO $PGUSER; "
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# Ownership and grants have set on the empty database.
|
|
|
|
# Restores the database from the dump.
|
|
#
|
|
echo -e "RESTORE" | "$TEE" -a "$LOGFILE"
|
|
if [ -n "$PGCONTAINER" ]; then
|
|
echo "PSQL dockerized - TODO!"
|
|
else
|
|
export PGPASSWORD="$PGDBAPASSWORD"
|
|
"$PG_RESTORE" $CONNECT \
|
|
--no-owner --no-acl --disable-triggers \
|
|
-d $PGDATABASE "$PGDUMPFILE" \
|
|
>/dev/null 2> >("$TEE" -a "$LOGFILE" >&2)
|
|
fi
|
|
# Unfortunately the result code doesn't differentiate the
|
|
# blocking and non-blocking states.
|
|
[[ $? -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# We had a try to restore the database - the result isn't properly defined.
|
|
|
|
# Tries to transfer the ownership of the restored objects to the database user,
|
|
# but we've some exceptions to deal first.
|
|
echo -e "REASSIGN EVENT TRIGGERS" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="$PGDATABASE"
|
|
# The event triggers (if any) have to owned by a DBA user.
|
|
# We try to transfer the ownership of this trigger to the postgres user,
|
|
# whom by default we will not use for daily operations.
|
|
SQLVERB="
|
|
DO LANGUAGE plpgsql \$\$
|
|
DECLARE evtrg text;
|
|
BEGIN
|
|
FOR evtrg IN EXECUTE 'SELECT evtname FROM pg_event_trigger'
|
|
LOOP
|
|
BEGIN
|
|
EXECUTE 'ALTER EVENT TRIGGER ' || evtrg || ' OWNER TO $postgres';
|
|
-- EXCEPTION
|
|
-- WHEN others THEN RAISE NOTICE '$MSG_EVTCHGFAIL %', evt;
|
|
END;
|
|
END LOOP;
|
|
END;
|
|
\$\$;"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# Exceptions have dealt, we're moving to the regular objects.
|
|
#
|
|
# To avoid exhausting the shared memory or running out from
|
|
# max_locks_per_transaction first we'll enumerate all the tables and change
|
|
# its owner one by one.
|
|
echo -e "REASSIGN" | "$TEE" -a "$LOGFILE"
|
|
# Creates separate ALTER commands for each table (in all non-technical schemas).
|
|
SQLVERB="SELECT 'ALTER TABLE '|| schemaname || '.' || tablename || ' OWNER TO $PGUSER;' "
|
|
SQLVERB+="FROM pg_tables WHERE NOT schemaname IN ('pg_catalog', 'information_schema') "
|
|
SQLVERB+="ORDER BY schemaname, tablename; "
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
if [ $excode -ne 0 ]; then
|
|
# On error simply skips this step.
|
|
echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
else
|
|
# Runs the generated ALTER commands.
|
|
SQLVERB="$result"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
fi
|
|
#
|
|
# Reassigns all remaining objects at once.
|
|
SQLVERB="REASSIGN OWNED BY CURRENT_USER TO $PGUSER;"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# Ownership and R/W privileges has been set.
|
|
|
|
# Sets a function and a trigger to ensure, the objects to be created in the future
|
|
# will be owned by the database owner. This avoids permission problems, when
|
|
# a foreign role (e.g a DBA) modifies any objects.
|
|
# Based on https://stackoverflow.com/questions/64046147
|
|
#
|
|
echo -e "SET EVENT TRIGGER" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="$PGDATABASE"
|
|
# The automatic reassign procedure for a future use.
|
|
SQLVERB="
|
|
CREATE OR REPLACE FUNCTION public.trg_set_owner()
|
|
RETURNS event_trigger
|
|
LANGUAGE plpgsql
|
|
AS \$\$
|
|
DECLARE
|
|
event_tuple record;
|
|
schema varchar;
|
|
name varchar;
|
|
kind varchar;
|
|
owner varchar;
|
|
BEGIN
|
|
-- Enumerates the queries involved in this event.
|
|
FOR event_tuple IN SELECT * FROM pg_event_trigger_ddl_commands()
|
|
LOOP
|
|
-- Retrieves the relevant properties of the object.
|
|
SELECT relnamespace::regnamespace::name,
|
|
relname::text,
|
|
relkind,
|
|
relowner::regrole
|
|
INTO schema, name, kind, owner
|
|
FROM pg_catalog.pg_class
|
|
WHERE oid = event_tuple.objid;
|
|
IF NOT owner = '$PGUSER' THEN
|
|
-- Reassigns this object.
|
|
CASE
|
|
WHEN kind = 'r' THEN
|
|
EXECUTE 'ALTER TABLE IF EXISTS ' || schema || '.' || name || ' OWNER TO $PGUSER';
|
|
WHEN kind = 'v' OR kind = 'm' THEN
|
|
EXECUTE 'ALTER VIEW IF EXISTS ' || schema || '.' || name || ' OWNER TO $PGUSER';
|
|
END CASE;
|
|
END IF;
|
|
END LOOP;
|
|
END;
|
|
\$\$; "
|
|
# The event trigger whitch will call the procedure above.
|
|
SQLVERB+="
|
|
DROP EVENT TRIGGER IF EXISTS trg_set_owner;
|
|
CREATE EVENT TRIGGER trg_set_owner
|
|
ON ddl_command_end
|
|
WHEN tag IN ('CREATE TABLE', 'CREATE TABLE AS', 'CREATE VIEW')
|
|
EXECUTE PROCEDURE public.trg_set_owner(); "
|
|
# Transfers the ownership of this trigger to the postgres DBA user,
|
|
# whom by default we will not use for daily operations.
|
|
SQLVERB+="
|
|
ALTER EVENT TRIGGER trg_set_owner OWNER TO $postgres; "
|
|
# Let's execute (failure doesn't blocks).
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# Done with the reassign automatism.
|
|
|
|
# Grants SELECT on all tables and sequences in all schemas to the R/O role (if it does exist).
|
|
# https://dba.stackexchange.com/questions/95867/grant-usage-on-all-schemas-in-a-database
|
|
#
|
|
if [ -n "$PGRONEED" ]; then
|
|
echo -e "GRANT SELECT (R/O)" | "$TEE" -a "$LOGFILE"
|
|
DATABASE="$PGDATABASE"
|
|
SQLVERB="GRANT CONNECT ON DATABASE $PGDATABASE TO ${PGROROLE}; "
|
|
SQLVERB+="
|
|
DO LANGUAGE plpgsql \$do\$
|
|
DECLARE
|
|
sch text;
|
|
BEGIN
|
|
FOR sch IN SELECT nspname FROM pg_namespace where nspname != 'pg_toast'
|
|
and nspname != 'pg_temp_1' and nspname != 'pg_toast_temp_1'
|
|
and nspname != 'pg_statistic' and nspname != 'pg_catalog'
|
|
and nspname != 'information_schema'
|
|
LOOP
|
|
EXECUTE format(\$\$ GRANT USAGE ON SCHEMA %I TO ${PGROROLE} \$\$, sch);
|
|
EXECUTE format(\$\$ GRANT SELECT ON ALL TABLES IN SCHEMA %I TO ${PGROROLE} \$\$, sch);
|
|
EXECUTE format(\$\$ GRANT SELECT ON ALL SEQUENCES IN SCHEMA %I TO ${PGROROLE} \$\$, sch);
|
|
EXECUTE format(\$\$ ALTER DEFAULT PRIVILEGES IN SCHEMA %I GRANT SELECT ON TABLES TO ${PGROROLE} \$\$, sch);
|
|
EXECUTE format(\$\$ ALTER DEFAULT PRIVILEGES IN SCHEMA %I GRANT SELECT ON SEQUENCES TO ${PGROROLE} \$\$, sch);
|
|
END LOOP;
|
|
END;
|
|
\$do\$;"
|
|
result=$(eval "$DO_SQLVERB" 2> >("$TEE" -a "$LOGFILE" >&2)); excode=$?
|
|
result="${result//[[:space:]]/}"
|
|
[[ $excode -ne 0 ]] \
|
|
&& echo -e "$MSG_NONBLOCKING" | "$TEE" -a "$LOGFILE" >&2
|
|
# R/O grants has been set.
|
|
fi
|
|
# Done with grants.
|
|
|
|
# Done with restore.
|
|
|
|
# Closing log entry will be handled via EXIT trap.
|
|
#
|
|
# That's all, Folks! :)
|