Changed the whole thing, now it really works

There are 2 functions, one with "SECURITY INVOKER" and the other  with
"SECURITY DEFINER".
One is to be invoked by the final user and the other one only for the
main function.
This commit is contained in:
dodger 2022-01-05 11:06:33 +01:00
parent 42cf4a43ee
commit 736c6871aa
2 changed files with 60 additions and 13 deletions

View File

@ -1,9 +1,10 @@
-- grant execution on the function
grant execute on function dba.passchanger(_password text) to dodger; -- grant usage for schema dba
grant usage on schema dba to dodger ;
-- grant execute on the function that change_my_password the pass but no on the one that change VALID UNTIL
grant execute on function dba.change_my_password(text) to dodger;
-- only insert is needed to allow audit trace -- only insert is needed to allow audit trace
GRANT INSERT ON TABLE dba.pwdhistory TO dodger; GRANT INSERT ON TABLE dba.pwdhistory TO dodger;
-- the following permissions are necessary to change the 'VALID UNTIL' date
grant select on pg_catalog.pg_authid to dodger ;
grant update (rolvaliduntil) on pg_catalog.pg_authid to dodger ;

View File

@ -2,6 +2,14 @@
-- Schema creation -- Schema creation
create schema dba ; create schema dba ;
-- 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 ;
-- password history table -- password history table
CREATE TABLE IF NOT EXISTS dba.pwdhistory CREATE TABLE IF NOT EXISTS dba.pwdhistory
( (
@ -12,12 +20,45 @@ CREATE TABLE IF NOT EXISTS dba.pwdhistory
TABLESPACE pg_default; TABLESPACE pg_default;
ALTER TABLE IF EXISTS dba.pwdhistory ALTER TABLE IF EXISTS dba.pwdhistory
OWNER to postgres; OWNER to dba;
-- the function
CREATE OR REPLACE FUNCTION dba.passchanger(_password text) -- ######################################
-- ######################################
-- real functions
-- ######################################
-- ######################################
CREATE OR REPLACE FUNCTION dba.change_valid_until(_usename text)
RETURNS integer RETURNS integer
SECURITY DEFINER
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$
begin
EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=now() + interval ''120 days'' where rolname=''%I'' ', _usename);
return 0;
exception
-- trap existing error and re-raise with added detail
when unique_violation then -- = error code 23505
raise unique_violation
using detail = 'Error updating VALID UNTIL.';
end
$BODY$;
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
LANGUAGE 'plpgsql' LANGUAGE 'plpgsql'
COST 100 COST 100
VOLATILE PARALLEL UNSAFE VOLATILE PARALLEL UNSAFE
@ -40,11 +81,12 @@ begin
insert into dba.pwdhistory insert into dba.pwdhistory
(usename, password, changed_on) (usename, password, changed_on)
values (_usename, md5(_password),now()); values (_usename, md5(_password),now());
EXECUTE format('update pg_catalog.pg_authid set rolvaliduntil=now() + interval ''120 days'' where rolname=''%I'' ', _usename); 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 -- update pg_catalog.pg_authid
-- set rolvaliduntil='2021-12-30 00:00:00+01' where rolname='dodger' ; -- set rolvaliduntil='2021-12-30 00:00:00+01' where rolname='dodger' ;
return 0; return 0;
exception exception
-- trap existing error and re-raise with added detail -- trap existing error and re-raise with added detail
when unique_violation then -- = error code 23505 when unique_violation then -- = error code 23505
raise unique_violation raise unique_violation
@ -52,3 +94,7 @@ exception
end end
$BODY$; $BODY$;
ALTER FUNCTION dba.change_my_password(text)
OWNER TO dba;
REVOKE EXECUTE ON FUNCTION dba.change_my_password(text) From PUBLIC;