diff --git a/passchanger.sql b/passchanger.sql index 32b5ba1..86107d6 100644 --- a/passchanger.sql +++ b/passchanger.sql @@ -47,27 +47,26 @@ CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text) VOLATILE PARALLEL UNSAFE AS $BODY$ declare - _invokingfunction text := ''; - _matches text; - --_password_lifetime text := '120 days'; -- specify password lifetime - _retval INTEGER; - _expiration_date text; + _invokingfunction text := ''; + _matches text; + _password_lifetime integer := 120 ; -- specify password lifetime in days + _retval INTEGER; + _expiration_date numeric ; begin - select now() + interval '120 days' into _expiration_date ; + 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 --- raise notice 'Invoking function: %', _invokingfunction; - --_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=|!){11,100}''\\)[[:space:]]{0,};' , 'i'); _matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(.*\\)[[:space:]]{0,};' , 'i'); --- raise notice 'Matches: %', _matches; if _matches IS NOT NULL then - -- then checking the regex for the password - EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=now() + interval ''120 days'' where rolname=''%I'' ', _usename); - return 0; - _matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=|!){11,100}''\\)[[:space:]]{0,};' , 'i'); + -- 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=now() + interval ''120 days'' where rolname=''%I'' ', _usename); - EXECUTE format('ALTER ROLE %I WITH PASSWORD %L VALID UNTIL now() + interval ''%I days'' ;', _usename, _thepassword, _password_lifetime); + EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=to_timestamp(%L) where rolname=%L ', _expiration_date, _usename); + -- EXECUTE format('ALTER ROLE %I WITH PASSWORD %L VALID UNTIL now() + interval ''%I days'' ;', _usename, _thepassword, _password_lifetime); + -- EXECUTE format('ALTER ROLE %I WITH PASSWORD %L ;', _usename, _thepassword, _password_lifetime); -- INTO _retval; RETURN 0; else @@ -75,6 +74,7 @@ begin 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 @@ -83,6 +83,7 @@ begin 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$; @@ -98,16 +99,18 @@ 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 := ''; + _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 @@ -117,18 +120,29 @@ begin 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 - EXECUTE format('ALTER USER %I WITH PASSWORD %L', _usename, _password); + 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()); - PERFORM dba.change_valid_until(_usename) ; - 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 diff --git a/passchanger_rds.sql b/passchanger_rds.sql index 52f5b3d..8b7079d 100644 --- a/passchanger_rds.sql +++ b/passchanger_rds.sql @@ -39,7 +39,7 @@ ALTER TABLE IF EXISTS dba.pwdhistory -- ###################################### -- ###################################### -drop function dba.change_valid_until ; +drop function if exists dba.change_valid_until ; CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text, _thepassword text) RETURNS integer