Skip to content

Commit 646203f

Browse files
authored
Add clientauth documentation and example (#231)
Based on the existing documentation for the passcheck hook. Added a SQL file under the examples directory containing a sample clientauth extension that locks out users after repeated failed login attempts.
1 parent 1835907 commit 646203f

File tree

2 files changed

+289
-0
lines changed

2 files changed

+289
-0
lines changed

docs/04_hooks.md

Lines changed: 219 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -172,3 +172,222 @@ SET password_encryption TO 'md5';
172172
-- set to "password"
173173
ERROR: password must not be found in a common password dictionary
174174
```
175+
176+
### Client authentication hook (`clientauth`)
177+
178+
You can use the client authentication hook (`clientauth`) to provide additional control over the authentication process. Functions registered to the hook are called after a client finishes authentication, whether or not the authentication is successful.
179+
180+
**Warning: clientauth functions are executed as superuser!** Please define functions carefully and be aware of potential security risks.
181+
182+
#### Function definition
183+
184+
A `clientauth` hook function takes the following arguments and returns either `text` or `void`.
185+
186+
clientauth_hook(port pgtle.clientauth_port_subset, status integer)
187+
188+
* `port` (`pgtle.clientauth_port_subset`) - an object containing the following fields. These are a subset of the Port object that client authentication hook passes to internal C functions.
189+
* `noblock` (`bool`)
190+
* `remote_host` (`text`)
191+
* `remote_hostname` (`text`)
192+
* `remote_hostname_resolv` (`integer`)
193+
* `remote_hostname_errcode` (`integer`)
194+
* `database_name` (`text`)
195+
* `user_name` (`text`)
196+
* `status` (`integer`) - connection status code. This can be one of the following:
197+
* 0, representing successful connection
198+
* -1, representing a connection error
199+
200+
If the function returns a non-empty string or raises an exception, the string or exception message is interpreted as an error. `clientauth` will return the error to the user and fail their connection.
201+
202+
If the function returns an empty string or void, `clientauth` will allow the connection.
203+
204+
Runtime errors in the function will also be returned to the user as an error message, causing their connection to fail.
205+
206+
#### Configuration
207+
208+
##### `pgtle.enable_clientauth`
209+
210+
Controls whether a `clientauth` hook is enabled. There are three settings:
211+
212+
* `off` — Disables the `clientauth` hook. This is the default.
213+
* `on` — only calls `clientauth` hook if one is present in the table.
214+
* `require` — requires a `clientauth` hook to be defined. **Warning**: connections will be rejected if no functions are registered to the `clientauth` hook.
215+
216+
Context: SIGHUP. **Note: A database restart is needed to enable the clientauth feature**, i.e. to switch from `off` to `on` or `require`. This is because the background workers need to be registered on postmaster startup. A database restart is not needed to disable the clientauth feature (i.e. switch from `on` or `require` to `off`), but restarting is recommended in order to prevent the background workers from consuming resources unnecessarily.
217+
218+
#### `pgtle.clientauth_db_name`
219+
220+
Controls which database to query for the registered `clientauth` function. All `clientauth` functions should be created in this database. When a client connects to any database in the cluster, the functions in `clientauth_db_name` will be executed.
221+
222+
Context: Postmaster
223+
224+
Default: `postgres`
225+
226+
#### `pgtle.clientauth_num_parallel_workers`
227+
228+
Controls the number of background workers to handle connection requests in parallel. This value can be increased to handle large connection storms and/or `clientauth` functions that are expected to run long. Note that `clientauth_num_parallel_workers` should always be less than `max_worker_processes`, with enough headroom for other workers to be started.
229+
230+
Context: Postmaster.
231+
232+
Default: 1
233+
234+
Minimum: 1
235+
236+
Maximum: `min(max_connections, 256)`
237+
238+
#### `pgtle.clientauth_users_to_skip`
239+
240+
Comma-separated list of users that will be skipped by the `clientauth` feature. If the connecting user is on this list, `clientauth` functions will not be executed and the connection will flow as if `clientauth` was disabled.
241+
242+
Context: SIGHUP
243+
244+
Default: `""`
245+
246+
#### `pgtle.clientauth_databases_to_skip`
247+
248+
Comma-separated list of databases that will be skipped by the `clientauth` feature. If the connecting database is on this list, `clientauth` functions will not be executed and the connection will flow as if `clientauth` was disabled.
249+
250+
Context: SIGHUP
251+
252+
Default: `""`
253+
254+
#### Example
255+
256+
The following examples demonstrates how to write a hook function that rejects a connection if the user has failed to authenticate 5 or more times in a row. After writing this function, the example shows how to register the hook function as part of the `clientauth` hook.
257+
258+
This example is available in the `examples` directory as a standalone `.sql` file.
259+
260+
```sql
261+
SELECT pgtle.install_extension(
262+
'client_lockout',
263+
'1.0',
264+
'Lock out users after 5 consecutive failed login attempts',
265+
$_pgtle_$
266+
CREATE SCHEMA client_lockout;
267+
268+
CREATE TABLE client_lockout.failed_attempts (
269+
user_name text PRIMARY KEY,
270+
num_failed_attempts integer
271+
);
272+
273+
CREATE FUNCTION client_lockout.hook_function(port pgtle.clientauth_port_subset, status integer)
274+
RETURNS void AS $$
275+
DECLARE
276+
num_attempts integer;
277+
BEGIN
278+
-- Get number of consecutive failed attempts by this user
279+
SELECT COALESCE(num_failed_attempts, 0) FROM client_lockout.failed_attempts
280+
WHERE user_name = port.user_name
281+
INTO num_attempts;
282+
283+
-- If at least 5 consecutive failed attempts, reject
284+
IF num_attempts >= 5 THEN
285+
RAISE EXCEPTION '% has failed 5 or more times consecutively, please contact the database administrator', port.user_name;
286+
END IF;
287+
288+
-- If password is wrong, increment counter
289+
IF status = -1 THEN
290+
INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts)
291+
VALUES (port.user_name, 0)
292+
ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = client_lockout.failed_attempts.num_failed_attempts + 1;
293+
END IF;
294+
295+
-- If password is right, reset counter to 0
296+
IF status = 0 THEN
297+
INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts)
298+
VALUES (port.user_name, 0)
299+
ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0;
300+
END IF;
301+
END
302+
$$ LANGUAGE plpgsql;
303+
304+
-- Allow extension owner to reset the password attempts of any user to 0
305+
CREATE FUNCTION client_lockout.reset_attempts(target_user_name text)
306+
RETURNS void AS $$
307+
BEGIN
308+
INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts)
309+
VALUES (target_user_name, 0)
310+
ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0;
311+
END
312+
$$ LANGUAGE plpgsql;
313+
314+
SELECT pgtle.register_feature('client_lockout.hook_function', 'clientauth');
315+
316+
REVOKE ALL ON SCHEMA client_lockout FROM PUBLIC;
317+
$_pgtle_$
318+
);
319+
```
320+
321+
To enable the `clientauth` hook, you will need to set `pgtle.enable_clientauth` to `on` or `require` and restart the database. For example:
322+
323+
```sql
324+
ALTER SYSTEM SET pgtle.enable_password_check TO 'on';
325+
```
326+
327+
Then restart the database (e.g. `pg_ctl restart`).
328+
329+
If you are using Amazon RDS or Amazon Aurora, you will need to adjust the parameter group. For example, if you are using a parameter group called `pgtle-pg` that was referenced in the [installation instructions]('01_install.md'), you can run this command:
330+
331+
```shell
332+
aws rds modify-db-parameter-group \
333+
--region us-east-1 \
334+
--db-parameter-group-name pgtle-pg \
335+
--parameters "ParameterName=pgtle.enable_clientauth,ParameterValue=on,ApplyMethod=pending-reboot"
336+
```
337+
338+
If you are using a database instance called `pg-tle-is-fun`, you can restart the database with this command:
339+
340+
```shell
341+
aws rds reboot-db-instance\
342+
--region us-east-1 \
343+
--db-instance-identifier pg-tle-is-fun
344+
```
345+
346+
You can check that the value is set using the `SHOW` command:
347+
348+
```sql
349+
SHOW pgtle.enable_clientauth;
350+
```
351+
352+
If the value is `on`, you will see the following output:
353+
354+
```
355+
pgtle.enable_clientauth
356+
-----------------------------
357+
on
358+
```
359+
360+
Here is example output of the above `clientauth` hook in action. First, a TLE admin user creates the `client_lockout` extension in the `pgtle.clientauth_db_name` database.
361+
362+
```
363+
CREATE EXTENSION client_lockout;
364+
```
365+
366+
Now the hook is active. After failing to authenticate 5 times, a user receives this message on subsequent attempts:
367+
368+
```
369+
$ psql -d postgres -U tle_user
370+
Password for user test:
371+
psql: error: connection to server on socket "/tmp/.s.PGSQL.5432" failed: FATAL: tle_user has failed 5 or more times consecutively, please contact the database administrator
372+
```
373+
374+
The database administrator can use the `client_lockout.reset_attempts` function to unlock the user.
375+
376+
```
377+
postgres=# select client_lockout.reset_attempts('tle_user');
378+
reset_attempts
379+
----------------
380+
381+
(1 row)
382+
```
383+
384+
Then the user can authenticate again.
385+
386+
```
387+
$ psql -d postgres -U tle_user
388+
Password for user test:
389+
psql (17devel)
390+
Type "help" for help.
391+
392+
postgres=>
393+
```

examples/client_lockout.sql

Lines changed: 70 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,70 @@
1+
/*
2+
* Trusted language extension that locks out users after 5 consecutive failed
3+
* login attempts. Uses the TLE clientauth feature.
4+
*
5+
* To use, execute this file in your `pgtle.clientauth_db_name` database
6+
* ('postgres' by default) and run `CREATE EXTENSION client_lockout`. Then set
7+
* `pgtle.enable_clientauth` to 'on' or 'require' and restart PostgreSQL
8+
* database.
9+
*/
10+
11+
CREATE EXTENSION IF NOT EXISTS pg_tle;
12+
13+
SELECT pgtle.install_extension(
14+
'client_lockout',
15+
'1.0',
16+
'Lock out users after 5 consecutive failed login attempts',
17+
$_pgtle_$
18+
CREATE SCHEMA client_lockout;
19+
20+
CREATE TABLE client_lockout.failed_attempts (
21+
user_name text PRIMARY KEY,
22+
num_failed_attempts integer
23+
);
24+
25+
CREATE FUNCTION client_lockout.hook_function(port pgtle.clientauth_port_subset, status integer)
26+
RETURNS void AS $$
27+
DECLARE
28+
num_attempts integer;
29+
BEGIN
30+
-- Get number of consecutive failed attempts by this user
31+
SELECT COALESCE(num_failed_attempts, 0) FROM client_lockout.failed_attempts
32+
WHERE user_name = port.user_name
33+
INTO num_attempts;
34+
35+
-- If at least 5 consecutive failed attempts, reject
36+
IF num_attempts >= 5 THEN
37+
RAISE EXCEPTION '% has failed 5 or more times consecutively, please contact the database administrator', port.user_name;
38+
END IF;
39+
40+
-- If password is wrong, increment counter
41+
IF status = -1 THEN
42+
INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts)
43+
VALUES (port.user_name, 0)
44+
ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = client_lockout.failed_attempts.num_failed_attempts + 1;
45+
END IF;
46+
47+
-- If password is right, reset counter to 0
48+
IF status = 0 THEN
49+
INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts)
50+
VALUES (port.user_name, 0)
51+
ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0;
52+
END IF;
53+
END
54+
$$ LANGUAGE plpgsql;
55+
56+
-- Allow extension owner to reset the password attempts of any user to 0
57+
CREATE FUNCTION client_lockout.reset_attempts(target_user_name text)
58+
RETURNS void AS $$
59+
BEGIN
60+
INSERT INTO client_lockout.failed_attempts (user_name, num_failed_attempts)
61+
VALUES (target_user_name, 0)
62+
ON CONFLICT (user_name) DO UPDATE SET num_failed_attempts = 0;
63+
END
64+
$$ LANGUAGE plpgsql;
65+
66+
SELECT pgtle.register_feature('client_lockout.hook_function', 'clientauth');
67+
68+
REVOKE ALL ON SCHEMA client_lockout FROM PUBLIC;
69+
$_pgtle_$
70+
);

0 commit comments

Comments
 (0)