Compare commits

..

No commits in common. "master" and "1d42673776101fd35371b47fd6432e4fc1dc5993" have entirely different histories.

5 changed files with 35 additions and 529 deletions

102
README.md
View File

@ -1,102 +1,4 @@
# postgresql_passchanger_function
# PostgreSQL expiration date management functions
## Table of Contents
1. [TOC](README.md#postgresql-expiration-date-management-functions)
1. [Description](README.md#description)
2. [Instructions](README.md#instructions)
3. [Helper script](README.md#helper-script)
4. [RDS considerations](README.md#rds-considerations)
5. [Security considerations](README.md#security-considerations)
## Description
This project tries to find a way to allow users the management of the `VALID UNTIL` expiration clause by themself.
Everyghin without granting `super` permissions and having a histoc of changes on a _pseudo-audit_ table.
You can easly combine this functions with the [passwordcheck extra](https://github.com/michaelpq/pg_plugins/tree/main/passwordcheck_extra) extension, the regex inside `dba.change_valid_until` match the _default_ requirements in the extension for special characters and you can change the variable `_min_password_length` to match your requirements (in the case you changed it, of course).
| :warning: WARNING |
|:---------------------------|
| Amazon RDS has some notes at the end... |
| :warning: WARNING |
## Instructions
### First deploy
Modify `passchanger.sql` according your needings:
* Change `_min_password_length` on `change_my_password` function
* Change `_password_lifetime` on `change_valid_until` function
Deploy `passchanger.sql` on the desired cluster/database.
It will:
* create a `dba` schema
* create a `dba` role
* create the `pwdhistory` table for audit purpouses
* Grant the minimum permissions for this new role so the whole thing works
* Create the 2 needed functions and grant permissions on them to `dba`
### Updates
Just execute the `CREATE OR REPLACE FUNCTION` part of the `passchanger.sql` file.
| :warning: WARNING |
|:---------------------------|
| Amazon RDS has some notes at the end... |
| :warning: WARNING |
### Allowing users to use that functions
Take the file `grants_to_grant.sql` and modify the username _dodger_ so it match the username that should have the permissions.
Execute the grants on the cluster/database you have deployed `passchanger.sql`
### Changing password & extending expiration date
The user should just execute:
```
select dba.change_my_password('YOUR_NEW_GENERATED_PASSWORD_NOT_THIS_ONE') ;
```
## Helper script
I've generated a helper script to make the process easier for users:
```
dodger@ciberterminal.net $ bash password_creator.sh
-- CHECK: password check
-- <Wl}TxqRPBQaV_N<rU#A
-- /CHECK: password check
-- ##############################################
select dba.change_my_password('<Wl}TxqRPBQaV_N<rU#A') ;
-- ##############################################
```
## RDS considerations
As Amazon has modified Postgresql so you don't have access as a *real* superuser and the _dangerous_ function
`change_valid_until` should run as the owner of the database (the user created when you deploy the database through AWS)
There's a `passchanger_rds.sql` file which should be used instead of the normal one.
For updates you should change the owner of the `change_valid_until` to the database _owner_:
```
ALTER FUNCTION dba.change_valid_until(text) OWNER TO _DATABASEOWNER;
```
Modify `_DATABASEOWNER` according your admin username...
## Security considerations
* Non-RDS `change_valid_until` function does not uses `ALTER USER` to modify `VALID UNTIL`, it makes an `update pg_catalog.pg_authid set rolvaliduntil` instead, so the `dba` user has only grant over that table/column instead of granting additional permissions to him.
* RDS `change_valid_until` should run as the database owner, is the only way to make this work as you can't access `pg_catalog.pg_authid` on rds, it uses `ALTER USER ... VALID UNTIL` instead.
Have a look at the comments

View File

@ -5,12 +5,8 @@ grant usage on schema dba to dodger ;
-- grant execute on the function change_my_password
grant execute on function dba.change_my_password(text) to dodger;
-- grant execute on the function change_valid_until
grant execute on function dba.change_valid_until(text, text) to dodger;
grant execute on function dba.change_valid_until(text) to dodger;
-- only insert is needed to allow audit trace
GRANT INSERT ON TABLE dba.pwdhistory TO dodger;
-- SET SESSION AUTORIZATION dodger ;

View File

@ -15,17 +15,11 @@ grant pg_read_all_stats to dba ;
CREATE TABLE IF NOT EXISTS dba.pwdhistory
(
usename character varying COLLATE pg_catalog."default",
usename_addres character varying COLLATE pg_catalog."default",
application_name character varying COLLATE pg_catalog."default",
password character varying COLLATE pg_catalog."default",
changed_on timestamp without time zone
)
TABLESPACE pg_default;
-- alter if you come from a previous version of the table:
-- alter table dba.pwdhistory add column usename_addres character varying ;
-- alter table dba.pwdhistory add column application_name character varying ;
ALTER TABLE IF EXISTS dba.pwdhistory
OWNER to dba;
@ -39,8 +33,6 @@ ALTER TABLE IF EXISTS dba.pwdhistory
-- ######################################
-- ######################################
drop function if exists dba.change_valid_until ;
CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text)
RETURNS integer
SECURITY DEFINER
@ -49,47 +41,31 @@ CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text)
VOLATILE PARALLEL UNSAFE
AS $BODY$
declare
_invokingfunction text := '';
_matches text;
_password_lifetime integer := 120 ; -- specify password lifetime in days
_retval INTEGER;
_expiration_date numeric ;
_invokingfunction text := '';
_matches text;
begin
select extract(epoch from localtimestamp) into _expiration_date;
select _expiration_date+(_password_lifetime*24*60*60) into _expiration_date;
select query into _invokingfunction from pg_stat_activity where pid = pg_backend_pid() ;
-- first, checking the invoking function
_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(.*\\)[[:space:]]{0,};' , 'i');
-- raise notice 'Invoking function: %', _invokingfunction;
_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=){1,100}''\\)[[:space:]]{0,};' , 'i');
-- raise notice 'Matches: %', _matches;
if _matches IS NOT NULL then
-- then checking the regex for the password
_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\([[:space:]]{0,}''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=|!){11,100}''[[:space:]]{0,}\\)[[:space:]]{0,};' , 'i');
if _matches IS NOT NULL then
EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=to_timestamp(%L) where rolname=%L ', _expiration_date, _usename);
-- INTO _retval;
RETURN 0;
else
raise exception 'Regular expresion for password check failed'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'Check your generated password an try again'
, hint = 'Read the official documentation' ;
RETURN 1;
end if;
else
-- also catches NULL
EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=now() + interval ''120 days'' where rolname=''%I'' ', _usename);
return 0;
else -- also catches NULL
-- raise custom error
raise exception 'You''re not allowed to run this function directly'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'Please call dba.change_my_password function.'
, hint = 'Invoked function: ' || _invokingfunction ;
RETURN 1;
, hint = 'Don''t mess with the devil';
end if;
end
$BODY$;
ALTER FUNCTION dba.change_valid_until(text) OWNER TO dba;
ALTER FUNCTION dba.change_valid_until(text)
OWNER TO dba;
REVOKE EXECUTE ON FUNCTION dba.change_valid_until(text) From PUBLIC;
CREATE OR REPLACE FUNCTION dba.change_my_password(_password text)
RETURNS integer
SECURITY INVOKER
@ -98,55 +74,37 @@ CREATE OR REPLACE FUNCTION dba.change_my_password(_password text)
VOLATILE PARALLEL UNSAFE
AS $BODY$
declare
_min_password_length int := 12; -- specify min length here
_usename text := '';
_useraddress text := '';
_userapp text := '';
_retval integer ;
_min_password_length int := 8; -- specify min length here
_usename text := '';
begin
select user into _usename;
if user = 'postgres' then
raise exception 'This function should not be run by user postgres'
using errcode = '22024' -- 22023 = "invalid_parameter_value'
, detail = 'Use a named user only.' ;
return 1;
end if;
if length(_password) < _min_password_length then
-- also catches NULL
if length(_password) >= _min_password_length then
EXECUTE format('ALTER USER %I WITH PASSWORD %L', _usename, _password);
else -- also catches NULL
-- raise custom error
raise exception 'Password too short!'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'Please check your password.'
, hint = 'Password must be at least ' || _min_password_length || ' characters.';
return 1;
end if;
select client_addr into _useraddress from pg_stat_activity where pid = pg_backend_pid() ;
select application_name into _userapp from pg_stat_activity where pid = pg_backend_pid() ;
--PERFORM dba.change_valid_until(_usename) ;
SELECT dba.change_valid_until(_usename)
INTO _retval;
-- this will be executed by the username invoking this function
if _retval = 0 then
EXECUTE format('ALTER USER %I WITH PASSWORD %L', _usename, _password);
insert into dba.pwdhistory
(usename, usename_addres, application_name, password, changed_on)
values (_usename, _useraddress, _userapp, md5(_password),now());
raise notice 'Password changed' ;
else
raise exception 'Could not change expiration date, please check'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'contact the dba' ;
return 1;
end if;
return 0;
insert into dba.pwdhistory
(usename, password, changed_on)
values (_usename, md5(_password),now());
PERFORM dba.change_valid_until(_usename) ;
-- EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=now() + interval ''120 days'' where rolname=''%I'' ', _usename);
-- update pg_catalog.pg_authid
-- set rolvaliduntil='2021-12-30 00:00:00+01' where rolname='dodger' ;
return 0;
exception
-- trap existing error and re-raise with added detail
when unique_violation then -- = error code 23505
raise unique_violation
using detail = 'Password already used earlier. Please try again with a different password.';
end
$BODY$;
ALTER FUNCTION dba.change_my_password(text) OWNER TO dba;
ALTER FUNCTION dba.change_my_password(text)
OWNER TO dba;
REVOKE EXECUTE ON FUNCTION dba.change_my_password(text) From PUBLIC;

View File

@ -1,156 +0,0 @@
-- Schema creation
create schema dba ;
-- role creation
create role dba with NOLOGIN NOINHERIT ;
-- grants for dba
-- GRANT rds_superuser TO dba ;
-- grant select on pg_catalog.pg_authid to dba ;
-- grant pg_read_all_stats to dba ;
-- password history table
CREATE TABLE IF NOT EXISTS dba.pwdhistory
(
usename character varying COLLATE pg_catalog."default",
usename_addres character varying COLLATE pg_catalog."default",
application_name character varying COLLATE pg_catalog."default",
password character varying COLLATE pg_catalog."default",
changed_on timestamp without time zone
)
TABLESPACE pg_default;
-- alter if you come from a previous version of the table:
-- alter table dba.pwdhistory add column usename_addres character varying ;
-- alter table dba.pwdhistory add column application_name character varying ;
ALTER TABLE IF EXISTS dba.pwdhistory
OWNER to dba;
-- ######################################
-- ######################################
-- real functions
-- ######################################
-- ######################################
drop function if exists dba.change_valid_until ;
CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text, _thepassword text)
RETURNS integer
SECURITY DEFINER
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$
declare
_invokingfunction text := '';
_matches text;
_password_lifetime integer := 120 ; -- specify password lifetime in days
_retval integer;
_expiration_epoch numeric ;
_expiration_date timestamp ;
begin
select extract(epoch from localtimestamp) into _expiration_epoch;
select _expiration_epoch+(_password_lifetime*24*60*60) into _expiration_epoch;
select to_timestamp(_expiration_epoch) into _expiration_date ;
select query into _invokingfunction from pg_stat_activity where pid = pg_backend_pid() ;
-- first, checking the invoking function
_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(.*\\)[[:space:]]{0,};' , 'i');
if _matches IS NOT NULL then
-- then checking the regex for the password
_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\([[:space:]]{0,}''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=|!){11,100}''[[:space:]]{0,}\\)[[:space:]]{0,};' , 'i');
if _matches IS NOT NULL then
-- EXECUTE format('ALTER ROLE %I WITH PASSWORD %L VALID UNTIL to_timestamp(%L) ;', _usename, _thepassword, _expiration_date);
EXECUTE format('ALTER ROLE %I WITH PASSWORD %L VALID UNTIL %L ;', _usename, _thepassword, _expiration_date);
-- INTO _retval;
RETURN 0;
else
raise exception 'Regular expresion for password check failed'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'Check your generated password (' || _thepassword || ') an try again'
, hint = 'Read the official documentation' ;
RETURN 1;
end if;
else
-- also catches NULL
-- raise custom error
raise exception 'You''re not allowed to run this function directly'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'Please call dba.change_my_password function.'
, hint = 'Invoked function: ' || _invokingfunction ;
RETURN 1;
end if;
end
$BODY$;
-- ALTER FUNCTION dba.change_valid_until(text, text) OWNER TO dba;
REVOKE EXECUTE ON FUNCTION dba.change_valid_until(text, text) From PUBLIC;
drop function if exists dba.change_my_password ;
CREATE OR REPLACE FUNCTION dba.change_my_password(_password text)
RETURNS integer
SECURITY INVOKER
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$
declare
_min_password_length int := 12; -- specify min length here
_usename text := '';
_useraddress text := '';
_userapp text := '';
_retval integer ;
begin
select user into _usename;
if user = 'postgres' then
raise exception 'This function should not be run by user postgres'
using errcode = '22024' -- 22023 = "invalid_parameter_value'
, detail = 'Use a named user only.' ;
return 1;
end if;
if length(_password) < _min_password_length then
-- also catches NULL
-- raise custom error
raise exception 'Password too short!'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'Please check your password.'
, hint = 'Password must be at least ' || _min_password_length || ' characters.';
return 1;
end if;
select client_addr into _useraddress from pg_stat_activity where pid = pg_backend_pid() ;
select application_name into _userapp from pg_stat_activity where pid = pg_backend_pid() ;
--PERFORM dba.change_valid_until(_usename, _password) ;
SELECT dba.change_valid_until(_usename, _password)
INTO _retval;
if _retval = 0 then
insert into dba.pwdhistory
(usename, usename_addres, application_name, password, changed_on)
values (_usename, _useraddress, _userapp, md5(_password),now());
raise notice 'Password changed' ;
else
raise exception 'Could not change expiration date, please check'
using errcode = '22023' -- 22023 = "invalid_parameter_value'
, detail = 'contact the dba' ;
return 1;
end if;
return 0;
end
$BODY$;
ALTER FUNCTION dba.change_my_password(text) OWNER TO dba;
REVOKE EXECUTE ON FUNCTION dba.change_my_password(text) From PUBLIC;

View File

@ -1,194 +0,0 @@
#!/bin/bash
# Exit codes:
# 1 :
# 2 :
# 3 :
# 4 :
########################################################################
#
# CONSTANTS
#
########################################################################
# colors
BOLD="\e[1m"
GREEN="\e[32m"
LIGHTGREEN="${BOLD}${GREEN}"
RED="\033[1;31m"
LIGHTRED="\033[1;31m"
BLUE="\e[34m"
LIGHTBLUE="${BOLD}${BLUE}"
YELLOW="\e[33m"
LIGHTYELLOW="${BOLD}${YELLOW}"
WHITE="\033[0;37m"
RESET="\033[0;00m"
NOW="$(date +%Y%m%d%H%M%S)"
DEBUG=0
DEBUG=1
########################################################################
#
# / CONSTANTS
#
########################################################################
########################################################################
#
# VARIABLES
#
########################################################################
SCRIPTLOG="$(dirname `readlink -f $0`)/logs/$(basename $0 .sh)_script_${NOW}.log"
SCRIPTLOGERR="$(dirname `readlink -f $0`)/logs/$(basename $0 .sh)_script_${NOW}.err"
MINIMUMPASSWORDLENGTH=8
PASSWORDLENGTH=20
THEPASSWORD=""
########################################################################
#
# / VARIABLES
#
########################################################################
########################################################################
#
# FUNCTIONS
#
########################################################################
usage()
{
printf "%s${LIGHTRED}USAGE:${RESET}
$0 -u USERNAME -t TEMPLAGE_FILE [-h] [-D]
-h this help
-D DEBUG mode
"
}
printmsg()
{
echo -e "$*"
}
output_log()
{
if [[ "${QUIETOUTPUT}" == true ]]; then
printmsg "$*" >> ${OUTPUTFILE}
else
printmsg "$*" | tee -a "${OUTPUTFILE}"
fi
}
abort_message()
{
printmsg "${LIGHTRED}ERROR${RESET}: $*"
exit 1
}
# ssh_it uses variable ${DEBUGME}
ssh_it()
{
if [[ "${DEBUGME}" && ${DEBUGME} -eq 0 ]] ; then
${SSHIT} $*
else
${SSHIT} $* 2>/dev/null
fi
}
# debug_me uses variable ${DEBUGME}
debug_me()
{
if [[ "${DEBUGME}" && ${DEBUGME} -eq 0 ]] ; then
echo -e "${LIGHTBLUE}DEBUG: ${RESET}$*"
fi
}
password_generator()
{
export THEPASSWORD="$(tr -cd '[:alnum:]@#$%^&*()_+{}|<>?=' < /dev/urandom | fold -w${PASSWORDLENGTH} | head -n 1)"
}
check_password()
{
echo -e "-- ${LIGHTYELLOW}CHECK:${RESET} password check"
echo -e "-- $(echo ${THEPASSWORD} | egrep --color "\!|@|#|\\$|%|\^|\&|\*|\(|\)|_|\+|\{|\}|\||<|>|\?|=") "
if [[ "$(echo ${THEPASSWORD} | egrep "\!|@|#|\\$|%|\^|\&|\*|\(|\)|_|\+|\{|\}|\||<|>|\?|=")" ]] ; then
RETURNVALUE=0
else
RETURNVALUE=1
fi
echo -e "-- ${LIGHTYELLOW}/CHECK:${RESET} password check"
return ${RETURNVALUE}
}
########################################################################
#
# / FUNCTIONS
#
########################################################################
########################################################################
#
# MAIN
#
########################################################################
if [[ ${DEBUG} -eq 0 ]] ; then
[[ ! -d $(dirname ${SCRIPTLOG}) ]] && mkdir -p $(dirname ${SCRIPTLOG})
[[ ! -d $(dirname ${SCRIPTLOGERR}) ]] && mkdir -p $(dirname ${SCRIPTLOGERR})
echo -e "${BLUE}DEBUGMODE${RESET} is on"
echo -e "\t SCRIPTLOG will be ${SCRIPTLOG}"
echo -e "\t SCRIPTLOGERR will be ${SCRIPTLOGERR}"
#set -x
#exec 2> ${SCRIPTLOGERR}
fi
while getopts "hDF" arg; do
case $arg in
h)
usage
;;
F)
MAYTHEFORCEBEWITHYOU=true
echo -e "${LIGHTBLUE}The force is strong in you?${RESET}"
;;
D)
DEBUG=0
;;
*)
usage
;;
esac
done
password_generator
check_password
RES=$?
echo -e "
-- ##############################################
select dba.change_my_password('${THEPASSWORD}') ;
-- ##############################################
"
exit ${EXITCODE}
########################################################################
#
# / MAIN
#
########################################################################