• Stars
    star
    143
  • Rank 257,007 (Top 6 %)
  • Language PLpgSQL
  • License
    Other
  • Created about 6 years ago
  • Updated 5 months ago

Reviews

There are no reviews yet. Be the first to send feedback to the community and the maintainers!

Repository Details

A simple set of views to see ALL permissions in a PostgreSQL database

PostgreSQL permission reports and checks

This extension allows you to review object permissions on a PostgreSQL database.

Cookbook

First, you have to install the extension in the database:

CREATE EXTENSION pg_permissions SCHEMA public;

Then you need to add entries to permission_target that correspond to your desired permissions.

Let's assume we have a schema appschema, and appuser should have SELECT, UPDATE, DELETE and INSERT permissions on all tables and views in that schema:

INSERT INTO public.permission_target
   (role_name, permissions,
    object_type, schema_name)
VALUES
   ('appuser', '{SELECT,INSERT,UPDATE,DELETE}',
    'TABLE', 'appschema');
INSERT INTO public.permission_target
   (role_name, permissions,
    object_type, schema_name)
VALUES
   ('appuser', '{SELECT,INSERT,UPDATE,DELETE}',
    'VIEW', 'appschema');

Of course, the user will need the USAGE privilege on the schema:

INSERT INTO public.permission_target
   (role_name, permissions,
    object_type, schema_name)
VALUES
   ('appuser', '{USAGE}',
    'SCHEMA', 'appschema');

The user also needs USAGE privileges on the appseq sequence in that schema:

INSERT INTO public.permission_target
   (role_name, permissions,
    object_type, schema_name, object_name)
VALUES
   ('appuser', '{USAGE}',
    'SEQUENCE', 'appschema', 'appseq');

Now we can review which permissions are missing and which additional permissions are granted:

SELECT * FROM public.permission_diffs();

 missing | role_name | object_type | schema_name | object_name | column_name | permission
---------+-----------+-------------+-------------+-------------+-------------+------------
 f       | laurenz   | VIEW        | appschema   | appview     |             | SELECT
 t       | appuser   | TABLE       | appschema   | apptable    |             | DELETE
(2 rows)

That means that appuser is missing the DELETE privilege on appschema.apptable which should be granted, while user laurenz has the additional SELECT privilege on appschema.appview (missing is FALSE).

To review the actual permissions on an object, we can use the *_permissions views:

SELECT * FROM schema_permissions
   WHERE role_name = 'appuser' AND schema_name = 'appschema';

 object_type | role_name | schema_name | object_name | column_name | permissions | granted
-------------+-----------+-------------+-------------+-------------+-------------+---------
 SCHEMA      | appuser   | appschema   |             |             | USAGE       | t
 SCHEMA      | appuser   | appschema   |             |             | CREATE      | f
(2 rows)

Usage

Views

The extension provides a number of views:

  • database_permissions: permissions granted on the current database

  • schema_permissions: permissions granted on schemas

  • table_permissions: permissions granted on tables

  • view_permissions: permissions granted on views

  • column_permissions: permissions granted on table and view columns

  • function_permissions: permissions granted on functions

  • sequence_permissions: permissions granted on sequences

  • all_permissions: permissions on all objects (UNION of the above)

All views have the same columns; a column is NULL if it has no meaning for the current view.

These views can be used to examine the currently granted permissions on database objects.

The granted column of these views can be updated, which causes the appropriate GRANT or REVOKE command to be executed.

Note: Superusers are not shown in the views, as they automatically have all permissions.

Tables

The extension provides a table permission_target with which you can describe the permissions that should be granted on database objects.

If you set a relevant column in permission_target to NULL (e.g., the object_name and column_name columns in a TABLE entry), the meaning is that the entry refers to all possible objects (in the example above, all tables in the schema).

Functions

The table function permission_diffs() checks the desired permissions in permission_target against the actually granted permissions in the views of the extension and returns a table of differences.

If the first column missing is TRUE, the result is a permission that should be there but isn't; if missing is FALSE, the result row is a permission that is there even though it is not defined in permission_target (an extra permission).

Installation

Make sure the PostgreSQL extension building infrastructure is installed. If you installed PostgreSQL with installation packages, you usually need to install the "development"-Package.

Make sure that pg_config is on your PATH. Then type

make install

Then connect to the database where you want to run pg_permissions and use

CREATE EXTENSION pg_permissions;

To upgrade from an older version of the extension, run

ALTER EXTENSION pg_permissions UPDATE;

You need CREATE privileges on the schema where you install the extension.

Installation without the extension building infrastructure

This is also what Windows users will have to do because there is no extension building infrastructure for Windows.

Find out where your PostgreSQL share directory is:

pg_config --sharedir

Then copy pg_permissions.control and the SQL files to the extension subdirectory of that directory, e.g.

copy pg_permissions.control *.sql "C:\Program Files\PostgreSQL\10\share\extension"

You still have to run CREATE EXTENSION as described above.

Support

Open an issue on GitHub if you have problems or questions.

For professional support, please contact Cybertec.

More Repositories

1

pgwatch2

PostgreSQL metrics monitor/dashboard
PLpgSQL
1,792
star
2

pg_timetable

pg_timetable: Advanced scheduling for PostgreSQL
Go
1,072
star
3

pg_squeeze

A PostgreSQL extension for automatic bloat cleanup
C
462
star
4

vip-manager

Manages a virtual IP based on state kept in etcd or Consul
Go
195
star
5

pg_show_plans

Show query plans of all currently running SQL statements
C
186
star
6

postgres-showcase

Postgres features showcase (commented SQL samples) for beginners
164
star
7

pgfaceting

Faceted query acceleration for PostgreSQL using roaring bitmaps
PLpgSQL
145
star
8

ora_migrator

Tools for Oracle to PostgreSQL migration
PLpgSQL
109
star
9

zheap

⚑️ Development status and progress reporting.
HTML
93
star
10

rjsf-material-ui

[Archived] Material UI theme for react-jsonschema-form.
TypeScript
62
star
11

pgwatch

πŸ”¬PGWATCH: PostgreSQL metrics monitor/dashboard
Go
59
star
12

postgres

PostgreSQL with Transparent Data Encryption (TDE)
C
49
star
13

pg_cgroups

PostgreSQL extension to manage Linux Control Groups
C
36
star
14

pg_rewrite

Perform maintenance tasks which require a table to be rewritten (i.e. the table data to be copied to a new storage) and which are expected to limit the access to the table as little as possible
C
34
star
15

pg_crash

Periodically or randomly crash your database
C
26
star
16

safe-backup

Pre- and post-backup scripts for a safe PostgreSQL online file system backup
Shell
25
star
17

cybertec_migrator

CYBERTEC Migrator πŸ—„πŸ”€πŸ—„
Shell
22
star
18

patroni-packaging

Shell
20
star
19

db_migrator

PLpgSQL
18
star
20

react-database-diagram

A react component to render nice database diagram using storm-react-diagrams
TypeScript
17
star
21

patroni-windows-packaging

Automate installing and launching of Patroni under Windows
Batchfile
15
star
22

pg_timetable_gui

GUI for pg_timetable
Pascal
13
star
23

CYBERTEC-pg-operator

Go
12
star
24

pg_sequence_fixer

Fixing PostgreSQL sequences which got out of sync with the data
PLpgSQL
12
star
25

walbouncer

A proxy server for PostgreSQL replication connections with the capability to filter out user defined subsets of data
C
12
star
26

scripts

Various scripts around PostgreSQL management
Python
10
star
27

generic-plan

generate a generic plan for a parameterized SQL statement
PLpgSQL
10
star
28

pg_remote_exec

Run shell commands in SQL prompt
C
8
star
29

drop_role_helper

Generate SQL to revoke all privileges of a role in the current database
PLpgSQL
7
star
30

poc-plpgsql-analyzer

Proof of concept for tooling to migrate PL/SQL code to PL/pgSQL written in Rust
Rust
7
star
31

PES

Patroni Environment Setup
Pascal
6
star
32

walbouncer-companion

A tool to perform a selective Postgres basebackup
Python
6
star
33

essence

β˜• breaks during database dump extraction? Not on our watch!
Rust
4
star
34

merge_ips

PLpgSQL
3
star
35

today-i-learned

TypeScript
3
star
36

python_template

Template repository for Python command line apps.
Python
3
star
37

.github

Repository to share actions and workflows
3
star
38

CYBERTEC-operator-tutorials

3
star
39

yaim

yaim - yet another ip manager
Go
2
star
40

postgresql-action

:octocat: GitHub Action for PostgreSQL
2
star
41

layman

fuse-overlayfs within Docker for volume mounts.
Shell
2
star
42

debezium2postgres

Application to apply CDC log from Debezium to the destination PostgreSQL
Go
2
star
43

pgbackrest-tde

pgbackrest fork, patched for PostgreSQL-TDE
C
2
star
44

patroni-infoblox-integration

Patroni callbacks for integrating into Infoblox DNS services
Python
2
star
45

CYBERTEC-pg-container

Python
1
star
46

today-i-learned-content

This repository contains all the content for Today I learned @Cybertec-postgresql.
Shell
1
star
47

postgresql

A fork of https://salsa.debian.org/postgresql/postgresql/
1
star