2022-01-04 17:46:37 +00:00
|
|
|
|
|
|
|
-- Schema creation
|
|
|
|
create schema dba ;
|
|
|
|
|
2022-01-05 10:06:33 +00:00
|
|
|
-- role creation
|
|
|
|
create role dba with NOLOGIN NOINHERIT ;
|
|
|
|
|
|
|
|
-- grants for dba
|
|
|
|
grant select on pg_catalog.pg_authid to dba ;
|
|
|
|
grant update (rolvaliduntil) on pg_catalog.pg_authid to dba ;
|
2022-01-05 12:07:06 +00:00
|
|
|
grant pg_read_all_stats to dba ;
|
2022-01-05 10:06:33 +00:00
|
|
|
|
|
|
|
|
2022-01-04 17:46:37 +00:00
|
|
|
-- password history table
|
|
|
|
CREATE TABLE IF NOT EXISTS dba.pwdhistory
|
|
|
|
(
|
|
|
|
usename character varying COLLATE pg_catalog."default",
|
2022-01-21 16:38:48 +00:00
|
|
|
usename_addres character varying COLLATE pg_catalog."default",
|
|
|
|
application_name character varying COLLATE pg_catalog."default",
|
2022-01-04 17:46:37 +00:00
|
|
|
password character varying COLLATE pg_catalog."default",
|
|
|
|
changed_on timestamp without time zone
|
|
|
|
)
|
|
|
|
TABLESPACE pg_default;
|
|
|
|
|
2022-01-21 16:47:10 +00:00
|
|
|
-- 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 ;
|
|
|
|
|
2022-01-04 17:46:37 +00:00
|
|
|
ALTER TABLE IF EXISTS dba.pwdhistory
|
2022-01-05 10:06:33 +00:00
|
|
|
OWNER to dba;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- ######################################
|
|
|
|
-- ######################################
|
|
|
|
|
|
|
|
-- real functions
|
|
|
|
|
|
|
|
-- ######################################
|
|
|
|
-- ######################################
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text)
|
|
|
|
RETURNS integer
|
|
|
|
SECURITY DEFINER
|
|
|
|
LANGUAGE 'plpgsql'
|
|
|
|
COST 100
|
|
|
|
VOLATILE PARALLEL UNSAFE
|
|
|
|
AS $BODY$
|
2022-01-05 12:07:06 +00:00
|
|
|
declare
|
|
|
|
_invokingfunction text := '';
|
|
|
|
_matches text;
|
2022-01-05 10:06:33 +00:00
|
|
|
begin
|
2022-01-05 12:07:06 +00:00
|
|
|
select query into _invokingfunction from pg_stat_activity where pid = pg_backend_pid() ;
|
|
|
|
-- raise notice 'Invoking function: %', _invokingfunction;
|
2022-05-03 08:15:32 +00:00
|
|
|
--_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=){1,100}''\\)[[:space:]]{0,};' , 'i');
|
|
|
|
_matches := regexp_matches(_invokingfunction, E'select dba\.change_my_password\\(''([[:alnum:]]|@|\\$|#|%|\\^|&|\\*|\\(|\\)|\\_|\\+|\\{|\\}|\\||<|>|\\?|=|!){11,100}''\\)[[:space:]]{0,};' , 'i');
|
2022-01-05 12:07:06 +00:00
|
|
|
-- raise notice 'Matches: %', _matches;
|
|
|
|
if _matches IS NOT NULL then
|
|
|
|
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.'
|
2022-01-21 10:03:03 +00:00
|
|
|
, hint = 'Invoked function: ' || _invokingfunction ;
|
2022-01-05 12:07:06 +00:00
|
|
|
end if;
|
2022-01-05 10:06:33 +00:00
|
|
|
end
|
|
|
|
$BODY$;
|
|
|
|
|
|
|
|
ALTER FUNCTION dba.change_valid_until(text)
|
|
|
|
OWNER TO dba;
|
|
|
|
REVOKE EXECUTE ON FUNCTION dba.change_valid_until(text) From PUBLIC;
|
2022-01-04 17:46:37 +00:00
|
|
|
|
|
|
|
|
2022-01-05 10:06:33 +00:00
|
|
|
CREATE OR REPLACE FUNCTION dba.change_my_password(_password text)
|
2022-01-04 17:46:37 +00:00
|
|
|
RETURNS integer
|
2022-01-05 10:06:33 +00:00
|
|
|
SECURITY INVOKER
|
2022-01-04 17:46:37 +00:00
|
|
|
LANGUAGE 'plpgsql'
|
|
|
|
COST 100
|
|
|
|
VOLATILE PARALLEL UNSAFE
|
|
|
|
AS $BODY$
|
|
|
|
declare
|
|
|
|
_min_password_length int := 8; -- specify min length here
|
|
|
|
_usename text := '';
|
2022-01-21 16:38:48 +00:00
|
|
|
_useraddress text := '';
|
|
|
|
_userapp text := '';
|
2022-01-04 17:46:37 +00:00
|
|
|
begin
|
|
|
|
select user into _usename;
|
2022-01-21 16:47:10 +00:00
|
|
|
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() ;
|
2022-01-04 17:46:37 +00:00
|
|
|
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.';
|
|
|
|
end if;
|
2022-01-21 16:25:56 +00:00
|
|
|
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.' ;
|
|
|
|
else
|
|
|
|
insert into dba.pwdhistory
|
2022-01-21 16:38:48 +00:00
|
|
|
(usename, usename_addres, application_name, password, changed_on)
|
|
|
|
values (_usename, _useraddress, _userapp, md5(_password),now());
|
2022-01-21 16:25:56 +00:00
|
|
|
PERFORM dba.change_valid_until(_usename) ;
|
|
|
|
end if;
|
2022-01-05 10:06:33 +00:00
|
|
|
|
2022-01-04 17:46:37 +00:00
|
|
|
return 0;
|
|
|
|
end
|
|
|
|
$BODY$;
|
|
|
|
|
2022-01-05 10:06:33 +00:00
|
|
|
ALTER FUNCTION dba.change_my_password(text)
|
|
|
|
OWNER TO dba;
|
|
|
|
REVOKE EXECUTE ON FUNCTION dba.change_my_password(text) From PUBLIC;
|
|
|
|
|