Skip to content

Commit bb2cdbf

Browse files
[DPE-8318] Predefined roles docs (#1107)
* Add documentation about roles and update extra user roles documentation Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Fix Juju anchors Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Fix documentation build by adding the missing links in the toctree Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Add CREATEDB to custom word list Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Add text to 'seealso' section Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Add explanation about how to escalate to another role Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Fix user allowed to call set_user Signed-off-by: Marcelo Henrique Neppel <[email protected]> * Add reset_user to approach description Signed-off-by: Marcelo Henrique Neppel <[email protected]> --------- Signed-off-by: Marcelo Henrique Neppel <[email protected]>
1 parent 6514faa commit bb2cdbf

File tree

4 files changed

+201
-8
lines changed

4 files changed

+201
-8
lines changed

docs/.custom_wordlist.txt

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -26,6 +26,7 @@ cjk
2626
codebase
2727
config
2828
configs
29+
CREATEDB
2930
cryptographically
3031
CSR
3132
CSRs

docs/explanation/index.md

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@ Clarification of standard operational concepts:
2323
:titlesonly:
2424
2525
Users <users>
26+
Roles <roles>
2627
Logs <logs>
2728
Connection pooling <connection-pooling>
2829
```
@@ -46,4 +47,4 @@ Charm event flowcharts:
4647
:titlesonly:
4748
4849
Flowcharts <flowcharts/index>
49-
```
50+
```

docs/explanation/roles.md

Lines changed: 197 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,197 @@
1+
# Roles
2+
3+
There are several definitions of roles in Charmed PostgreSQL:
4+
* Predefined PostgreSQL roles
5+
* Instance-level DB/relation-specific roles
6+
* LDAP-specific roles
7+
* Extra user roles relation flag
8+
9+
```{seealso}
10+
For details on how users relate to roles, see [](/explanation/users).
11+
```
12+
13+
## PostgreSQL 16 roles
14+
15+
```text
16+
test123=> SELECT * FROM pg_roles;
17+
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
18+
-----------------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+-------
19+
pg_database_owner | f | t | f | f | f | f | -1 | ******** | | f | | 6171
20+
pg_read_all_data | f | t | f | f | f | f | -1 | ******** | | f | | 6181
21+
pg_write_all_data | f | t | f | f | f | f | -1 | ******** | | f | | 6182
22+
pg_monitor | f | t | f | f | f | f | -1 | ******** | | f | | 3373
23+
pg_read_all_settings | f | t | f | f | f | f | -1 | ******** | | f | | 3374
24+
pg_read_all_stats | f | t | f | f | f | f | -1 | ******** | | f | | 3375
25+
pg_stat_scan_tables | f | t | f | f | f | f | -1 | ******** | | f | | 3377
26+
pg_read_server_files | f | t | f | f | f | f | -1 | ******** | | f | | 4569
27+
pg_write_server_files | f | t | f | f | f | f | -1 | ******** | | f | | 4570
28+
pg_execute_server_program | f | t | f | f | f | f | -1 | ******** | | f | | 4571
29+
pg_signal_backend | f | t | f | f | f | f | -1 | ******** | | f | | 4200
30+
pg_checkpoint | f | t | f | f | f | f | -1 | ******** | | f | | 4544
31+
pg_use_reserved_connections | f | t | f | f | f | f | -1 | ******** | | f | | 4550
32+
pg_create_subscription | f | t | f | f | f | f | -1 | ******** | | f | | 6304
33+
...
34+
```
35+
36+
## Charmed PostgreSQL 16 roles
37+
38+
Charmed PostgreSQL 16 introduces the following instance-level predefined roles:
39+
40+
* `charmed_stats` (inherit from pg_monitor)
41+
* `charmed_read` (inherit from pg_read_all_data and `charmed_stats`)
42+
* `charmed_dml` (inherit from pg_write_all_data and `charmed_read`)
43+
* `charmed_backup` (inherit from pg_checkpoint and `charmed_stats`)
44+
* `charmed_dba` (allowed to escalate to any other user, including the superuser `operator`)
45+
* `charmed_admin` (inherit from `charmed_dml` and allowed to escalate to the database-specific `charmed_<database-name>_owner` role, which is explained later in this document)
46+
* `charmed_databases_owner` (allowed to create databases; it can be requested through the CREATEDB extra user role)
47+
48+
Currently, `charmed_backup` and `charmed_dba` cannot be requested through the relation as extra user roles.
49+
50+
```text
51+
test123=> SELECT * FROM pg_roles;
52+
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
53+
-----------------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+-------
54+
...
55+
charmed_stats | f | t | f | f | f | f | -1 | ******** | | f | | 16386
56+
charmed_read | f | t | f | f | f | f | -1 | ******** | | f | | 16388
57+
charmed_dml | f | t | f | f | f | f | -1 | ******** | | f | | 16390
58+
charmed_backup | f | t | f | f | f | f | -1 | ******** | | f | | 16392
59+
charmed_dba | f | t | f | f | f | f | -1 | ******** | | f | | 16393
60+
charmed_admin | f | t | f | f | f | f | -1 | ******** | | f | | 16394
61+
charmed_databases_owner | f | t | f | t | t | f | -1 | ******** | | f | | 16395
62+
...
63+
```
64+
65+
Charmed PostgreSQL 16 also introduces catalogue/database level roles, with permissions tied to each database that's created. Example for a database named `test`:
66+
67+
```text
68+
test123=> SELECT * FROM pg_roles WHERE rolname LIKE 'charmed_test_%';
69+
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
70+
--------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+-------
71+
charmed_test_owner | f | t | f | f | f | f | -1 | ******** | | f | | 16396
72+
charmed_test_admin | f | f | f | f | f | f | -1 | ******** | | f | | 16397
73+
charmed_test_dml | f | t | f | f | f | f | -1 | ******** | | f | | 16398
74+
```
75+
76+
The `charmed_<database-name>_admin` role is assigned to each relation user (explained in the next section) with access to the specific database. When that user connects to the database, it's auto-escalated to the `charmed_<database-name>_owner` user, which will own every object inside the database, simplifying the permissions to perform operations on those objects when a new user requests access to that same database.
77+
78+
There is also a `charmed_<database-name>_dml` role that is assigned to each relation user to still allow them to read and write to the database objects even if the mechanism to auto-escalate the relation user to the `charmed_<database-name>_owner` role doesn't work.
79+
80+
### Relation-specific roles
81+
82+
For each application/relation, the dedicated user has been created:
83+
84+
```text
85+
postgres=# SELECT * FROM pg_roles;
86+
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
87+
----------------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+-------
88+
...
89+
relation_id_12 | f | t | t | t | t | f | -1 | ******** | | f | | 16416
90+
...
91+
92+
postgres=# SELECT * FROM pg_user;
93+
usename | usesysid | usecreatedb | usesuper | userepl | usebypassrls | passwd | valuntil | useconfig
94+
----------------------------+----------+-------------+----------+---------+--------------+----------+----------+-----------
95+
...
96+
relation_id_12 | 16416 | t | f | f | f | ******** | |
97+
```
98+
99+
When the same application is being related through PgBouncer, the extra users/roles are created following the same logic as above:
100+
101+
```text
102+
postgres=# SELECT * FROM pg_roles;
103+
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
104+
----------------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+-------
105+
...
106+
relation-14 | t | t | f | f | t | f | -1 | ******** | | f | | 16403
107+
pgbouncer_auth_relation_14 | t | t | f | f | t | f | -1 | ******** | | f | | 16410
108+
relation_id_13 | f | t | t | t | t | f | -1 | ******** | | f | | 16417
109+
...
110+
111+
postgres=# SELECT * FROM pg_user;
112+
usename | usesysid | usecreatedb | usesuper | userepl | usebypassrls | passwd | valuntil | useconfig
113+
----------------------------+----------+-------------+----------+---------+--------------+----------+----------+-----------
114+
...
115+
relation-14 | 16403 | f | t | f | f | ******** | |
116+
pgbouncer_auth_relation_14 | 16410 | f | t | f | f | ******** | |
117+
relation_id_13 | 16417 | t | f | f | f | ******** | |
118+
```
119+
120+
In this case, there are several records created to:
121+
* `relation_id_13` - for relation between Application and PgBouncer
122+
* `relation-14` - for relation between PgBouncer and PostgreSQL
123+
* `pgbouncer_auth_relation_14` - to authenticate end-users, which connects PgBouncer
124+
125+
## Escalation and switching identity
126+
127+
Regular relation users can temporarily escalate their privileges to other predefined roles using PostgreSQL's role-switching features. There are two approaches:
128+
129+
- SET ROLE / RESET ROLE (standard, built-in)
130+
- The `set_user` / `reset_user`
131+
132+
Both approaches are enabled by default in the charm.
133+
134+
Below they are explained in more details, including some examples.
135+
136+
### 1) Using SET ROLE and RESET ROLE
137+
138+
This is the standard PostgreSQL mechanism. A session can switch its current role to any role of which the current role is a member. Use the `SET ROLE` command to switch to a predefined role. Use RESET ROLE to return to the original role.
139+
140+
Example: escalate to `charmed_dml`:
141+
142+
```sql
143+
-- In the application/session for the relation user, escalate to the predefined role.
144+
SET ROLE charmed_dml;
145+
146+
-- Perform privileged operations that charmed_dml allows.
147+
148+
-- Then switch back to the original role.
149+
RESET ROLE;
150+
```
151+
152+
Notes:
153+
- `SET ROLE` only works if the current role is a member of the target role (i.e. the target role was requested through the `extra-user-roles` relation field).
154+
155+
### 2) Using the set_user and reset_user to switch identity to another user
156+
157+
In some deployments you may want a member of `charmed_dba` to be able to become a different PostgreSQL user (either a non-superuser or the cluster superuser) for the duration of a session. The `set_user` extension provides functions that allow a caller to change the session's effective user identity.
158+
159+
Example: switch identity to a non-superuser role:
160+
161+
```sql
162+
-- Called in a session where the relation user is a member of charmed_dba.
163+
SELECT set_user('another_user'::TEXT);
164+
165+
-- Perform actions as another_user.
166+
167+
-- Then switch back to the previous identity.
168+
SELECT reset_user();
169+
```
170+
171+
Example: switch identity to the (cluster) superuser `operator`:
172+
173+
```sql
174+
-- Called in a session where the relation user is a member of charmed_dba.
175+
SELECT set_user_u('operator'::TEXT);
176+
177+
-- Perform superuser operations.
178+
179+
-- Then switch back to the previous identity.
180+
SELECT reset_user();
181+
```
182+
183+
Important security considerations:
184+
- Prefer using `SET ROLE` when possible; use the `set_user` identity switching approach only when you need to assume an identity that cannot be achieved via role membership.
185+
186+
### Charmed PostgreSQL LDAP roles
187+
188+
To map LDAP users to PostgreSQL users, the dedicated LDAP groups have to be created before hand using [Data Integrator](https://charmhub.io/data-integrator) charm.
189+
The result of such mapping will be a new PostgreSQL Roles:
190+
191+
```text
192+
postgres=# SELECT * FROM pg_roles;
193+
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
194+
----------------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+-------
195+
...
196+
myrole | t | t | f | f | t | f | -1 | ******** | | f | | 16422
197+
```

docs/explanation/users.md

Lines changed: 1 addition & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -109,13 +109,7 @@ juju relate postgresql-k8s myclientapp
109109

110110
### Extra user roles
111111

112-
When an application charm requests a new user through the relation/integration it can specify that the user should have the `admin` role in the `extra-user-roles` field. The `admin` role enables the new user to read and write to all databases (for the `postgres` system database it can only read data) and also to create and delete non-system databases.
113-
114-
```{note}
115-
`extra-user-roles` is only supported by the modern interface `postgresql_client`. It is not supported for the legacy `pgsql` interface. R
116-
117-
Read more about the supported charm interfaces in [](/explanation/interfaces-and-endpoints).
118-
```
112+
When an application charm requests a new user through the relation/integration, it can specify that the user should be part of a predefined role to give them additional permissions. Please check [](/explanation/roles) for the list of available roles.
119113

120114
## Identity users
121115

0 commit comments

Comments
 (0)