]> Git — Sourcephile - sourcephile-nix.git/blob - hosts/mermet/postgresql.nix
mermet: postgresql: tweak settings
[sourcephile-nix.git] / hosts / mermet / postgresql.nix
1 { pkgs, config, host, ... }:
2 let
3 inherit (config.services) postgresql;
4 in
5 {
6 /*
7 networking.nftables.ruleset = ''
8 table inet filter {
9 chain input-net {
10 tcp dport postgresql counter accept comment "PostgreSQL"
11 }
12 }
13 '';
14 users.groups.acme.members = [ users."postgres".name ];
15 security.acme.certs."${domain}" = {
16 postRun = "systemctl reload postgresql";
17 };
18 systemd.services.postgresql = {
19 wants = [ "acme-selfsigned-${domain}.service" "acme-${domain}.service"];
20 after = [ "acme-selfsigned-${domain}.service" ];
21 };
22 */
23 services.postgresql = {
24 enable = true;
25 package = pkgs.postgresql_12;
26 enableTCPIP = false;
27 # zfs set recordsize=16k
28 # zfs set sync=disabled
29 # zfs set logbias=latency
30 # zfs set primarycache=all
31 # zfs set redundant_metadata=most
32 # DOC: https://wiki.postgresql.org/wiki/Tuning_Your_PostgreSQL_Server
33 settings = {
34 log_connections = true;
35 log_disconnections = true;
36 log_hostname = false;
37 max_locks_per_transaction = 1024;
38 password_encryption = "scram-sha-256"; # requires postfix >= 11
39 # Synchronous commit doesn't introduce the risk of corruption, which is really bad,
40 # just some risk of data loss.
41 unix_socket_permissions = "0770";
42
43 # ZFS is Copy on Write (CoW). As a result, it’s not possible
44 # to have a torn page because a page can’t be partially written
45 # without reverting to the previous copy.
46 # https://vadosware.io/post/everything-ive-seen-on-optimizing-postgres-on-zfs-on-linux/#setting-full_page_writesoff
47 full_page_writes = false;
48 # Avoid zero-filling of new files used for Postgres’s Write Ahead Log.
49 # The reasoning here is that since ZFS overwrites these anyway,
50 # you might as well get yourself a new inode.
51 wal_init_zero = false;
52 wal_recycle = false;
53
54 max_connections = 50;
55 # The proper size for the POSTGRESQL shared buffer cache is the largest
56 # useful size that does not adversely affect other activity.
57 # Ideally we should limit ZFS's ARC's max size
58 # to a percentage of physical memory
59 # minus the shared_buffer cache for PostgreSQL
60 # minus the kernel's memory overhead.
61 shared_buffers = "512MB";
62 # Used by the optimizer to estimate the size of the kernel's disk buffer cache.
63 effective_cache_size = "1536MB";
64 # Setting a large value helps in tasks like
65 # VACUUM, RESTORE, CREATE INDEX, ADD FOREIGN KEY and ALTER TABLE.
66 maintenance_work_mem = "128MB";
67 # Bigger value for wal_buffers in case of lot of concurrent connection gives better performance.
68 wal_buffers = "16MB";
69 min_wal_size = "1GB";
70 max_wal_size = "4GB";
71 default_statistics_target = 100;
72 random_page_cost = "1.1";
73 effective_io_concurrency = 200;
74 work_mem = "5242kB";
75 huge_pages = false;
76 max_worker_processes = host.CPUs;
77 max_parallel_workers_per_gather = host.CPUs / 2;
78 max_parallel_workers = host.CPUs;
79 max_parallel_maintenance_workers = host.CPUs / 2;
80 };
81 # If one record is chosen and the auth fails,
82 # subsequent records are not considered.
83 authentication = ''
84 # CONNECTION DATABASE USER AUTH OPTIONS
85 local all postgres peer map=admin
86 local samerole all peer map=user
87 #local all backup peer
88 '';
89 identMap = ''
90 # MAPNAME SYSTEM-USERNAME PG-USERNAME
91 admin postgres postgres
92 admin root postgres
93 # Commented to prefer explicit auth
94 # to handle revocation without droping the user yet
95 #user /^(.*)$ \1
96 '';
97 };
98 services.sanoid.datasets = {
99 "rpool/var/lib/postgresql" = {
100 use_template = [ "snap" ];
101 daily = 31;
102 hourly = 24;
103 recursive = true;
104 };
105 };
106 systemd.services.postgresql = {
107 # DOC: https://wiki.postgresql.org/wiki/Shared_Database_Hosting
108 postStart = ''
109 set -eux
110 # DOC: https://wiki.postgresql.org/wiki/Shared_Database_Hosting#Defining_shared_hosting
111 $PSQL -d template1 --set ON_ERROR_STOP=1 -f - <<EOF
112 -- Disallow access to the public schema
113 -- of individual users' databases by other users
114 REVOKE ALL ON DATABASE template0 FROM public;
115 REVOKE ALL ON DATABASE template1 FROM public;
116 REVOKE ALL ON SCHEMA public FROM public;
117 GRANT USAGE,CREATE ON SCHEMA public TO public;
118 GRANT ALL ON SCHEMA public TO "${postgresql.superUser}";
119 REVOKE ALL ON ALL TABLES IN SCHEMA public FROM public;
120 GRANT ALL ON ALL TABLES IN SCHEMA public TO "${postgresql.superUser}";
121
122 -- Disallow access to database and user names for everyone
123 REVOKE ALL ON pg_catalog.pg_user FROM public;
124 REVOKE ALL ON pg_catalog.pg_group FROM public;
125 REVOKE ALL ON pg_catalog.pg_authid FROM public;
126 REVOKE ALL ON pg_catalog.pg_auth_members FROM public;
127 REVOKE ALL ON pg_catalog.pg_settings FROM public;
128 -- The following must have SELECT reallowed if pg_dump is allowed
129 REVOKE ALL ON pg_catalog.pg_roles FROM public;
130 REVOKE ALL ON pg_catalog.pg_database FROM public;
131 REVOKE ALL ON pg_catalog.pg_tablespace FROM public;
132 EOF
133
134 pg_createdb () {
135 local db=$1
136 local owner=''${owner:-$db}
137 local template=''${template:-template1}
138 $PSQL -tAc "SELECT 1 FROM pg_catalog.pg_database WHERE datname = '$db'" | grep -q 1 || {
139 $PSQL -d "$template" -AqtX --set ON_ERROR_STOP=1 -f - <<EOF
140 CREATE ROLE "$owner" NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT LOGIN ''${pass:+PASSWORD '$pass'};
141 CREATE DATABASE "$db" WITH OWNER="$owner"
142 ''${encoding:+ENCODING='$encoding'}
143 ''${lc_collate:+LC_COLLATE='$lc_collate'}
144 ''${lc_ctype:+LC_CTYPE='$lc_ctype'}
145 ''${tablespace:+TABLESPACE='$tablespace'}
146 ''${connection_limit:+CONNECTION LIMIT=$connection_limit}
147 ;
148 REVOKE ALL ON DATABASE "$db" FROM public;
149 EOF
150 $PSQL -d "$db" -AqtX --set ON_ERROR_STOP=1 -f - <<EOF
151 -- Grant all rights to the public schema in the new database to the main user
152 GRANT ALL ON SCHEMA public TO "$owner" WITH GRANT OPTION;
153 EOF
154 $PSQL -d "$db" -AqtX --set ON_ERROR_STOP=1 -f -
155 }
156 }
157
158 pg_adduser () {
159 local db=$1
160 local user=$2
161 $PSQL -tAc "SELECT 1 FROM pg_catalog.pg_roles WHERE rolname='$user'" | grep -q 1 ||
162 $PSQL -d "$db" -AqtX --set ON_ERROR_STOP=1 -f - <<EOF
163 CREATE ROLE "$user" NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT LOGIN ''${pass:+ENCRYPTED PASSWORD '$pass'};
164 GRANT USAGE ON SCHEMA public TO "$user";
165 GRANT CONNECT,TEMPORARY ON DATABASE "$db" TO "$user";
166 EOF
167 }
168 '';
169 };
170 }