From 32f9310a68c0d17de997377474dd8753b0f2714b Mon Sep 17 00:00:00 2001 From: Bill Dealey Date: Thu, 20 Mar 2025 09:44:24 -0400 Subject: [PATCH 1/2] catch insert/update failurs on READ-ONLY datbase instance --- .../client_lockout/client_lockout--1.2.sql | 71 +++++++++++++++++++ 1 file changed, 71 insertions(+) create mode 100644 examples/client_lockout/client_lockout--1.2.sql diff --git a/examples/client_lockout/client_lockout--1.2.sql b/examples/client_lockout/client_lockout--1.2.sql new file mode 100644 index 0000000..94d47fa --- /dev/null +++ b/examples/client_lockout/client_lockout--1.2.sql @@ -0,0 +1,71 @@ +/* + * Trusted language extension that locks out users after 5 consecutive failed + * login attempts. Uses the TLE clientauth feature. + + * To install the extension, configure the Postgres database target in + * `../env.ini`, then run `make install`. + */ + +CREATE SCHEMA client_lockout; + +CREATE TABLE client_lockout.failed_attempts ( + user_name text PRIMARY KEY, + num_failed_attempts integer +); + +CREATE FUNCTION client_lockout.hook_function(port pgtle.clientauth_port_subset, status integer) +RETURNS void AS $$ + DECLARE + num_attempts integer; + BEGIN + -- Get number of consecutive failed attempts by this user + SELECT COALESCE(num_failed_attempts, 0) FROM client_lockout.failed_attempts + WHERE user_name = port.user_name + INTO num_attempts; + + -- If at least 5 consecutive failed attempts, reject + IF num_attempts >= 5 THEN + RAISE EXCEPTION '% has failed 5 or more times consecutively, please contact the database administrator', port.user_name; + END IF; + + -- If password is wrong, increment counter + IF status = -1 THEN + INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts) + VALUES (port.user_name, 1) + ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = client_lockout.failed_attempts.num_failed_attempts + 1; + EXCEPTION + when SQLSTATE '25006' then + raise notice 'clientauth: % failed login attempt on READ-ONLY database.', port.user_name; + when others then + raise notice 'clientauth: % unhandled error encountered on login. error_code: %s error: %s', port.user_name, SQLSTATE, SQLERRM; + + END IF; + + -- If password is right, reset counter to 0 + IF status = 0 THEN + INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts) + VALUES (port.user_name, 0) + ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0; + EXCEPTION + when SQLSTATE '25006' then + raise notice 'clientauth: % successfully logged in on READ-ONLY database.', port.user_name; + when OTHERS then + raise notice 'clientauth: % successfully logged in on READ-ONLY database. code: %', port.user_name, SQLSTATE; + end; + END IF; + END +$$ LANGUAGE plpgsql; + +-- Allow extension owner to reset the password attempts of any user to 0 +CREATE FUNCTION client_lockout.reset_attempts(target_user_name text) +RETURNS void AS $$ + BEGIN + INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts) + VALUES (target_user_name, 0) + ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0; + END +$$ LANGUAGE plpgsql; + +SELECT pgtle.register_feature('client_lockout.hook_function', 'clientauth'); + +REVOKE ALL ON SCHEMA client_lockout FROM PUBLIC; From 0bf2100cf43229c86091318b5a3129efd608ceba Mon Sep 17 00:00:00 2001 From: Bill Dealey Date: Thu, 20 Mar 2025 12:16:03 -0400 Subject: [PATCH 2/2] client update script for v1.2 --- .../client_lockout--1.1--1.2.sql | 42 +++++++++++++++++++ 1 file changed, 42 insertions(+) create mode 100644 examples/client_lockout/client_lockout--1.1--1.2.sql diff --git a/examples/client_lockout/client_lockout--1.1--1.2.sql b/examples/client_lockout/client_lockout--1.1--1.2.sql new file mode 100644 index 0000000..39384f7 --- /dev/null +++ b/examples/client_lockout/client_lockout--1.1--1.2.sql @@ -0,0 +1,42 @@ +CREATE FUNCTION client_lockout.hook_function(port pgtle.clientauth_port_subset, status integer) +RETURNS void AS $$ + DECLARE + num_attempts integer; + BEGIN + -- Get number of consecutive failed attempts by this user + SELECT COALESCE(num_failed_attempts, 0) FROM client_lockout.failed_attempts + WHERE user_name = port.user_name + INTO num_attempts; + + -- If at least 5 consecutive failed attempts, reject + IF num_attempts >= 5 THEN + RAISE EXCEPTION '% has failed 5 or more times consecutively, please contact the database administrator', port.user_name; + END IF; + + -- If password is wrong, increment counter + IF status = -1 THEN + INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts) + VALUES (port.user_name, 1) + ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = client_lockout.failed_attempts.num_failed_attempts + 1; + EXCEPTION + when SQLSTATE '25006' then + raise notice 'clientauth: % failed login attempt on READ-ONLY database.', port.user_name; + when others then + raise notice 'clientauth: % unhandled error encountered on login. error_code: %s error: %s', port.user_name, SQLSTATE, SQLERRM; + + END IF; + + -- If password is right, reset counter to 0 + IF status = 0 THEN + INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts) + VALUES (port.user_name, 0) + ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0; + EXCEPTION + when SQLSTATE '25006' then + raise notice 'clientauth: % successfully logged in on READ-ONLY database.', port.user_name; + when OTHERS then + raise notice 'clientauth: % successfully logged in on READ-ONLY database. code: %', port.user_name, SQLSTATE; + end; + END IF; + END +$$ LANGUAGE plpgsql;