├── .gitignore ├── Makefile ├── README.md ├── column ├── explain-analyze.txt ├── sample-data.sql └── schema.sql ├── docker-compose.yaml ├── pgdata ├── postgresql.conf ├── table ├── explain-analyze.txt ├── sample-data.sql └── schema.sql └── view ├── explain-analyze.txt ├── sample-data.sql └── schema.sql /.gitignore: -------------------------------------------------------------------------------- 1 | .DS_Store 2 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | seed-db: 2 | make run-schema && \ 3 | make insert-sample-data 4 | 5 | destroy-db: 6 | docker-compose down && \ 7 | docker volume rm breakdown_pgdata && \ 8 | rm -f pgdata && touch pgdata 9 | 10 | run-db: 11 | docker-compose up & 12 | 13 | run-schema: 14 | psql -d test -h localhost -W postgres -w -f $(schema)/schema.sql 15 | 16 | insert-sample-data: 17 | psql -d test -h localhost -W postgres -w -f $(schema)/sample-data.sql 18 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Row Level Security Performance 2 | > A collection of Row Level Security-type schemas and performance tests 3 | 4 | ## Installation 5 | You'll need the following things to make this work: 6 | 1. [Docker](https://www.docker.com/get-docker) 7 | 8 | ## Usage 9 | You can do a few things with the `make` scripts built into this repository: 10 | 11 | ### `make run-db` 12 | This runs the DB so that you can run a schema on it. 13 | 14 | ### `make seed-db schema=column|table|view` 15 | This will run the schema and the sample-data query for the specified test. The seed data inserts 100 users and 100,000 items into the database automatically. 16 | 17 | ### `make destroy-db` 18 | This tears down a running stack and drops the database so that you can run `make seed-db` all over again. 19 | 20 | There are a few other commands which compose those documented but they are less interesting. 21 | 22 | ## Purpose 23 | The purpose of this repository is the easily test the performance of access control strategies in PostgreSQL, primarily using Row Level Security. 24 | -------------------------------------------------------------------------------- /column/explain-analyze.txt: -------------------------------------------------------------------------------- 1 | ===================== 2 | No GIN on permissions 3 | ===================== 4 | 5 | Finalize Aggregate (cost=5984.40..5984.41 rows=1 width=8) (actual time=48.524..48.528 rows=1 loops=1) 6 | -> Gather (cost=5984.18..5984.39 rows=2 width=8) (actual time=47.298..48.499 rows=3 loops=1) 7 | Workers Planned: 2 8 | Workers Launched: 2 9 | -> Partial Aggregate (cost=4984.18..4984.19 rows=1 width=8) (actual time=38.167..38.172 rows=1 loops=3) 10 | -> Parallel Seq Scan on items (cost=0.00..4983.09 rows=438 width=0) (actual time=0.449..36.410 rows=339 loops=3) 11 | Filter: (permissions @> ARRAY[(current_setting('jwt.claims.role'::text))::name]) 12 | Rows Removed by Filter: 32994 13 | Planning time: 0.165 ms 14 | Execution time: 51.929 m 15 | 16 | ================== 17 | GIN on permissions 18 | ================== 19 | 20 | Aggregate (cost=2608.51..2608.52 rows=1 width=8) (actual time=12.314..12.317 rows=1 loops=1) 21 | -> Bitmap Heap Scan on items (cost=22.29..2605.19 rows=1327 width=0) (actual time=0.239..6.687 rows=1364 loops=1) 22 | Recheck Cond: (permissions @> ARRAY[(current_setting('jwt.claims.role'::text))::name]) 23 | Heap Blocks: exact=282 24 | -> Bitmap Index Scan on permissions_index (cost=0.00..21.96 rows=1327 width=0) (actual time=0.182..0.182 rows=1364 loops=1) 25 | Index Cond: (permissions @> ARRAY[(current_setting('jwt.claims.role'::text))::name]) 26 | Planning time: 2.763 ms 27 | Execution time: 12.423 ms 28 | -------------------------------------------------------------------------------- /column/sample-data.sql: -------------------------------------------------------------------------------- 1 | create or replace function insert_data(n integer) 2 | returns integer 3 | AS $$ 4 | DECLARE 5 | counter integer := 0; 6 | begin 7 | loop 8 | exit when counter = n; 9 | counter := counter + 1; 10 | insert into items (value) values ('test value ' || counter); 11 | end loop; 12 | return n; 13 | end; 14 | $$ language plpgsql; 15 | 16 | create or replace function insert_users(n integer) 17 | returns integer 18 | as $$ 19 | declare 20 | counter integer := 0; 21 | user_id uuid; 22 | begin 23 | loop 24 | exit when counter = n; 25 | counter := counter + 1; 26 | insert into users (name) values ('user ' || counter) returning id into user_id; 27 | execute 'set local jwt.claims.roles = ''' || user_id || ''''; 28 | perform insert_data(1000); 29 | update items 30 | set acl_read = array_append(acl_read, user_id) 31 | where random() > .99 32 | and not acl_read @> array[user_id]; 33 | end loop; 34 | return n; 35 | end; 36 | $$ language plpgsql; 37 | 38 | create or replace function user_item_stats() 39 | returns setof text 40 | as $$ 41 | declare 42 | user_id uuid; 43 | row record; 44 | begin 45 | select id 46 | from users 47 | where random() > .95 48 | limit 1 into user_id; 49 | execute 'set local role = ''' || user_id || ''''; 50 | execute 'set local jwt.claims.roles = ''' || user_id || ''''; 51 | return query 52 | explain analyze select count(*) 53 | from items; 54 | return; 55 | end 56 | $$ language plpgsql; 57 | 58 | create view permission_stats as 59 | select 60 | min(array_length(acl_read, 1)), 61 | avg(array_length(acl_read, 1)), 62 | max(array_length(acl_read, 1)), 63 | sum(array_length(acl_read, 1)), 64 | ( 65 | select count(*) from items 66 | ) as item_count, 67 | ( 68 | select count(*) from users 69 | ) as user_count 70 | from items; 71 | 72 | select insert_users(100); 73 | -------------------------------------------------------------------------------- /column/schema.sql: -------------------------------------------------------------------------------- 1 | create extension if not exists "postgis"; 2 | create extension if not exists "uuid-ossp"; 3 | 4 | create role application_user; 5 | 6 | create table if not exists users ( 7 | id uuid default uuid_generate_v4() not null primary key, 8 | name text not null 9 | ); 10 | 11 | create table if not exists items ( 12 | id uuid default uuid_generate_v4() not null primary key, 13 | value text, 14 | acl_read uuid[] default array[]::uuid[], 15 | acl_write uuid[] default array[]::uuid[] 16 | ); 17 | 18 | create index read_permissions_index on items using gin(acl_read); 19 | create index write_permissions_index on items using gin(acl_write); 20 | 21 | grant all 22 | on schema public 23 | to application_user; 24 | 25 | grant all 26 | on all tables in schema public 27 | to application_user; 28 | 29 | alter table items 30 | enable row level security; 31 | 32 | create policy item_owner 33 | on items 34 | as permissive 35 | for all 36 | to application_user 37 | using ( 38 | items.acl_read && regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[] 39 | or items.acl_write && regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[] 40 | ) 41 | with check ( 42 | items.acl_write && regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[] 43 | ); 44 | 45 | create or replace function insert_item_permission() 46 | returns trigger 47 | as $$ 48 | begin 49 | new.acl_write = array[ 50 | (regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[])[1] 51 | ]; 52 | return new; 53 | end 54 | $$ language plpgsql; 55 | 56 | create trigger item_permission 57 | before insert 58 | on items 59 | for each row 60 | execute procedure insert_item_permission(); 61 | 62 | -- this is only neccessary if we plan to give SQL access to users 63 | create or replace function create_role() 64 | returns trigger 65 | as $$ 66 | begin 67 | execute 'create role ' || quote_ident( new.id::text ) || ' inherit'; 68 | execute 'grant application_user to ' || quote_ident( new.id::text ); 69 | return new; 70 | end 71 | $$ language plpgsql; 72 | 73 | create trigger insert_user_trigger 74 | after insert 75 | on users 76 | for each row 77 | execute procedure create_role(); 78 | -------------------------------------------------------------------------------- /docker-compose.yaml: -------------------------------------------------------------------------------- 1 | version: "3" 2 | services: 3 | pg: 4 | image: mdillon/postgis:10 5 | container_name: 'breakdown-pg' 6 | command: postgres -c config_file=/etc/postgresql.conf 7 | ports: 8 | - 5432:5432 9 | volumes: 10 | - pgdata:/var/lib/postgresql/data 11 | - ./postgresql.conf:/etc/postgresql.conf 12 | environment: 13 | POSTGRES_DB: 'test' 14 | networks: 15 | - database 16 | volumes: 17 | pgdata: 18 | networks: 19 | database: 20 | driver: bridge 21 | -------------------------------------------------------------------------------- /pgdata: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/cazzer/row-level-security-performance/58a8f141e6c1ee0dda53a711ba96b837e1c33dd3/pgdata -------------------------------------------------------------------------------- /postgresql.conf: -------------------------------------------------------------------------------- 1 | # ----------------------------- 2 | # PostgreSQL configuration file 3 | # ----------------------------- 4 | # 5 | # This file consists of lines of the form: 6 | # 7 | # name = value 8 | # 9 | # (The "=" is optional.) Whitespace may be used. Comments are introduced with 10 | # "#" anywhere on a line. The complete list of parameter names and allowed 11 | # values can be found in the PostgreSQL documentation. 12 | # 13 | # The commented-out settings shown in this file represent the default values. 14 | # Re-commenting a setting is NOT sufficient to revert it to the default value; 15 | # you need to reload the server. 16 | # 17 | # This file is read on server startup and when the server receives a SIGHUP 18 | # signal. If you edit the file on a running system, you have to SIGHUP the 19 | # server for the changes to take effect, run "pg_ctl reload", or execute 20 | # "SELECT pg_reload_conf()". Some parameters, which are marked below, 21 | # require a server shutdown and restart to take effect. 22 | # 23 | # Any parameter can also be given as a command-line option to the server, e.g., 24 | # "postgres -c log_connections=on". Some parameters can be changed at run time 25 | # with the "SET" SQL command. 26 | # 27 | # Memory units: kB = kilobytes Time units: ms = milliseconds 28 | # MB = megabytes s = seconds 29 | # GB = gigabytes min = minutes 30 | # TB = terabytes h = hours 31 | # d = days 32 | 33 | 34 | #------------------------------------------------------------------------------ 35 | # FILE LOCATIONS 36 | #------------------------------------------------------------------------------ 37 | 38 | # The default values of these variables are driven from the -D command-line 39 | # option or PGDATA environment variable, represented here as ConfigDir. 40 | 41 | #data_directory = 'ConfigDir' # use data in another directory 42 | # (change requires restart) 43 | #hba_file = 'ConfigDir/pg_hba.conf' # host-based authentication file 44 | # (change requires restart) 45 | #ident_file = 'ConfigDir/pg_ident.conf' # ident configuration file 46 | # (change requires restart) 47 | 48 | # If external_pid_file is not explicitly set, no extra PID file is written. 49 | #external_pid_file = '' # write an extra PID file 50 | # (change requires restart) 51 | 52 | 53 | #------------------------------------------------------------------------------ 54 | # CONNECTIONS AND AUTHENTICATION 55 | #------------------------------------------------------------------------------ 56 | 57 | # - Connection Settings - 58 | 59 | listen_addresses = '*' 60 | # comma-separated list of addresses; 61 | # defaults to 'localhost'; use '*' for all 62 | # (change requires restart) 63 | #port = 5432 # (change requires restart) 64 | max_connections = 100 # (change requires restart) 65 | #superuser_reserved_connections = 3 # (change requires restart) 66 | #unix_socket_directories = '/var/run/postgresql' # comma-separated list of directories 67 | # (change requires restart) 68 | #unix_socket_group = '' # (change requires restart) 69 | #unix_socket_permissions = 0777 # begin with 0 to use octal notation 70 | # (change requires restart) 71 | #bonjour = off # advertise server via Bonjour 72 | # (change requires restart) 73 | #bonjour_name = '' # defaults to the computer name 74 | # (change requires restart) 75 | 76 | # - Security and Authentication - 77 | 78 | #authentication_timeout = 1min # 1s-600s 79 | #ssl = off 80 | #ssl_ciphers = 'HIGH:MEDIUM:+3DES:!aNULL' # allowed SSL ciphers 81 | #ssl_prefer_server_ciphers = on 82 | #ssl_ecdh_curve = 'prime256v1' 83 | #ssl_dh_params_file = '' 84 | #ssl_cert_file = 'server.crt' 85 | #ssl_key_file = 'server.key' 86 | #ssl_ca_file = '' 87 | #ssl_crl_file = '' 88 | #password_encryption = md5 # md5 or scram-sha-256 89 | #db_user_namespace = off 90 | #row_security = on 91 | 92 | # GSSAPI using Kerberos 93 | #krb_server_keyfile = '' 94 | #krb_caseins_users = off 95 | 96 | # - TCP Keepalives - 97 | # see "man 7 tcp" for details 98 | 99 | #tcp_keepalives_idle = 0 # TCP_KEEPIDLE, in seconds; 100 | # 0 selects the system default 101 | #tcp_keepalives_interval = 0 # TCP_KEEPINTVL, in seconds; 102 | # 0 selects the system default 103 | #tcp_keepalives_count = 0 # TCP_KEEPCNT; 104 | # 0 selects the system default 105 | 106 | 107 | #------------------------------------------------------------------------------ 108 | # RESOURCE USAGE (except WAL) 109 | #------------------------------------------------------------------------------ 110 | 111 | # - Memory - 112 | 113 | shared_buffers = 128MB # min 128kB 114 | # (change requires restart) 115 | #huge_pages = try # on, off, or try 116 | # (change requires restart) 117 | #temp_buffers = 8MB # min 800kB 118 | #max_prepared_transactions = 0 # zero disables the feature 119 | # (change requires restart) 120 | # Caution: it is not advisable to set max_prepared_transactions nonzero unless 121 | # you actively intend to use prepared transactions. 122 | #work_mem = 4MB # min 64kB 123 | #maintenance_work_mem = 64MB # min 1MB 124 | #replacement_sort_tuples = 150000 # limits use of replacement selection sort 125 | #autovacuum_work_mem = -1 # min 1MB, or -1 to use maintenance_work_mem 126 | #max_stack_depth = 2MB # min 100kB 127 | dynamic_shared_memory_type = posix # the default is the first option 128 | # supported by the operating system: 129 | # posix 130 | # sysv 131 | # windows 132 | # mmap 133 | # use none to disable dynamic shared memory 134 | # (change requires restart) 135 | 136 | # - Disk - 137 | 138 | #temp_file_limit = -1 # limits per-process temp file space 139 | # in kB, or -1 for no limit 140 | 141 | # - Kernel Resource Usage - 142 | 143 | #max_files_per_process = 1000 # min 25 144 | # (change requires restart) 145 | #shared_preload_libraries = '' # (change requires restart) 146 | 147 | # - Cost-Based Vacuum Delay - 148 | 149 | #vacuum_cost_delay = 0 # 0-100 milliseconds 150 | #vacuum_cost_page_hit = 1 # 0-10000 credits 151 | #vacuum_cost_page_miss = 10 # 0-10000 credits 152 | #vacuum_cost_page_dirty = 20 # 0-10000 credits 153 | #vacuum_cost_limit = 200 # 1-10000 credits 154 | 155 | # - Background Writer - 156 | 157 | #bgwriter_delay = 200ms # 10-10000ms between rounds 158 | #bgwriter_lru_maxpages = 100 # 0-1000 max buffers written/round 159 | #bgwriter_lru_multiplier = 2.0 # 0-10.0 multiplier on buffers scanned/round 160 | #bgwriter_flush_after = 512kB # measured in pages, 0 disables 161 | 162 | # - Asynchronous Behavior - 163 | 164 | #effective_io_concurrency = 1 # 1-1000; 0 disables prefetching 165 | #max_worker_processes = 8 # (change requires restart) 166 | #max_parallel_workers_per_gather = 2 # taken from max_parallel_workers 167 | #max_parallel_workers = 8 # maximum number of max_worker_processes that 168 | # can be used in parallel queries 169 | #old_snapshot_threshold = -1 # 1min-60d; -1 disables; 0 is immediate 170 | # (change requires restart) 171 | #backend_flush_after = 0 # measured in pages, 0 disables 172 | 173 | 174 | #------------------------------------------------------------------------------ 175 | # WRITE AHEAD LOG 176 | #------------------------------------------------------------------------------ 177 | 178 | # - Settings - 179 | 180 | wal_level = logical # minimal, replica, or logical 181 | # (change requires restart) 182 | #fsync = on # flush data to disk for crash safety 183 | # (turning this off can cause 184 | # unrecoverable data corruption) 185 | #synchronous_commit = on # synchronization level; 186 | # off, local, remote_write, remote_apply, or on 187 | #wal_sync_method = fsync # the default is the first option 188 | # supported by the operating system: 189 | # open_datasync 190 | # fdatasync (default on Linux) 191 | # fsync 192 | # fsync_writethrough 193 | # open_sync 194 | #full_page_writes = on # recover from partial page writes 195 | #wal_compression = off # enable compression of full-page writes 196 | #wal_log_hints = off # also do full page writes of non-critical updates 197 | # (change requires restart) 198 | #wal_buffers = -1 # min 32kB, -1 sets based on shared_buffers 199 | # (change requires restart) 200 | #wal_writer_delay = 200ms # 1-10000 milliseconds 201 | #wal_writer_flush_after = 1MB # measured in pages, 0 disables 202 | 203 | #commit_delay = 0 # range 0-100000, in microseconds 204 | #commit_siblings = 5 # range 1-1000 205 | 206 | # - Checkpoints - 207 | 208 | #checkpoint_timeout = 5min # range 30s-1d 209 | #max_wal_size = 1GB 210 | #min_wal_size = 80MB 211 | #checkpoint_completion_target = 0.5 # checkpoint target duration, 0.0 - 1.0 212 | #checkpoint_flush_after = 256kB # measured in pages, 0 disables 213 | #checkpoint_warning = 30s # 0 disables 214 | 215 | # - Archiving - 216 | 217 | #archive_mode = off # enables archiving; off, on, or always 218 | # (change requires restart) 219 | #archive_command = '' # command to use to archive a logfile segment 220 | # placeholders: %p = path of file to archive 221 | # %f = file name only 222 | # e.g. 'test ! -f /mnt/server/archivedir/%f && cp %p /mnt/server/archivedir/%f' 223 | #archive_timeout = 0 # force a logfile segment switch after this 224 | # number of seconds; 0 disables 225 | 226 | 227 | #------------------------------------------------------------------------------ 228 | # REPLICATION 229 | #------------------------------------------------------------------------------ 230 | 231 | # - Sending Server(s) - 232 | 233 | # Set these on the master and on any standby that will send replication data. 234 | 235 | #max_wal_senders = 10 # max number of walsender processes 236 | # (change requires restart) 237 | #wal_keep_segments = 0 # in logfile segments, 16MB each; 0 disables 238 | #wal_sender_timeout = 60s # in milliseconds; 0 disables 239 | 240 | max_replication_slots = 10 # max number of replication slots 241 | # (change requires restart) 242 | #track_commit_timestamp = off # collect timestamp of transaction commit 243 | # (change requires restart) 244 | 245 | # - Master Server - 246 | 247 | # These settings are ignored on a standby server. 248 | 249 | #synchronous_standby_names = '' # standby servers that provide sync rep 250 | # method to choose sync standbys, number of sync standbys, 251 | # and comma-separated list of application_name 252 | # from standby(s); '*' = all 253 | #vacuum_defer_cleanup_age = 0 # number of xacts by which cleanup is delayed 254 | 255 | # - Standby Servers - 256 | 257 | # These settings are ignored on a master server. 258 | 259 | #hot_standby = on # "off" disallows queries during recovery 260 | # (change requires restart) 261 | #max_standby_archive_delay = 30s # max delay before canceling queries 262 | # when reading WAL from archive; 263 | # -1 allows indefinite delay 264 | #max_standby_streaming_delay = 30s # max delay before canceling queries 265 | # when reading streaming WAL; 266 | # -1 allows indefinite delay 267 | #wal_receiver_status_interval = 10s # send replies at least this often 268 | # 0 disables 269 | #hot_standby_feedback = off # send info from standby to prevent 270 | # query conflicts 271 | #wal_receiver_timeout = 60s # time that receiver waits for 272 | # communication from master 273 | # in milliseconds; 0 disables 274 | #wal_retrieve_retry_interval = 5s # time to wait before retrying to 275 | # retrieve WAL after a failed attempt 276 | 277 | # - Subscribers - 278 | 279 | # These settings are ignored on a publisher. 280 | 281 | #max_logical_replication_workers = 4 # taken from max_worker_processes 282 | # (change requires restart) 283 | #max_sync_workers_per_subscription = 2 # taken from max_logical_replication_workers 284 | 285 | 286 | #------------------------------------------------------------------------------ 287 | # QUERY TUNING 288 | #------------------------------------------------------------------------------ 289 | 290 | # - Planner Method Configuration - 291 | 292 | #enable_bitmapscan = on 293 | #enable_hashagg = on 294 | #enable_hashjoin = on 295 | #enable_indexscan = on 296 | #enable_indexonlyscan = on 297 | #enable_material = on 298 | #enable_mergejoin = on 299 | #enable_nestloop = on 300 | #enable_seqscan = on 301 | #enable_sort = on 302 | #enable_tidscan = on 303 | 304 | # - Planner Cost Constants - 305 | 306 | #seq_page_cost = 1.0 # measured on an arbitrary scale 307 | #random_page_cost = 4.0 # same scale as above 308 | #cpu_tuple_cost = 0.01 # same scale as above 309 | #cpu_index_tuple_cost = 0.005 # same scale as above 310 | #cpu_operator_cost = 0.0025 # same scale as above 311 | #parallel_tuple_cost = 0.1 # same scale as above 312 | #parallel_setup_cost = 1000.0 # same scale as above 313 | #min_parallel_table_scan_size = 8MB 314 | #min_parallel_index_scan_size = 512kB 315 | #effective_cache_size = 4GB 316 | 317 | # - Genetic Query Optimizer - 318 | 319 | #geqo = on 320 | #geqo_threshold = 12 321 | #geqo_effort = 5 # range 1-10 322 | #geqo_pool_size = 0 # selects default based on effort 323 | #geqo_generations = 0 # selects default based on effort 324 | #geqo_selection_bias = 2.0 # range 1.5-2.0 325 | #geqo_seed = 0.0 # range 0.0-1.0 326 | 327 | # - Other Planner Options - 328 | 329 | #default_statistics_target = 100 # range 1-10000 330 | #constraint_exclusion = partition # on, off, or partition 331 | #cursor_tuple_fraction = 0.1 # range 0.0-1.0 332 | #from_collapse_limit = 8 333 | #join_collapse_limit = 8 # 1 disables collapsing of explicit 334 | # JOIN clauses 335 | #force_parallel_mode = off 336 | 337 | 338 | #------------------------------------------------------------------------------ 339 | # ERROR REPORTING AND LOGGING 340 | #------------------------------------------------------------------------------ 341 | 342 | # - Where to Log - 343 | 344 | #log_destination = 'stderr' # Valid values are combinations of 345 | # stderr, csvlog, syslog, and eventlog, 346 | # depending on platform. csvlog 347 | # requires logging_collector to be on. 348 | 349 | # This is used when logging to stderr: 350 | #logging_collector = off # Enable capturing of stderr and csvlog 351 | # into log files. Required to be on for 352 | # csvlogs. 353 | # (change requires restart) 354 | 355 | # These are only used if logging_collector is on: 356 | #log_directory = 'log' # directory where log files are written, 357 | # can be absolute or relative to PGDATA 358 | #log_filename = 'postgresql-%Y-%m-%d_%H%M%S.log' # log file name pattern, 359 | # can include strftime() escapes 360 | #log_file_mode = 0600 # creation mode for log files, 361 | # begin with 0 to use octal notation 362 | #log_truncate_on_rotation = off # If on, an existing log file with the 363 | # same name as the new log file will be 364 | # truncated rather than appended to. 365 | # But such truncation only occurs on 366 | # time-driven rotation, not on restarts 367 | # or size-driven rotation. Default is 368 | # off, meaning append to existing files 369 | # in all cases. 370 | #log_rotation_age = 1d # Automatic rotation of logfiles will 371 | # happen after that time. 0 disables. 372 | #log_rotation_size = 10MB # Automatic rotation of logfiles will 373 | # happen after that much log output. 374 | # 0 disables. 375 | 376 | # These are relevant when logging to syslog: 377 | #syslog_facility = 'LOCAL0' 378 | #syslog_ident = 'postgres' 379 | #syslog_sequence_numbers = on 380 | #syslog_split_messages = on 381 | 382 | # This is only relevant when logging to eventlog (win32): 383 | # (change requires restart) 384 | #event_source = 'PostgreSQL' 385 | 386 | # - When to Log - 387 | 388 | #client_min_messages = notice # values in order of decreasing detail: 389 | # debug5 390 | # debug4 391 | # debug3 392 | # debug2 393 | # debug1 394 | # log 395 | # notice 396 | # warning 397 | # error 398 | 399 | #log_min_messages = warning # values in order of decreasing detail: 400 | # debug5 401 | # debug4 402 | # debug3 403 | # debug2 404 | # debug1 405 | # info 406 | # notice 407 | # warning 408 | # error 409 | # log 410 | # fatal 411 | # panic 412 | 413 | #log_min_error_statement = error # values in order of decreasing detail: 414 | # debug5 415 | # debug4 416 | # debug3 417 | # debug2 418 | # debug1 419 | # info 420 | # notice 421 | # warning 422 | # error 423 | # log 424 | # fatal 425 | # panic (effectively off) 426 | 427 | #log_min_duration_statement = -1 # -1 is disabled, 0 logs all statements 428 | # and their durations, > 0 logs only 429 | # statements running at least this number 430 | # of milliseconds 431 | 432 | 433 | # - What to Log - 434 | 435 | #debug_print_parse = off 436 | #debug_print_rewritten = off 437 | #debug_print_plan = off 438 | #debug_pretty_print = on 439 | #log_checkpoints = off 440 | #log_connections = off 441 | #log_disconnections = off 442 | #log_duration = off 443 | #log_error_verbosity = default # terse, default, or verbose messages 444 | #log_hostname = off 445 | #log_line_prefix = '%m [%p] ' # special values: 446 | # %a = application name 447 | # %u = user name 448 | # %d = database name 449 | # %r = remote host and port 450 | # %h = remote host 451 | # %p = process ID 452 | # %t = timestamp without milliseconds 453 | # %m = timestamp with milliseconds 454 | # %n = timestamp with milliseconds (as a Unix epoch) 455 | # %i = command tag 456 | # %e = SQL state 457 | # %c = session ID 458 | # %l = session line number 459 | # %s = session start timestamp 460 | # %v = virtual transaction ID 461 | # %x = transaction ID (0 if none) 462 | # %q = stop here in non-session 463 | # processes 464 | # %% = '%' 465 | # e.g. '<%u%%%d> ' 466 | #log_lock_waits = off # log lock waits >= deadlock_timeout 467 | #log_statement = 'all' # none, ddl, mod, all 468 | #log_replication_commands = off 469 | #log_temp_files = -1 # log temporary files equal or larger 470 | # than the specified size in kilobytes; 471 | # -1 disables, 0 logs all temp filesi 472 | log_timezone = 'UTC' 473 | 474 | 475 | # - Process Title - 476 | 477 | #cluster_name = '' # added to process titles if nonempty 478 | # (change requires restart) 479 | #update_process_title = on 480 | 481 | 482 | #------------------------------------------------------------------------------ 483 | # RUNTIME STATISTICS 484 | #------------------------------------------------------------------------------ 485 | 486 | # - Query/Index Statistics Collector - 487 | 488 | #track_activities = on 489 | #track_counts = on 490 | #track_io_timing = off 491 | #track_functions = none # none, pl, all 492 | #track_activity_query_size = 1024 # (change requires restart) 493 | #stats_temp_directory = 'pg_stat_tmp' 494 | 495 | 496 | # - Statistics Monitoring - 497 | 498 | #log_parser_stats = off 499 | #log_planner_stats = off 500 | #log_executor_stats = off 501 | #log_statement_stats = off 502 | 503 | 504 | #------------------------------------------------------------------------------ 505 | # AUTOVACUUM PARAMETERS 506 | #------------------------------------------------------------------------------ 507 | 508 | #autovacuum = on # Enable autovacuum subprocess? 'on' 509 | # requires track_counts to also be on. 510 | #log_autovacuum_min_duration = -1 # -1 disables, 0 logs all actions and 511 | # their durations, > 0 logs only 512 | # actions running at least this number 513 | # of milliseconds. 514 | #autovacuum_max_workers = 3 # max number of autovacuum subprocesses 515 | # (change requires restart) 516 | #autovacuum_naptime = 1min # time between autovacuum runs 517 | #autovacuum_vacuum_threshold = 50 # min number of row updates before 518 | # vacuum 519 | #autovacuum_analyze_threshold = 50 # min number of row updates before 520 | # analyze 521 | #autovacuum_vacuum_scale_factor = 0.2 # fraction of table size before vacuum 522 | #autovacuum_analyze_scale_factor = 0.1 # fraction of table size before analyze 523 | #autovacuum_freeze_max_age = 200000000 # maximum XID age before forced vacuum 524 | # (change requires restart) 525 | #autovacuum_multixact_freeze_max_age = 400000000 # maximum multixact age 526 | # before forced vacuum 527 | # (change requires restart) 528 | #autovacuum_vacuum_cost_delay = 20ms # default vacuum cost delay for 529 | # autovacuum, in milliseconds; 530 | # -1 means use vacuum_cost_delay 531 | #autovacuum_vacuum_cost_limit = -1 # default vacuum cost limit for 532 | # autovacuum, -1 means use 533 | # vacuum_cost_limit 534 | 535 | 536 | #------------------------------------------------------------------------------ 537 | # CLIENT CONNECTION DEFAULTS 538 | #------------------------------------------------------------------------------ 539 | 540 | # - Statement Behavior - 541 | 542 | #search_path = '"$user", public' # schema names 543 | #default_tablespace = '' # a tablespace name, '' uses the default 544 | #temp_tablespaces = '' # a list of tablespace names, '' uses 545 | # only default tablespace 546 | #check_function_bodies = on 547 | #default_transaction_isolation = 'read committed' 548 | #default_transaction_read_only = off 549 | #default_transaction_deferrable = off 550 | #session_replication_role = 'origin' 551 | #statement_timeout = 0 # in milliseconds, 0 is disabled 552 | #lock_timeout = 0 # in milliseconds, 0 is disabled 553 | #idle_in_transaction_session_timeout = 0 # in milliseconds, 0 is disabled 554 | #vacuum_freeze_min_age = 50000000 555 | #vacuum_freeze_table_age = 150000000 556 | #vacuum_multixact_freeze_min_age = 5000000 557 | #vacuum_multixact_freeze_table_age = 150000000 558 | #bytea_output = 'hex' # hex, escape 559 | #xmlbinary = 'base64' 560 | #xmloption = 'content' 561 | #gin_fuzzy_search_limit = 0 562 | #gin_pending_list_limit = 4MB 563 | 564 | # - Locale and Formatting - 565 | 566 | datestyle = 'iso, mdy' 567 | #intervalstyle = 'postgres' 568 | timezone = 'UTC' 569 | #timezone_abbreviations = 'Default' # Select the set of available time zone 570 | # abbreviations. Currently, there are 571 | # Default 572 | # Australia (historical usage) 573 | # India 574 | # You can create your own file in 575 | # share/timezonesets/. 576 | #extra_float_digits = 0 # min -15, max 3 577 | #client_encoding = sql_ascii # actually, defaults to database 578 | # encoding 579 | 580 | # These settings are initialized by initdb, but they can be changed. 581 | lc_messages = 'en_US.utf8' # locale for system error message 582 | # strings 583 | lc_monetary = 'en_US.utf8' # locale for monetary formatting 584 | lc_numeric = 'en_US.utf8' # locale for number formatting 585 | lc_time = 'en_US.utf8' # locale for time formatting 586 | 587 | # default configuration for text search 588 | default_text_search_config = 'pg_catalog.english' 589 | 590 | # - Other Defaults - 591 | 592 | #dynamic_library_path = '$libdir' 593 | #local_preload_libraries = '' 594 | #session_preload_libraries = '' 595 | 596 | 597 | #------------------------------------------------------------------------------ 598 | # LOCK MANAGEMENT 599 | #------------------------------------------------------------------------------ 600 | 601 | #deadlock_timeout = 1s 602 | #max_locks_per_transaction = 64 # min 10 603 | # (change requires restart) 604 | #max_pred_locks_per_transaction = 64 # min 10 605 | # (change requires restart) 606 | #max_pred_locks_per_relation = -2 # negative values mean 607 | # (max_pred_locks_per_transaction 608 | # / -max_pred_locks_per_relation) - 1 609 | #max_pred_locks_per_page = 2 # min 0 610 | 611 | 612 | #------------------------------------------------------------------------------ 613 | # VERSION/PLATFORM COMPATIBILITY 614 | #------------------------------------------------------------------------------ 615 | 616 | # - Previous PostgreSQL Versions - 617 | 618 | #array_nulls = on 619 | #backslash_quote = safe_encoding # on, off, or safe_encoding 620 | #default_with_oids = off 621 | #escape_string_warning = on 622 | #lo_compat_privileges = off 623 | #operator_precedence_warning = off 624 | #quote_all_identifiers = off 625 | #standard_conforming_strings = on 626 | #synchronize_seqscans = on 627 | 628 | # - Other Platforms and Clients - 629 | 630 | #transform_null_equals = off 631 | 632 | 633 | #------------------------------------------------------------------------------ 634 | # ERROR HANDLING 635 | #------------------------------------------------------------------------------ 636 | 637 | #exit_on_error = off # terminate session on any error? 638 | #restart_after_crash = on # reinitialize after backend crash? 639 | 640 | 641 | #------------------------------------------------------------------------------ 642 | # CONFIG FILE INCLUDES 643 | #------------------------------------------------------------------------------ 644 | 645 | # These options allow settings to be loaded from files other than the 646 | # default postgresql.conf. 647 | 648 | #include_dir = 'conf.d' # include files ending in '.conf' from 649 | # directory 'conf.d' 650 | #include_if_exists = 'exists.conf' # include file only if it exists 651 | #include = 'special.conf' # include file 652 | 653 | 654 | #------------------------------------------------------------------------------ 655 | # CUSTOMIZED OPTIONS 656 | #------------------------------------------------------------------------------ 657 | 658 | # Add settings for extensions here 659 | -------------------------------------------------------------------------------- /table/explain-analyze.txt: -------------------------------------------------------------------------------- 1 | Aggregate (cost=3121681.50..3121681.51 rows=1 width=8) (actual time=28.917..28.922 rows=1 loops=1) 2 | -> Seq Scan on items (cost=0.00..3121669.00 rows=5000 width=0) (actual time=15.867..23.448 rows=1046 loops=1) 3 | Filter: (alternatives: SubPlan 1 or hashed SubPlan 2) 4 | Rows Removed by Filter: 8954 5 | SubPlan 1 6 | -> Seq Scan on user_items (cost=0.00..312.15 rows=1 width=0) (never executed) 7 | Filter: ((item_id = items.id) AND (user_id = (current_setting('jwt.claims.role'::text))::uuid)) 8 | SubPlan 2 9 | -> Seq Scan on user_items user_items_1 (cost=0.00..286.02 rows=1046 width=16) (actual time=2.370..10.693 rows=1046 loops=1) 10 | Filter: (user_id = (current_setting('jwt.claims.role'::text))::uuid) 11 | Rows Removed by Filter: 9405 12 | Planning time: 0.181 ms 13 | Execution time: 28.987 ms 14 | -------------------------------------------------------------------------------- /table/sample-data.sql: -------------------------------------------------------------------------------- 1 | create or replace function insert_data(n integer) 2 | returns integer 3 | AS $$ 4 | DECLARE 5 | counter INTEGER := 0; 6 | BEGIN 7 | LOOP 8 | EXIT WHEN counter = n; 9 | counter := counter + 1; 10 | insert into items (value) values ('test value ' || counter); 11 | end loop; 12 | return n; 13 | end; 14 | $$ LANGUAGE plpgsql; 15 | 16 | create or replace function insert_users(n integer) 17 | returns integer 18 | AS $$ 19 | DECLARE 20 | counter INTEGER := 0; 21 | user_id uuid; 22 | BEGIN 23 | LOOP 24 | EXIT WHEN counter = n; 25 | counter := counter + 1; 26 | insert into users_and_groups (name) values ('user ' || counter) returning id into user_id; 27 | execute 'set local jwt.claims.roles = ''' || user_id || ''''; 28 | perform insert_data(1000); 29 | execute 'insert into permissions (item_id, user_or_group_id) 30 | select 31 | items.id as item_id, 32 | ''' || user_id || ''' 33 | from items 34 | left outer join permissions on items.id = item_id and user_or_group_id = ''' || user_id || ''' 35 | where user_or_group_id is null 36 | and random() > .99'; 37 | end loop; 38 | return n; 39 | end; 40 | $$ LANGUAGE plpgsql; 41 | 42 | select insert_users(100); 43 | 44 | create or replace function user_item_stats() 45 | returns setof text 46 | as $$ 47 | declare 48 | user_id uuid; 49 | row record; 50 | begin 51 | select id 52 | from users_and_groups 53 | where random() > .95 54 | limit 1 into user_id; 55 | execute 'set local role = ''' || user_id || ''''; 56 | execute 'set local jwt.claims.roles = ''' || user_id || ''''; 57 | return query 58 | explain analyze select count(*) 59 | from items; 60 | return; 61 | end 62 | $$ language plpgsql; 63 | 64 | create view permission_stats as 65 | select 66 | min(count), 67 | avg(count), 68 | max(count), 69 | sum(count), 70 | ( 71 | select count(*) from items 72 | ) as item_count, 73 | ( 74 | select count(*) from users_and_groups 75 | ) as user_count 76 | from ( 77 | select 78 | count(user_or_group_id) 79 | from permissions 80 | group by item_id 81 | ) permission_counts; 82 | -------------------------------------------------------------------------------- /table/schema.sql: -------------------------------------------------------------------------------- 1 | create extension if not exists "postgis"; 2 | create extension if not exists "uuid-ossp"; 3 | 4 | create role application_user; 5 | 6 | create table if not exists users_and_groups ( 7 | id uuid default uuid_generate_v4() not null primary key, 8 | name text not null 9 | ); 10 | 11 | create table if not exists items ( 12 | id uuid default uuid_generate_v4() not null primary key, 13 | value text, 14 | public boolean default false 15 | ); 16 | 17 | create type permission_role as enum ( 18 | 'read', 19 | 'write' 20 | ); 21 | 22 | create table if not exists permissions ( 23 | item_id uuid references items(id), 24 | user_or_group_id uuid references users_and_groups(id), 25 | role permission_role default 'read' not null 26 | ); 27 | 28 | create index on permissions(item_id); 29 | create index on permissions(user_or_group_id); 30 | 31 | create unique index permissions_index ON permissions (item_id, user_or_group_id); 32 | 33 | grant all 34 | on schema public 35 | to application_user; 36 | 37 | grant all 38 | on all tables in schema public 39 | to application_user; 40 | 41 | alter table items 42 | enable row level security; 43 | 44 | create policy item_owner 45 | on items 46 | as permissive 47 | for all 48 | to application_user 49 | using ( 50 | items.public = true 51 | or exists( 52 | select item_id 53 | from permissions 54 | where ( 55 | permissions.user_or_group_id = 56 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]) 57 | and permissions.item_id = items.id 58 | ) 59 | ) 60 | ) 61 | with check (exists( 62 | select item_id 63 | from permissions 64 | where ( 65 | permissions.user_or_group_id = 66 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]) 67 | and permissions.item_id = items.id 68 | and permissions.role = 'write' 69 | ) 70 | )); 71 | 72 | create policy new_item 73 | on items 74 | as permissive 75 | for insert 76 | to application_user 77 | with check (true); 78 | 79 | create policy permission_owner 80 | on permissions 81 | for all 82 | to application_user 83 | using ( 84 | permissions.user_or_group_id = 85 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]) 86 | ) 87 | with check ( 88 | permissions.user_or_group_id = 89 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]) 90 | and permissions.role = 'write' 91 | ); 92 | 93 | create or replace function insert_permission() 94 | returns trigger 95 | as $$ 96 | begin 97 | insert into permissions (item_id, user_or_group_id, role) values ( 98 | new.id, 99 | (regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[])[1], 100 | 'write' 101 | ); 102 | return new; 103 | end 104 | $$ language plpgsql; 105 | 106 | create trigger insert_permission_trigger 107 | after insert 108 | on items 109 | for each row 110 | execute procedure insert_permission(); 111 | 112 | -- this is only neccessary if we plan to give SQL access to users 113 | create or replace function create_role() 114 | returns trigger 115 | as $$ 116 | begin 117 | execute 'create role ' || quote_ident( new.id::text ) || ' inherit'; 118 | execute 'grant application_user to ' || quote_ident( new.id::text ); 119 | return new; 120 | end 121 | $$ language plpgsql; 122 | 123 | create trigger insert_user_trigger 124 | after insert 125 | on users_and_groups 126 | for each row 127 | execute procedure create_role(); 128 | -------------------------------------------------------------------------------- /view/explain-analyze.txt: -------------------------------------------------------------------------------- 1 | Aggregate (cost=7423.76..7423.77 rows=1 width=8) (actual time=71.992..72.045 rows=1 loops=1) 2 | -> Gather (cost=1000.42..7406.83 rows=1354 width=73) (actual time=13.838..65.803 rows=1330 loops=1) 3 | Workers Planned: 1 4 | Workers Launched: 1 5 | -> Nested Loop (cost=0.42..6271.43 rows=796 width=73) (actual time=11.091..59.657 rows=665 loops=2) 6 | -> Parallel Seq Scan on user_items (cost=0.00..2856.40 rows=796 width=16) (actual time=11.021..44.010 rows=665 loops=2) 7 | Filter: (user_id = (current_setting('jwt.claims.role'::text))::uuid) 8 | Rows Removed by Filter: 74024 9 | -> Index Only Scan using items_pkey on items (cost=0.42..4.29 rows=1 width=16) (actual time=0.009..0.009 rows=1 loops=1330) 10 | Index Cond: (id = user_items.item_id) 11 | Heap Fetches: 498 12 | Planning time: 0.541 ms 13 | Execution time: 74.874 ms 14 | -------------------------------------------------------------------------------- /view/sample-data.sql: -------------------------------------------------------------------------------- 1 | create or replace function insert_data(n integer) 2 | returns integer 3 | AS $$ 4 | DECLARE 5 | counter INTEGER := 0; 6 | BEGIN 7 | LOOP 8 | EXIT WHEN counter = n; 9 | counter := counter + 1; 10 | insert into items (value) values ('test value ' || counter); 11 | end loop; 12 | return n; 13 | end; 14 | $$ LANGUAGE plpgsql; 15 | 16 | create or replace function insert_users(n integer) 17 | returns integer 18 | AS $$ 19 | DECLARE 20 | counter INTEGER := 0; 21 | user_id uuid; 22 | BEGIN 23 | LOOP 24 | EXIT WHEN counter = n; 25 | counter := counter + 1; 26 | insert into users_and_groups (name) values ('user ' || counter) returning id into user_id; 27 | execute 'set local jwt.claims.roles = ''' || user_id || ''''; 28 | perform insert_data(1000); 29 | execute 'insert into permissions (item_id, user_or_group_id) 30 | select 31 | items.id as item_id, 32 | ''' || user_id || ''' 33 | from items 34 | left outer join permissions on items.id = item_id and user_or_group_id = ''' || user_id || ''' 35 | where user_or_group_id is null 36 | and random() > .99'; 37 | end loop; 38 | return n; 39 | end; 40 | $$ LANGUAGE plpgsql; 41 | 42 | select insert_users(100); 43 | 44 | create or replace function user_item_stats() 45 | returns setof text 46 | as $$ 47 | declare 48 | user_id uuid; 49 | row record; 50 | begin 51 | select id 52 | from users_and_groups 53 | where random() > .95 54 | limit 1 into user_id; 55 | execute 'set local role = ''' || user_id || ''''; 56 | execute 'set local jwt.claims.roles = ''' || user_id || ''''; 57 | return query 58 | explain analyze select count(*) 59 | from items_view; 60 | return; 61 | end 62 | $$ language plpgsql; 63 | 64 | create view permission_stats as 65 | select 66 | min(count), 67 | avg(count), 68 | max(count), 69 | sum(count), 70 | ( 71 | select count(*) from items 72 | ) as item_count, 73 | ( 74 | select count(*) from users_and_groups 75 | ) as user_count 76 | from ( 77 | select 78 | count(user_or_group_id) 79 | from permissions 80 | group by item_id 81 | ) permission_counts; 82 | -------------------------------------------------------------------------------- /view/schema.sql: -------------------------------------------------------------------------------- 1 | create extension if not exists "postgis"; 2 | create extension if not exists "uuid-ossp"; 3 | 4 | create role application_user; 5 | 6 | create table if not exists users_and_groups ( 7 | id uuid default uuid_generate_v4() not null primary key, 8 | name text not null 9 | ); 10 | 11 | create table if not exists items ( 12 | id uuid default uuid_generate_v4() not null primary key, 13 | value text 14 | ); 15 | 16 | create type permission_role as enum ( 17 | 'read', 18 | 'write' 19 | ); 20 | 21 | create table if not exists permissions ( 22 | item_id uuid references items(id), 23 | user_or_group_id uuid references users_and_groups(id), 24 | role permission_role default 'read' not null 25 | ); 26 | 27 | create index on permissions(item_id); 28 | create index on permissions(user_or_group_id); 29 | 30 | create view items_view 31 | with (security_barrier) 32 | as 33 | select items.* 34 | from permissions 35 | join items 36 | on item_id = items.id 37 | and user_or_group_id = 38 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]); 39 | 40 | grant all 41 | on schema public 42 | to application_user; 43 | 44 | grant all 45 | on all tables in schema public 46 | to application_user; 47 | 48 | create policy permission_owner 49 | on permissions 50 | for all 51 | to application_user 52 | using ( 53 | permissions.user_or_group_id = 54 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]) 55 | ) 56 | with check ( 57 | permissions.user_or_group_id = 58 | any(regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[]) 59 | and permissions.role = 'write' 60 | ); 61 | 62 | create or replace function insert_permission() 63 | returns trigger 64 | as $$ 65 | begin 66 | insert into permissions (item_id, user_or_group_id, role) values ( 67 | new.id, 68 | (regexp_split_to_array(current_setting('jwt.claims.roles'), ',')::uuid[])[1], 69 | 'write' 70 | ); 71 | return new; 72 | end 73 | $$ language plpgsql; 74 | 75 | create trigger insert_permission_trigger 76 | after insert 77 | on items 78 | for each row 79 | execute procedure insert_permission(); 80 | 81 | create or replace function create_role() 82 | returns trigger 83 | as $$ 84 | begin 85 | execute 'create role ' || quote_ident( new.id::text ) || ' inherit'; 86 | execute 'grant application_user to ' || quote_ident( new.id::text ); 87 | return new; 88 | end 89 | $$ language plpgsql; 90 | 91 | create trigger insert_user_trigger 92 | after insert 93 | on users_and_groups 94 | for each row 95 | execute procedure create_role(); 96 | --------------------------------------------------------------------------------