-
Notifications
You must be signed in to change notification settings - Fork 37
Allow login on Reader Instance #297
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Open
bdealey
wants to merge
4
commits into
aws:main
Choose a base branch
from
bdealey:main
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
Open
Changes from all commits
Commits
Show all changes
4 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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; |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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; |
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Tested briefly on PG17 and this part threw a syntax error, I think plpgsql doesn't support exception handling like this? the exception handling should be after the BEGIN block
https://www.postgresql.org/docs/current/plpgsql-control-structures.html#PLPGSQL-ERROR-TRAPPING