2 * PostgreSQL System Views
4 * Copyright (c) 1996-2020, PostgreSQL Global Development Group
6 * src/backend/catalog/system_views.sql
8 * Note: this file is read in single-user -j mode, which means that the
9 * command terminator is semicolon-newline-newline; whenever the backend
10 * sees that, it stops and executes what it's got. If you write a lot of
11 * statements without empty lines between, they'll all get quoted to you
12 * in any error message about one of them, so don't do that. Also, you
13 * cannot write a semicolon immediately followed by an empty line in a
14 * string literal (including a function body!) or a multiline comment.
17 CREATE VIEW pg_roles AS
27 '********'::text as rolpassword,
30 setconfig as rolconfig,
32 FROM pg_authid LEFT JOIN pg_db_role_setting s
33 ON (pg_authid.oid = setrole AND setdatabase = 0);
35 CREATE VIEW pg_shadow AS
38 pg_authid.oid AS usesysid,
39 rolcreatedb AS usecreatedb,
41 rolreplication AS userepl,
42 rolbypassrls AS usebypassrls,
43 rolpassword AS passwd,
44 rolvaliduntil AS valuntil,
45 setconfig AS useconfig
46 FROM pg_authid LEFT JOIN pg_db_role_setting s
47 ON (pg_authid.oid = setrole AND setdatabase = 0)
50 REVOKE ALL on pg_shadow FROM public;
52 CREATE VIEW pg_group AS
56 ARRAY(SELECT member FROM pg_auth_members WHERE roleid = oid) AS grolist
58 WHERE NOT rolcanlogin;
60 CREATE VIEW pg_user AS
68 '********'::text as passwd,
73 CREATE VIEW pg_policies AS
75 N.nspname AS schemaname,
76 C.relname AS tablename,
77 pol.polname AS policyname,
79 WHEN pol.polpermissive THEN
85 WHEN pol.polroles = '{0}' THEN
86 string_to_array('public', '')
91 FROM pg_catalog.pg_authid
92 WHERE oid = ANY (pol.polroles) ORDER BY 1
96 WHEN 'r' THEN 'SELECT'
97 WHEN 'a' THEN 'INSERT'
98 WHEN 'w' THEN 'UPDATE'
99 WHEN 'd' THEN 'DELETE'
102 pg_catalog.pg_get_expr(pol.polqual, pol.polrelid) AS qual,
103 pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid) AS with_check
104 FROM pg_catalog.pg_policy pol
105 JOIN pg_catalog.pg_class C ON (C.oid = pol.polrelid)
106 LEFT JOIN pg_catalog.pg_namespace N ON (N.oid = C.relnamespace);
108 CREATE VIEW pg_rules AS
110 N.nspname AS schemaname,
111 C.relname AS tablename,
112 R.rulename AS rulename,
113 pg_get_ruledef(R.oid) AS definition
114 FROM (pg_rewrite R JOIN pg_class C ON (C.oid = R.ev_class))
115 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
116 WHERE R.rulename != '_RETURN';
118 CREATE VIEW pg_views AS
120 N.nspname AS schemaname,
121 C.relname AS viewname,
122 pg_get_userbyid(C.relowner) AS viewowner,
123 pg_get_viewdef(C.oid) AS definition
124 FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
125 WHERE C.relkind = 'v';
127 CREATE VIEW pg_tables AS
129 N.nspname AS schemaname,
130 C.relname AS tablename,
131 pg_get_userbyid(C.relowner) AS tableowner,
132 T.spcname AS tablespace,
133 C.relhasindex AS hasindexes,
134 C.relhasrules AS hasrules,
135 C.relhastriggers AS hastriggers,
136 C.relrowsecurity AS rowsecurity
137 FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
138 LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
139 WHERE C.relkind IN ('r', 'p');
141 CREATE VIEW pg_matviews AS
143 N.nspname AS schemaname,
144 C.relname AS matviewname,
145 pg_get_userbyid(C.relowner) AS matviewowner,
146 T.spcname AS tablespace,
147 C.relhasindex AS hasindexes,
148 C.relispopulated AS ispopulated,
149 pg_get_viewdef(C.oid) AS definition
150 FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
151 LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
152 WHERE C.relkind = 'm';
154 CREATE VIEW pg_indexes AS
156 N.nspname AS schemaname,
157 C.relname AS tablename,
158 I.relname AS indexname,
159 T.spcname AS tablespace,
160 pg_get_indexdef(I.oid) AS indexdef
161 FROM pg_index X JOIN pg_class C ON (C.oid = X.indrelid)
162 JOIN pg_class I ON (I.oid = X.indexrelid)
163 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
164 LEFT JOIN pg_tablespace T ON (T.oid = I.reltablespace)
165 WHERE C.relkind IN ('r', 'm', 'p') AND I.relkind IN ('i', 'I');
167 CREATE OR REPLACE VIEW pg_sequences AS
169 N.nspname AS schemaname,
170 C.relname AS sequencename,
171 pg_get_userbyid(C.relowner) AS sequenceowner,
172 S.seqtypid::regtype AS data_type,
173 S.seqstart AS start_value,
174 S.seqmin AS min_value,
175 S.seqmax AS max_value,
176 S.seqincrement AS increment_by,
178 S.seqcache AS cache_size,
180 WHEN has_sequence_privilege(C.oid, 'SELECT,USAGE'::text)
181 THEN pg_sequence_last_value(C.oid)
184 FROM pg_sequence S JOIN pg_class C ON (C.oid = S.seqrelid)
185 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
186 WHERE NOT pg_is_other_temp_schema(N.oid)
189 CREATE VIEW pg_stats WITH (security_barrier) AS
191 nspname AS schemaname,
192 relname AS tablename,
194 stainherit AS inherited,
195 stanullfrac AS null_frac,
196 stawidth AS avg_width,
197 stadistinct AS n_distinct,
199 WHEN stakind1 = 1 THEN stavalues1
200 WHEN stakind2 = 1 THEN stavalues2
201 WHEN stakind3 = 1 THEN stavalues3
202 WHEN stakind4 = 1 THEN stavalues4
203 WHEN stakind5 = 1 THEN stavalues5
204 END AS most_common_vals,
206 WHEN stakind1 = 1 THEN stanumbers1
207 WHEN stakind2 = 1 THEN stanumbers2
208 WHEN stakind3 = 1 THEN stanumbers3
209 WHEN stakind4 = 1 THEN stanumbers4
210 WHEN stakind5 = 1 THEN stanumbers5
211 END AS most_common_freqs,
213 WHEN stakind1 = 2 THEN stavalues1
214 WHEN stakind2 = 2 THEN stavalues2
215 WHEN stakind3 = 2 THEN stavalues3
216 WHEN stakind4 = 2 THEN stavalues4
217 WHEN stakind5 = 2 THEN stavalues5
218 END AS histogram_bounds,
220 WHEN stakind1 = 3 THEN stanumbers1[1]
221 WHEN stakind2 = 3 THEN stanumbers2[1]
222 WHEN stakind3 = 3 THEN stanumbers3[1]
223 WHEN stakind4 = 3 THEN stanumbers4[1]
224 WHEN stakind5 = 3 THEN stanumbers5[1]
227 WHEN stakind1 = 4 THEN stavalues1
228 WHEN stakind2 = 4 THEN stavalues2
229 WHEN stakind3 = 4 THEN stavalues3
230 WHEN stakind4 = 4 THEN stavalues4
231 WHEN stakind5 = 4 THEN stavalues5
232 END AS most_common_elems,
234 WHEN stakind1 = 4 THEN stanumbers1
235 WHEN stakind2 = 4 THEN stanumbers2
236 WHEN stakind3 = 4 THEN stanumbers3
237 WHEN stakind4 = 4 THEN stanumbers4
238 WHEN stakind5 = 4 THEN stanumbers5
239 END AS most_common_elem_freqs,
241 WHEN stakind1 = 5 THEN stanumbers1
242 WHEN stakind2 = 5 THEN stanumbers2
243 WHEN stakind3 = 5 THEN stanumbers3
244 WHEN stakind4 = 5 THEN stanumbers4
245 WHEN stakind5 = 5 THEN stanumbers5
246 END AS elem_count_histogram
247 FROM pg_statistic s JOIN pg_class c ON (c.oid = s.starelid)
248 JOIN pg_attribute a ON (c.oid = attrelid AND attnum = s.staattnum)
249 LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace)
250 WHERE NOT attisdropped
251 AND has_column_privilege(c.oid, a.attnum, 'select')
252 AND (c.relrowsecurity = false OR NOT row_security_active(c.oid));
254 REVOKE ALL on pg_statistic FROM public;
256 CREATE VIEW pg_stats_ext WITH (security_barrier) AS
257 SELECT cn.nspname AS schemaname,
258 c.relname AS tablename,
259 sn.nspname AS statistics_schemaname,
260 s.stxname AS statistics_name,
261 pg_get_userbyid(s.stxowner) AS statistics_owner,
262 ( SELECT array_agg(a.attname ORDER BY a.attnum)
263 FROM unnest(s.stxkeys) k
265 ON (a.attrelid = s.stxrelid AND a.attnum = k)
268 sd.stxdndistinct AS n_distinct,
269 sd.stxddependencies AS dependencies,
271 m.most_common_val_nulls,
273 m.most_common_base_freqs
274 FROM pg_statistic_ext s JOIN pg_class c ON (c.oid = s.stxrelid)
275 JOIN pg_statistic_ext_data sd ON (s.oid = sd.stxoid)
276 LEFT JOIN pg_namespace cn ON (cn.oid = c.relnamespace)
277 LEFT JOIN pg_namespace sn ON (sn.oid = s.stxnamespace)
279 ( SELECT array_agg(values) AS most_common_vals,
280 array_agg(nulls) AS most_common_val_nulls,
281 array_agg(frequency) AS most_common_freqs,
282 array_agg(base_frequency) AS most_common_base_freqs
283 FROM pg_mcv_list_items(sd.stxdmcv)
284 ) m ON sd.stxdmcv IS NOT NULL
287 FROM unnest(stxkeys) k
289 ON (a.attrelid = s.stxrelid AND a.attnum = k)
290 WHERE NOT has_column_privilege(c.oid, a.attnum, 'select') )
291 AND (c.relrowsecurity = false OR NOT row_security_active(c.oid));
293 -- unprivileged users may read pg_statistic_ext but not pg_statistic_ext_data
294 REVOKE ALL on pg_statistic_ext_data FROM public;
296 CREATE VIEW pg_publication_tables AS
298 P.pubname AS pubname,
299 N.nspname AS schemaname,
300 C.relname AS tablename
301 FROM pg_publication P,
302 LATERAL pg_get_publication_tables(P.pubname) GPT,
303 pg_class C JOIN pg_namespace N ON (N.oid = C.relnamespace)
304 WHERE C.oid = GPT.relid;
306 CREATE VIEW pg_locks AS
307 SELECT * FROM pg_lock_status() AS L;
309 CREATE VIEW pg_cursors AS
310 SELECT * FROM pg_cursor() AS C;
312 CREATE VIEW pg_available_extensions AS
313 SELECT E.name, E.default_version, X.extversion AS installed_version,
315 FROM pg_available_extensions() AS E
316 LEFT JOIN pg_extension AS X ON E.name = X.extname;
318 CREATE VIEW pg_available_extension_versions AS
319 SELECT E.name, E.version, (X.extname IS NOT NULL) AS installed,
320 E.superuser, E.trusted, E.relocatable,
321 E.schema, E.requires, E.comment
322 FROM pg_available_extension_versions() AS E
323 LEFT JOIN pg_extension AS X
324 ON E.name = X.extname AND E.version = X.extversion;
326 CREATE VIEW pg_prepared_xacts AS
327 SELECT P.transaction, P.gid, P.prepared,
328 U.rolname AS owner, D.datname AS database
329 FROM pg_prepared_xact() AS P
330 LEFT JOIN pg_authid U ON P.ownerid = U.oid
331 LEFT JOIN pg_database D ON P.dbid = D.oid;
333 CREATE VIEW pg_prepared_statements AS
334 SELECT * FROM pg_prepared_statement() AS P;
336 CREATE VIEW pg_seclabels AS
338 l.objoid, l.classoid, l.objsubid,
339 CASE WHEN rel.relkind IN ('r', 'p') THEN 'table'::text
340 WHEN rel.relkind = 'v' THEN 'view'::text
341 WHEN rel.relkind = 'm' THEN 'materialized view'::text
342 WHEN rel.relkind = 'S' THEN 'sequence'::text
343 WHEN rel.relkind = 'f' THEN 'foreign table'::text END AS objtype,
344 rel.relnamespace AS objnamespace,
345 CASE WHEN pg_table_is_visible(rel.oid)
346 THEN quote_ident(rel.relname)
347 ELSE quote_ident(nsp.nspname) || '.' || quote_ident(rel.relname)
352 JOIN pg_class rel ON l.classoid = rel.tableoid AND l.objoid = rel.oid
353 JOIN pg_namespace nsp ON rel.relnamespace = nsp.oid
358 l.objoid, l.classoid, l.objsubid,
359 'column'::text AS objtype,
360 rel.relnamespace AS objnamespace,
361 CASE WHEN pg_table_is_visible(rel.oid)
362 THEN quote_ident(rel.relname)
363 ELSE quote_ident(nsp.nspname) || '.' || quote_ident(rel.relname)
364 END || '.' || att.attname AS objname,
368 JOIN pg_class rel ON l.classoid = rel.tableoid AND l.objoid = rel.oid
369 JOIN pg_attribute att
370 ON rel.oid = att.attrelid AND l.objsubid = att.attnum
371 JOIN pg_namespace nsp ON rel.relnamespace = nsp.oid
376 l.objoid, l.classoid, l.objsubid,
378 WHEN 'a' THEN 'aggregate'::text
379 WHEN 'f' THEN 'function'::text
380 WHEN 'p' THEN 'procedure'::text
381 WHEN 'w' THEN 'window'::text END AS objtype,
382 pro.pronamespace AS objnamespace,
383 CASE WHEN pg_function_is_visible(pro.oid)
384 THEN quote_ident(pro.proname)
385 ELSE quote_ident(nsp.nspname) || '.' || quote_ident(pro.proname)
386 END || '(' || pg_catalog.pg_get_function_arguments(pro.oid) || ')' AS objname,
390 JOIN pg_proc pro ON l.classoid = pro.tableoid AND l.objoid = pro.oid
391 JOIN pg_namespace nsp ON pro.pronamespace = nsp.oid
396 l.objoid, l.classoid, l.objsubid,
397 CASE WHEN typ.typtype = 'd' THEN 'domain'::text
398 ELSE 'type'::text END AS objtype,
399 typ.typnamespace AS objnamespace,
400 CASE WHEN pg_type_is_visible(typ.oid)
401 THEN quote_ident(typ.typname)
402 ELSE quote_ident(nsp.nspname) || '.' || quote_ident(typ.typname)
407 JOIN pg_type typ ON l.classoid = typ.tableoid AND l.objoid = typ.oid
408 JOIN pg_namespace nsp ON typ.typnamespace = nsp.oid
413 l.objoid, l.classoid, l.objsubid,
414 'large object'::text AS objtype,
415 NULL::oid AS objnamespace,
416 l.objoid::text AS objname,
420 JOIN pg_largeobject_metadata lom ON l.objoid = lom.oid
422 l.classoid = 'pg_catalog.pg_largeobject'::regclass AND l.objsubid = 0
425 l.objoid, l.classoid, l.objsubid,
426 'language'::text AS objtype,
427 NULL::oid AS objnamespace,
428 quote_ident(lan.lanname) AS objname,
432 JOIN pg_language lan ON l.classoid = lan.tableoid AND l.objoid = lan.oid
437 l.objoid, l.classoid, l.objsubid,
438 'schema'::text AS objtype,
439 nsp.oid AS objnamespace,
440 quote_ident(nsp.nspname) AS objname,
444 JOIN pg_namespace nsp ON l.classoid = nsp.tableoid AND l.objoid = nsp.oid
449 l.objoid, l.classoid, l.objsubid,
450 'event trigger'::text AS objtype,
451 NULL::oid AS objnamespace,
452 quote_ident(evt.evtname) AS objname,
456 JOIN pg_event_trigger evt ON l.classoid = evt.tableoid
457 AND l.objoid = evt.oid
462 l.objoid, l.classoid, l.objsubid,
463 'publication'::text AS objtype,
464 NULL::oid AS objnamespace,
465 quote_ident(p.pubname) AS objname,
469 JOIN pg_publication p ON l.classoid = p.tableoid AND l.objoid = p.oid
474 l.objoid, l.classoid, 0::int4 AS objsubid,
475 'subscription'::text AS objtype,
476 NULL::oid AS objnamespace,
477 quote_ident(s.subname) AS objname,
481 JOIN pg_subscription s ON l.classoid = s.tableoid AND l.objoid = s.oid
484 l.objoid, l.classoid, 0::int4 AS objsubid,
485 'database'::text AS objtype,
486 NULL::oid AS objnamespace,
487 quote_ident(dat.datname) AS objname,
491 JOIN pg_database dat ON l.classoid = dat.tableoid AND l.objoid = dat.oid
494 l.objoid, l.classoid, 0::int4 AS objsubid,
495 'tablespace'::text AS objtype,
496 NULL::oid AS objnamespace,
497 quote_ident(spc.spcname) AS objname,
501 JOIN pg_tablespace spc ON l.classoid = spc.tableoid AND l.objoid = spc.oid
504 l.objoid, l.classoid, 0::int4 AS objsubid,
505 'role'::text AS objtype,
506 NULL::oid AS objnamespace,
507 quote_ident(rol.rolname) AS objname,
511 JOIN pg_authid rol ON l.classoid = rol.tableoid AND l.objoid = rol.oid;
513 CREATE VIEW pg_settings AS
514 SELECT * FROM pg_show_all_settings() AS A;
516 CREATE RULE pg_settings_u AS
517 ON UPDATE TO pg_settings
518 WHERE new.name = old.name DO
519 SELECT set_config(old.name, new.setting, 'f');
521 CREATE RULE pg_settings_n AS
522 ON UPDATE TO pg_settings
525 GRANT SELECT, UPDATE ON pg_settings TO PUBLIC;
527 CREATE VIEW pg_file_settings AS
528 SELECT * FROM pg_show_all_file_settings() AS A;
530 REVOKE ALL on pg_file_settings FROM PUBLIC;
531 REVOKE EXECUTE ON FUNCTION pg_show_all_file_settings() FROM PUBLIC;
533 CREATE VIEW pg_hba_file_rules AS
534 SELECT * FROM pg_hba_file_rules() AS A;
536 REVOKE ALL on pg_hba_file_rules FROM PUBLIC;
537 REVOKE EXECUTE ON FUNCTION pg_hba_file_rules() FROM PUBLIC;
539 CREATE VIEW pg_timezone_abbrevs AS
540 SELECT * FROM pg_timezone_abbrevs();
542 CREATE VIEW pg_timezone_names AS
543 SELECT * FROM pg_timezone_names();
545 CREATE VIEW pg_config AS
546 SELECT * FROM pg_config();
548 REVOKE ALL on pg_config FROM PUBLIC;
549 REVOKE EXECUTE ON FUNCTION pg_config() FROM PUBLIC;
551 CREATE VIEW pg_shmem_allocations AS
552 SELECT * FROM pg_get_shmem_allocations();
554 REVOKE ALL ON pg_shmem_allocations FROM PUBLIC;
555 REVOKE EXECUTE ON FUNCTION pg_get_shmem_allocations() FROM PUBLIC;
559 CREATE VIEW pg_stat_all_tables AS
562 N.nspname AS schemaname,
563 C.relname AS relname,
564 pg_stat_get_numscans(C.oid) AS seq_scan,
565 pg_stat_get_tuples_returned(C.oid) AS seq_tup_read,
566 sum(pg_stat_get_numscans(I.indexrelid))::bigint AS idx_scan,
567 sum(pg_stat_get_tuples_fetched(I.indexrelid))::bigint +
568 pg_stat_get_tuples_fetched(C.oid) AS idx_tup_fetch,
569 pg_stat_get_tuples_inserted(C.oid) AS n_tup_ins,
570 pg_stat_get_tuples_updated(C.oid) AS n_tup_upd,
571 pg_stat_get_tuples_deleted(C.oid) AS n_tup_del,
572 pg_stat_get_tuples_hot_updated(C.oid) AS n_tup_hot_upd,
573 pg_stat_get_live_tuples(C.oid) AS n_live_tup,
574 pg_stat_get_dead_tuples(C.oid) AS n_dead_tup,
575 pg_stat_get_mod_since_analyze(C.oid) AS n_mod_since_analyze,
576 pg_stat_get_ins_since_vacuum(C.oid) AS n_ins_since_vacuum,
577 pg_stat_get_last_vacuum_time(C.oid) as last_vacuum,
578 pg_stat_get_last_autovacuum_time(C.oid) as last_autovacuum,
579 pg_stat_get_last_analyze_time(C.oid) as last_analyze,
580 pg_stat_get_last_autoanalyze_time(C.oid) as last_autoanalyze,
581 pg_stat_get_vacuum_count(C.oid) AS vacuum_count,
582 pg_stat_get_autovacuum_count(C.oid) AS autovacuum_count,
583 pg_stat_get_analyze_count(C.oid) AS analyze_count,
584 pg_stat_get_autoanalyze_count(C.oid) AS autoanalyze_count
585 FROM pg_class C LEFT JOIN
586 pg_index I ON C.oid = I.indrelid
587 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
588 WHERE C.relkind IN ('r', 't', 'm')
589 GROUP BY C.oid, N.nspname, C.relname;
591 CREATE VIEW pg_stat_xact_all_tables AS
594 N.nspname AS schemaname,
595 C.relname AS relname,
596 pg_stat_get_xact_numscans(C.oid) AS seq_scan,
597 pg_stat_get_xact_tuples_returned(C.oid) AS seq_tup_read,
598 sum(pg_stat_get_xact_numscans(I.indexrelid))::bigint AS idx_scan,
599 sum(pg_stat_get_xact_tuples_fetched(I.indexrelid))::bigint +
600 pg_stat_get_xact_tuples_fetched(C.oid) AS idx_tup_fetch,
601 pg_stat_get_xact_tuples_inserted(C.oid) AS n_tup_ins,
602 pg_stat_get_xact_tuples_updated(C.oid) AS n_tup_upd,
603 pg_stat_get_xact_tuples_deleted(C.oid) AS n_tup_del,
604 pg_stat_get_xact_tuples_hot_updated(C.oid) AS n_tup_hot_upd
605 FROM pg_class C LEFT JOIN
606 pg_index I ON C.oid = I.indrelid
607 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
608 WHERE C.relkind IN ('r', 't', 'm')
609 GROUP BY C.oid, N.nspname, C.relname;
611 CREATE VIEW pg_stat_sys_tables AS
612 SELECT * FROM pg_stat_all_tables
613 WHERE schemaname IN ('pg_catalog', 'information_schema') OR
614 schemaname ~ '^pg_toast';
616 CREATE VIEW pg_stat_xact_sys_tables AS
617 SELECT * FROM pg_stat_xact_all_tables
618 WHERE schemaname IN ('pg_catalog', 'information_schema') OR
619 schemaname ~ '^pg_toast';
621 CREATE VIEW pg_stat_user_tables AS
622 SELECT * FROM pg_stat_all_tables
623 WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
624 schemaname !~ '^pg_toast';
626 CREATE VIEW pg_stat_xact_user_tables AS
627 SELECT * FROM pg_stat_xact_all_tables
628 WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
629 schemaname !~ '^pg_toast';
631 CREATE VIEW pg_statio_all_tables AS
634 N.nspname AS schemaname,
635 C.relname AS relname,
636 pg_stat_get_blocks_fetched(C.oid) -
637 pg_stat_get_blocks_hit(C.oid) AS heap_blks_read,
638 pg_stat_get_blocks_hit(C.oid) AS heap_blks_hit,
639 sum(pg_stat_get_blocks_fetched(I.indexrelid) -
640 pg_stat_get_blocks_hit(I.indexrelid))::bigint AS idx_blks_read,
641 sum(pg_stat_get_blocks_hit(I.indexrelid))::bigint AS idx_blks_hit,
642 pg_stat_get_blocks_fetched(T.oid) -
643 pg_stat_get_blocks_hit(T.oid) AS toast_blks_read,
644 pg_stat_get_blocks_hit(T.oid) AS toast_blks_hit,
645 pg_stat_get_blocks_fetched(X.indexrelid) -
646 pg_stat_get_blocks_hit(X.indexrelid) AS tidx_blks_read,
647 pg_stat_get_blocks_hit(X.indexrelid) AS tidx_blks_hit
648 FROM pg_class C LEFT JOIN
649 pg_index I ON C.oid = I.indrelid LEFT JOIN
650 pg_class T ON C.reltoastrelid = T.oid LEFT JOIN
651 pg_index X ON T.oid = X.indrelid
652 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
653 WHERE C.relkind IN ('r', 't', 'm')
654 GROUP BY C.oid, N.nspname, C.relname, T.oid, X.indexrelid;
656 CREATE VIEW pg_statio_sys_tables AS
657 SELECT * FROM pg_statio_all_tables
658 WHERE schemaname IN ('pg_catalog', 'information_schema') OR
659 schemaname ~ '^pg_toast';
661 CREATE VIEW pg_statio_user_tables AS
662 SELECT * FROM pg_statio_all_tables
663 WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
664 schemaname !~ '^pg_toast';
666 CREATE VIEW pg_stat_all_indexes AS
670 N.nspname AS schemaname,
671 C.relname AS relname,
672 I.relname AS indexrelname,
673 pg_stat_get_numscans(I.oid) AS idx_scan,
674 pg_stat_get_tuples_returned(I.oid) AS idx_tup_read,
675 pg_stat_get_tuples_fetched(I.oid) AS idx_tup_fetch
677 pg_index X ON C.oid = X.indrelid JOIN
678 pg_class I ON I.oid = X.indexrelid
679 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
680 WHERE C.relkind IN ('r', 't', 'm');
682 CREATE VIEW pg_stat_sys_indexes AS
683 SELECT * FROM pg_stat_all_indexes
684 WHERE schemaname IN ('pg_catalog', 'information_schema') OR
685 schemaname ~ '^pg_toast';
687 CREATE VIEW pg_stat_user_indexes AS
688 SELECT * FROM pg_stat_all_indexes
689 WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
690 schemaname !~ '^pg_toast';
692 CREATE VIEW pg_statio_all_indexes AS
696 N.nspname AS schemaname,
697 C.relname AS relname,
698 I.relname AS indexrelname,
699 pg_stat_get_blocks_fetched(I.oid) -
700 pg_stat_get_blocks_hit(I.oid) AS idx_blks_read,
701 pg_stat_get_blocks_hit(I.oid) AS idx_blks_hit
703 pg_index X ON C.oid = X.indrelid JOIN
704 pg_class I ON I.oid = X.indexrelid
705 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
706 WHERE C.relkind IN ('r', 't', 'm');
708 CREATE VIEW pg_statio_sys_indexes AS
709 SELECT * FROM pg_statio_all_indexes
710 WHERE schemaname IN ('pg_catalog', 'information_schema') OR
711 schemaname ~ '^pg_toast';
713 CREATE VIEW pg_statio_user_indexes AS
714 SELECT * FROM pg_statio_all_indexes
715 WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
716 schemaname !~ '^pg_toast';
718 CREATE VIEW pg_statio_all_sequences AS
721 N.nspname AS schemaname,
722 C.relname AS relname,
723 pg_stat_get_blocks_fetched(C.oid) -
724 pg_stat_get_blocks_hit(C.oid) AS blks_read,
725 pg_stat_get_blocks_hit(C.oid) AS blks_hit
727 LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
728 WHERE C.relkind = 'S';
730 CREATE VIEW pg_statio_sys_sequences AS
731 SELECT * FROM pg_statio_all_sequences
732 WHERE schemaname IN ('pg_catalog', 'information_schema') OR
733 schemaname ~ '^pg_toast';
735 CREATE VIEW pg_statio_user_sequences AS
736 SELECT * FROM pg_statio_all_sequences
737 WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
738 schemaname !~ '^pg_toast';
740 CREATE VIEW pg_stat_activity AS
743 D.datname AS datname,
747 U.rolname AS usename,
763 FROM pg_stat_get_activity(NULL) AS S
764 LEFT JOIN pg_database AS D ON (S.datid = D.oid)
765 LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
767 CREATE VIEW pg_stat_replication AS
771 U.rolname AS usename,
789 FROM pg_stat_get_activity(NULL) AS S
790 JOIN pg_stat_get_wal_senders() AS W ON (S.pid = W.pid)
791 LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
793 CREATE VIEW pg_stat_slru AS
804 FROM pg_stat_get_slru() s;
806 CREATE VIEW pg_stat_wal_receiver AS
815 s.last_msg_send_time,
816 s.last_msg_receipt_time,
823 FROM pg_stat_get_wal_receiver() s
824 WHERE s.pid IS NOT NULL;
826 CREATE VIEW pg_stat_subscription AS
833 st.last_msg_send_time,
834 st.last_msg_receipt_time,
837 FROM pg_subscription su
838 LEFT JOIN pg_stat_get_subscription(NULL) st
839 ON (st.subid = su.oid);
841 CREATE VIEW pg_stat_ssl AS
845 S.sslversion AS version,
846 S.sslcipher AS cipher,
848 S.sslcompression AS compression,
849 S.ssl_client_dn AS client_dn,
850 S.ssl_client_serial AS client_serial,
851 S.ssl_issuer_dn AS issuer_dn
852 FROM pg_stat_get_activity(NULL) AS S
853 WHERE S.client_port IS NOT NULL;
855 CREATE VIEW pg_stat_gssapi AS
858 S.gss_auth AS gss_authenticated,
859 S.gss_princ AS principal,
860 S.gss_enc AS encrypted
861 FROM pg_stat_get_activity(NULL) AS S
862 WHERE S.client_port IS NOT NULL;
864 CREATE VIEW pg_replication_slots AS
870 D.datname AS database,
877 L.confirmed_flush_lsn,
880 FROM pg_get_replication_slots() AS L
881 LEFT JOIN pg_database D ON (L.datoid = D.oid);
883 CREATE VIEW pg_stat_database AS
886 D.datname AS datname,
888 WHEN (D.oid = (0)::oid) THEN 0
889 ELSE pg_stat_get_db_numbackends(D.oid)
891 pg_stat_get_db_xact_commit(D.oid) AS xact_commit,
892 pg_stat_get_db_xact_rollback(D.oid) AS xact_rollback,
893 pg_stat_get_db_blocks_fetched(D.oid) -
894 pg_stat_get_db_blocks_hit(D.oid) AS blks_read,
895 pg_stat_get_db_blocks_hit(D.oid) AS blks_hit,
896 pg_stat_get_db_tuples_returned(D.oid) AS tup_returned,
897 pg_stat_get_db_tuples_fetched(D.oid) AS tup_fetched,
898 pg_stat_get_db_tuples_inserted(D.oid) AS tup_inserted,
899 pg_stat_get_db_tuples_updated(D.oid) AS tup_updated,
900 pg_stat_get_db_tuples_deleted(D.oid) AS tup_deleted,
901 pg_stat_get_db_conflict_all(D.oid) AS conflicts,
902 pg_stat_get_db_temp_files(D.oid) AS temp_files,
903 pg_stat_get_db_temp_bytes(D.oid) AS temp_bytes,
904 pg_stat_get_db_deadlocks(D.oid) AS deadlocks,
905 pg_stat_get_db_checksum_failures(D.oid) AS checksum_failures,
906 pg_stat_get_db_checksum_last_failure(D.oid) AS checksum_last_failure,
907 pg_stat_get_db_blk_read_time(D.oid) AS blk_read_time,
908 pg_stat_get_db_blk_write_time(D.oid) AS blk_write_time,
909 pg_stat_get_db_stat_reset_time(D.oid) AS stats_reset
911 SELECT 0 AS oid, NULL::name AS datname
913 SELECT oid, datname FROM pg_database
916 CREATE VIEW pg_stat_database_conflicts AS
919 D.datname AS datname,
920 pg_stat_get_db_conflict_tablespace(D.oid) AS confl_tablespace,
921 pg_stat_get_db_conflict_lock(D.oid) AS confl_lock,
922 pg_stat_get_db_conflict_snapshot(D.oid) AS confl_snapshot,
923 pg_stat_get_db_conflict_bufferpin(D.oid) AS confl_bufferpin,
924 pg_stat_get_db_conflict_startup_deadlock(D.oid) AS confl_deadlock
927 CREATE VIEW pg_stat_user_functions AS
930 N.nspname AS schemaname,
931 P.proname AS funcname,
932 pg_stat_get_function_calls(P.oid) AS calls,
933 pg_stat_get_function_total_time(P.oid) AS total_time,
934 pg_stat_get_function_self_time(P.oid) AS self_time
935 FROM pg_proc P LEFT JOIN pg_namespace N ON (N.oid = P.pronamespace)
936 WHERE P.prolang != 12 -- fast check to eliminate built-in functions
937 AND pg_stat_get_function_calls(P.oid) IS NOT NULL;
939 CREATE VIEW pg_stat_xact_user_functions AS
942 N.nspname AS schemaname,
943 P.proname AS funcname,
944 pg_stat_get_xact_function_calls(P.oid) AS calls,
945 pg_stat_get_xact_function_total_time(P.oid) AS total_time,
946 pg_stat_get_xact_function_self_time(P.oid) AS self_time
947 FROM pg_proc P LEFT JOIN pg_namespace N ON (N.oid = P.pronamespace)
948 WHERE P.prolang != 12 -- fast check to eliminate built-in functions
949 AND pg_stat_get_xact_function_calls(P.oid) IS NOT NULL;
951 CREATE VIEW pg_stat_archiver AS
955 s.last_archived_time,
960 FROM pg_stat_get_archiver() s;
962 CREATE VIEW pg_stat_bgwriter AS
964 pg_stat_get_bgwriter_timed_checkpoints() AS checkpoints_timed,
965 pg_stat_get_bgwriter_requested_checkpoints() AS checkpoints_req,
966 pg_stat_get_checkpoint_write_time() AS checkpoint_write_time,
967 pg_stat_get_checkpoint_sync_time() AS checkpoint_sync_time,
968 pg_stat_get_bgwriter_buf_written_checkpoints() AS buffers_checkpoint,
969 pg_stat_get_bgwriter_buf_written_clean() AS buffers_clean,
970 pg_stat_get_bgwriter_maxwritten_clean() AS maxwritten_clean,
971 pg_stat_get_buf_written_backend() AS buffers_backend,
972 pg_stat_get_buf_fsync_backend() AS buffers_backend_fsync,
973 pg_stat_get_buf_alloc() AS buffers_alloc,
974 pg_stat_get_bgwriter_stat_reset_time() AS stats_reset;
976 CREATE VIEW pg_stat_progress_analyze AS
978 S.pid AS pid, S.datid AS datid, D.datname AS datname,
979 CAST(S.relid AS oid) AS relid,
980 CASE S.param1 WHEN 0 THEN 'initializing'
981 WHEN 1 THEN 'acquiring sample rows'
982 WHEN 2 THEN 'acquiring inherited sample rows'
983 WHEN 3 THEN 'computing statistics'
984 WHEN 4 THEN 'computing extended statistics'
985 WHEN 5 THEN 'finalizing analyze'
987 S.param2 AS sample_blks_total,
988 S.param3 AS sample_blks_scanned,
989 S.param4 AS ext_stats_total,
990 S.param5 AS ext_stats_computed,
991 S.param6 AS child_tables_total,
992 S.param7 AS child_tables_done,
993 CAST(S.param8 AS oid) AS current_child_table_relid
994 FROM pg_stat_get_progress_info('ANALYZE') AS S
995 LEFT JOIN pg_database D ON S.datid = D.oid;
997 CREATE VIEW pg_stat_progress_vacuum AS
999 S.pid AS pid, S.datid AS datid, D.datname AS datname,
1001 CASE S.param1 WHEN 0 THEN 'initializing'
1002 WHEN 1 THEN 'scanning heap'
1003 WHEN 2 THEN 'vacuuming indexes'
1004 WHEN 3 THEN 'vacuuming heap'
1005 WHEN 4 THEN 'cleaning up indexes'
1006 WHEN 5 THEN 'truncating heap'
1007 WHEN 6 THEN 'performing final cleanup'
1009 S.param2 AS heap_blks_total, S.param3 AS heap_blks_scanned,
1010 S.param4 AS heap_blks_vacuumed, S.param5 AS index_vacuum_count,
1011 S.param6 AS max_dead_tuples, S.param7 AS num_dead_tuples
1012 FROM pg_stat_get_progress_info('VACUUM') AS S
1013 LEFT JOIN pg_database D ON S.datid = D.oid;
1015 CREATE VIEW pg_stat_progress_cluster AS
1019 D.datname AS datname,
1021 CASE S.param1 WHEN 1 THEN 'CLUSTER'
1022 WHEN 2 THEN 'VACUUM FULL'
1024 CASE S.param2 WHEN 0 THEN 'initializing'
1025 WHEN 1 THEN 'seq scanning heap'
1026 WHEN 2 THEN 'index scanning heap'
1027 WHEN 3 THEN 'sorting tuples'
1028 WHEN 4 THEN 'writing new heap'
1029 WHEN 5 THEN 'swapping relation files'
1030 WHEN 6 THEN 'rebuilding index'
1031 WHEN 7 THEN 'performing final cleanup'
1033 CAST(S.param3 AS oid) AS cluster_index_relid,
1034 S.param4 AS heap_tuples_scanned,
1035 S.param5 AS heap_tuples_written,
1036 S.param6 AS heap_blks_total,
1037 S.param7 AS heap_blks_scanned,
1038 S.param8 AS index_rebuild_count
1039 FROM pg_stat_get_progress_info('CLUSTER') AS S
1040 LEFT JOIN pg_database D ON S.datid = D.oid;
1042 CREATE VIEW pg_stat_progress_create_index AS
1044 S.pid AS pid, S.datid AS datid, D.datname AS datname,
1046 CAST(S.param7 AS oid) AS index_relid,
1047 CASE S.param1 WHEN 1 THEN 'CREATE INDEX'
1048 WHEN 2 THEN 'CREATE INDEX CONCURRENTLY'
1049 WHEN 3 THEN 'REINDEX'
1050 WHEN 4 THEN 'REINDEX CONCURRENTLY'
1052 CASE S.param10 WHEN 0 THEN 'initializing'
1053 WHEN 1 THEN 'waiting for writers before build'
1054 WHEN 2 THEN 'building index' ||
1055 COALESCE((': ' || pg_indexam_progress_phasename(S.param9::oid, S.param11)),
1057 WHEN 3 THEN 'waiting for writers before validation'
1058 WHEN 4 THEN 'index validation: scanning index'
1059 WHEN 5 THEN 'index validation: sorting tuples'
1060 WHEN 6 THEN 'index validation: scanning table'
1061 WHEN 7 THEN 'waiting for old snapshots'
1062 WHEN 8 THEN 'waiting for readers before marking dead'
1063 WHEN 9 THEN 'waiting for readers before dropping'
1065 S.param4 AS lockers_total,
1066 S.param5 AS lockers_done,
1067 S.param6 AS current_locker_pid,
1068 S.param16 AS blocks_total,
1069 S.param17 AS blocks_done,
1070 S.param12 AS tuples_total,
1071 S.param13 AS tuples_done,
1072 S.param14 AS partitions_total,
1073 S.param15 AS partitions_done
1074 FROM pg_stat_get_progress_info('CREATE INDEX') AS S
1075 LEFT JOIN pg_database D ON S.datid = D.oid;
1077 CREATE VIEW pg_stat_progress_basebackup AS
1080 CASE S.param1 WHEN 0 THEN 'initializing'
1081 WHEN 1 THEN 'waiting for checkpoint to finish'
1082 WHEN 2 THEN 'estimating backup size'
1083 WHEN 3 THEN 'streaming database files'
1084 WHEN 4 THEN 'waiting for wal archiving to finish'
1085 WHEN 5 THEN 'transferring wal files'
1087 CASE S.param2 WHEN -1 THEN NULL ELSE S.param2 END AS backup_total,
1088 S.param3 AS backup_streamed,
1089 S.param4 AS tablespaces_total,
1090 S.param5 AS tablespaces_streamed
1091 FROM pg_stat_get_progress_info('BASEBACKUP') AS S;
1093 CREATE VIEW pg_user_mappings AS
1097 S.srvname AS srvname,
1099 CASE WHEN U.umuser = 0 THEN
1104 CASE WHEN (U.umuser <> 0 AND A.rolname = current_user
1105 AND (pg_has_role(S.srvowner, 'USAGE')
1106 OR has_server_privilege(S.oid, 'USAGE')))
1107 OR (U.umuser = 0 AND pg_has_role(S.srvowner, 'USAGE'))
1108 OR (SELECT rolsuper FROM pg_authid WHERE rolname = current_user)
1110 ELSE NULL END AS umoptions
1111 FROM pg_user_mapping U
1112 JOIN pg_foreign_server S ON (U.umserver = S.oid)
1113 LEFT JOIN pg_authid A ON (A.oid = U.umuser);
1115 REVOKE ALL on pg_user_mapping FROM public;
1117 CREATE VIEW pg_replication_origin_status AS
1119 FROM pg_show_replication_origin_status();
1121 REVOKE ALL ON pg_replication_origin_status FROM public;
1123 -- All columns of pg_subscription except subconninfo are readable.
1124 REVOKE ALL ON pg_subscription FROM public;
1125 GRANT SELECT (subdbid, subname, subowner, subenabled, subbinary, subslotname, subpublications)
1126 ON pg_subscription TO public;
1130 -- We have a few function definitions in here, too.
1131 -- At some point there might be enough to justify breaking them out into
1132 -- a separate "system_functions.sql" file.
1135 -- Tsearch debug function. Defined here because it'd be pretty unwieldy
1136 -- to put it into pg_proc.h
1138 CREATE FUNCTION ts_debug(IN config regconfig, IN document text,
1140 OUT description text,
1142 OUT dictionaries regdictionary[],
1143 OUT dictionary regdictionary,
1145 RETURNS SETOF record AS
1149 tt.description AS description,
1150 parse.token AS token,
1151 ARRAY ( SELECT m.mapdict::pg_catalog.regdictionary
1152 FROM pg_catalog.pg_ts_config_map AS m
1153 WHERE m.mapcfg = $1 AND m.maptokentype = parse.tokid
1154 ORDER BY m.mapseqno )
1156 ( SELECT mapdict::pg_catalog.regdictionary
1157 FROM pg_catalog.pg_ts_config_map AS m
1158 WHERE m.mapcfg = $1 AND m.maptokentype = parse.tokid
1159 ORDER BY pg_catalog.ts_lexize(mapdict, parse.token) IS NULL, m.mapseqno
1162 ( SELECT pg_catalog.ts_lexize(mapdict, parse.token)
1163 FROM pg_catalog.pg_ts_config_map AS m
1164 WHERE m.mapcfg = $1 AND m.maptokentype = parse.tokid
1165 ORDER BY pg_catalog.ts_lexize(mapdict, parse.token) IS NULL, m.mapseqno
1168 FROM pg_catalog.ts_parse(
1169 (SELECT cfgparser FROM pg_catalog.pg_ts_config WHERE oid = $1 ), $2
1171 pg_catalog.ts_token_type(
1172 (SELECT cfgparser FROM pg_catalog.pg_ts_config WHERE oid = $1 )
1174 WHERE tt.tokid = parse.tokid
1176 LANGUAGE SQL STRICT STABLE PARALLEL SAFE;
1178 COMMENT ON FUNCTION ts_debug(regconfig,text) IS
1179 'debug function for text search configuration';
1181 CREATE FUNCTION ts_debug(IN document text,
1183 OUT description text,
1185 OUT dictionaries regdictionary[],
1186 OUT dictionary regdictionary,
1188 RETURNS SETOF record AS
1190 SELECT * FROM pg_catalog.ts_debug( pg_catalog.get_current_ts_config(), $1);
1192 LANGUAGE SQL STRICT STABLE PARALLEL SAFE;
1194 COMMENT ON FUNCTION ts_debug(text) IS
1195 'debug function for current text search configuration';
1198 -- Redeclare built-in functions that need default values attached to their
1199 -- arguments. It's impractical to set those up directly in pg_proc.h because
1200 -- of the complexity and platform-dependency of the expression tree
1201 -- representation. (Note that internal functions still have to have entries
1202 -- in pg_proc.h; we are merely causing their proargnames and proargdefaults
1203 -- to get filled in.)
1206 CREATE OR REPLACE FUNCTION
1207 pg_start_backup(label text, fast boolean DEFAULT false, exclusive boolean DEFAULT true)
1208 RETURNS pg_lsn STRICT VOLATILE LANGUAGE internal AS 'pg_start_backup'
1209 PARALLEL RESTRICTED;
1211 CREATE OR REPLACE FUNCTION pg_stop_backup (
1212 exclusive boolean, wait_for_archive boolean DEFAULT true,
1213 OUT lsn pg_lsn, OUT labelfile text, OUT spcmapfile text)
1214 RETURNS SETOF record STRICT VOLATILE LANGUAGE internal as 'pg_stop_backup_v2'
1215 PARALLEL RESTRICTED;
1217 CREATE OR REPLACE FUNCTION
1218 pg_promote(wait boolean DEFAULT true, wait_seconds integer DEFAULT 60)
1219 RETURNS boolean STRICT VOLATILE LANGUAGE INTERNAL AS 'pg_promote'
1222 -- legacy definition for compatibility with 9.3
1223 CREATE OR REPLACE FUNCTION
1224 json_populate_record(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
1225 RETURNS anyelement LANGUAGE internal STABLE AS 'json_populate_record' PARALLEL SAFE;
1227 -- legacy definition for compatibility with 9.3
1228 CREATE OR REPLACE FUNCTION
1229 json_populate_recordset(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
1230 RETURNS SETOF anyelement LANGUAGE internal STABLE ROWS 100 AS 'json_populate_recordset' PARALLEL SAFE;
1232 CREATE OR REPLACE FUNCTION pg_logical_slot_get_changes(
1233 IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
1234 OUT lsn pg_lsn, OUT xid xid, OUT data text)
1235 RETURNS SETOF RECORD
1237 VOLATILE ROWS 1000 COST 1000
1238 AS 'pg_logical_slot_get_changes';
1240 CREATE OR REPLACE FUNCTION pg_logical_slot_peek_changes(
1241 IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
1242 OUT lsn pg_lsn, OUT xid xid, OUT data text)
1243 RETURNS SETOF RECORD
1245 VOLATILE ROWS 1000 COST 1000
1246 AS 'pg_logical_slot_peek_changes';
1248 CREATE OR REPLACE FUNCTION pg_logical_slot_get_binary_changes(
1249 IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
1250 OUT lsn pg_lsn, OUT xid xid, OUT data bytea)
1251 RETURNS SETOF RECORD
1253 VOLATILE ROWS 1000 COST 1000
1254 AS 'pg_logical_slot_get_binary_changes';
1256 CREATE OR REPLACE FUNCTION pg_logical_slot_peek_binary_changes(
1257 IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
1258 OUT lsn pg_lsn, OUT xid xid, OUT data bytea)
1259 RETURNS SETOF RECORD
1261 VOLATILE ROWS 1000 COST 1000
1262 AS 'pg_logical_slot_peek_binary_changes';
1264 CREATE OR REPLACE FUNCTION pg_create_physical_replication_slot(
1265 IN slot_name name, IN immediately_reserve boolean DEFAULT false,
1266 IN temporary boolean DEFAULT false,
1267 OUT slot_name name, OUT lsn pg_lsn)
1271 AS 'pg_create_physical_replication_slot';
1273 CREATE OR REPLACE FUNCTION pg_create_logical_replication_slot(
1274 IN slot_name name, IN plugin name,
1275 IN temporary boolean DEFAULT false,
1276 OUT slot_name name, OUT lsn pg_lsn)
1280 AS 'pg_create_logical_replication_slot';
1282 CREATE OR REPLACE FUNCTION
1283 make_interval(years int4 DEFAULT 0, months int4 DEFAULT 0, weeks int4 DEFAULT 0,
1284 days int4 DEFAULT 0, hours int4 DEFAULT 0, mins int4 DEFAULT 0,
1285 secs double precision DEFAULT 0.0)
1288 STRICT IMMUTABLE PARALLEL SAFE
1291 CREATE OR REPLACE FUNCTION
1292 jsonb_set(jsonb_in jsonb, path text[] , replacement jsonb,
1293 create_if_missing boolean DEFAULT true)
1296 STRICT IMMUTABLE PARALLEL SAFE
1299 CREATE OR REPLACE FUNCTION
1300 jsonb_set_lax(jsonb_in jsonb, path text[] , replacement jsonb,
1301 create_if_missing boolean DEFAULT true,
1302 null_value_treatment text DEFAULT 'use_json_null')
1305 CALLED ON NULL INPUT IMMUTABLE PARALLEL SAFE
1308 CREATE OR REPLACE FUNCTION
1309 parse_ident(str text, strict boolean DEFAULT true)
1312 STRICT IMMUTABLE PARALLEL SAFE
1315 CREATE OR REPLACE FUNCTION
1316 jsonb_insert(jsonb_in jsonb, path text[] , replacement jsonb,
1317 insert_after boolean DEFAULT false)
1320 STRICT IMMUTABLE PARALLEL SAFE
1323 CREATE OR REPLACE FUNCTION
1324 jsonb_path_exists(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1325 silent boolean DEFAULT false)
1328 STRICT IMMUTABLE PARALLEL SAFE
1329 AS 'jsonb_path_exists';
1331 CREATE OR REPLACE FUNCTION
1332 jsonb_path_match(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1333 silent boolean DEFAULT false)
1336 STRICT IMMUTABLE PARALLEL SAFE
1337 AS 'jsonb_path_match';
1339 CREATE OR REPLACE FUNCTION
1340 jsonb_path_query(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1341 silent boolean DEFAULT false)
1344 STRICT IMMUTABLE PARALLEL SAFE
1345 AS 'jsonb_path_query';
1347 CREATE OR REPLACE FUNCTION
1348 jsonb_path_query_array(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1349 silent boolean DEFAULT false)
1352 STRICT IMMUTABLE PARALLEL SAFE
1353 AS 'jsonb_path_query_array';
1355 CREATE OR REPLACE FUNCTION
1356 jsonb_path_query_first(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1357 silent boolean DEFAULT false)
1360 STRICT IMMUTABLE PARALLEL SAFE
1361 AS 'jsonb_path_query_first';
1363 CREATE OR REPLACE FUNCTION
1364 jsonb_path_exists_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1365 silent boolean DEFAULT false)
1368 STRICT STABLE PARALLEL SAFE
1369 AS 'jsonb_path_exists_tz';
1371 CREATE OR REPLACE FUNCTION
1372 jsonb_path_match_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1373 silent boolean DEFAULT false)
1376 STRICT STABLE PARALLEL SAFE
1377 AS 'jsonb_path_match_tz';
1379 CREATE OR REPLACE FUNCTION
1380 jsonb_path_query_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1381 silent boolean DEFAULT false)
1384 STRICT STABLE PARALLEL SAFE
1385 AS 'jsonb_path_query_tz';
1387 CREATE OR REPLACE FUNCTION
1388 jsonb_path_query_array_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1389 silent boolean DEFAULT false)
1392 STRICT STABLE PARALLEL SAFE
1393 AS 'jsonb_path_query_array_tz';
1395 CREATE OR REPLACE FUNCTION
1396 jsonb_path_query_first_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
1397 silent boolean DEFAULT false)
1400 STRICT STABLE PARALLEL SAFE
1401 AS 'jsonb_path_query_first_tz';
1403 -- default normalization form is NFC, per SQL standard
1404 CREATE OR REPLACE FUNCTION
1405 "normalize"(text, text DEFAULT 'NFC')
1408 STRICT IMMUTABLE PARALLEL SAFE
1409 AS 'unicode_normalize_func';
1411 CREATE OR REPLACE FUNCTION
1412 is_normalized(text, text DEFAULT 'NFC')
1415 STRICT IMMUTABLE PARALLEL SAFE
1416 AS 'unicode_is_normalized';
1419 -- The default permissions for functions mean that anyone can execute them.
1420 -- A number of functions shouldn't be executable by just anyone, but rather
1421 -- than use explicit 'superuser()' checks in those functions, we use the GRANT
1422 -- system to REVOKE access to those functions at initdb time. Administrators
1423 -- can later change who can access these functions, or leave them as only
1424 -- available to superuser / cluster owner, if they choose.
1426 REVOKE EXECUTE ON FUNCTION pg_start_backup(text, boolean, boolean) FROM public;
1427 REVOKE EXECUTE ON FUNCTION pg_stop_backup() FROM public;
1428 REVOKE EXECUTE ON FUNCTION pg_stop_backup(boolean, boolean) FROM public;
1429 REVOKE EXECUTE ON FUNCTION pg_create_restore_point(text) FROM public;
1430 REVOKE EXECUTE ON FUNCTION pg_switch_wal() FROM public;
1431 REVOKE EXECUTE ON FUNCTION pg_wal_replay_pause() FROM public;
1432 REVOKE EXECUTE ON FUNCTION pg_wal_replay_resume() FROM public;
1433 REVOKE EXECUTE ON FUNCTION pg_rotate_logfile() FROM public;
1434 REVOKE EXECUTE ON FUNCTION pg_reload_conf() FROM public;
1435 REVOKE EXECUTE ON FUNCTION pg_current_logfile() FROM public;
1436 REVOKE EXECUTE ON FUNCTION pg_current_logfile(text) FROM public;
1437 REVOKE EXECUTE ON FUNCTION pg_promote(boolean, integer) FROM public;
1439 REVOKE EXECUTE ON FUNCTION pg_stat_reset() FROM public;
1440 REVOKE EXECUTE ON FUNCTION pg_stat_reset_shared(text) FROM public;
1441 REVOKE EXECUTE ON FUNCTION pg_stat_reset_slru(text) FROM public;
1442 REVOKE EXECUTE ON FUNCTION pg_stat_reset_single_table_counters(oid) FROM public;
1443 REVOKE EXECUTE ON FUNCTION pg_stat_reset_single_function_counters(oid) FROM public;
1445 REVOKE EXECUTE ON FUNCTION lo_import(text) FROM public;
1446 REVOKE EXECUTE ON FUNCTION lo_import(text, oid) FROM public;
1447 REVOKE EXECUTE ON FUNCTION lo_export(oid, text) FROM public;
1449 REVOKE EXECUTE ON FUNCTION pg_ls_logdir() FROM public;
1450 REVOKE EXECUTE ON FUNCTION pg_ls_waldir() FROM public;
1451 REVOKE EXECUTE ON FUNCTION pg_ls_archive_statusdir() FROM public;
1452 REVOKE EXECUTE ON FUNCTION pg_ls_tmpdir() FROM public;
1453 REVOKE EXECUTE ON FUNCTION pg_ls_tmpdir(oid) FROM public;
1455 REVOKE EXECUTE ON FUNCTION pg_read_file(text) FROM public;
1456 REVOKE EXECUTE ON FUNCTION pg_read_file(text,bigint,bigint) FROM public;
1457 REVOKE EXECUTE ON FUNCTION pg_read_file(text,bigint,bigint,boolean) FROM public;
1459 REVOKE EXECUTE ON FUNCTION pg_read_binary_file(text) FROM public;
1460 REVOKE EXECUTE ON FUNCTION pg_read_binary_file(text,bigint,bigint) FROM public;
1461 REVOKE EXECUTE ON FUNCTION pg_read_binary_file(text,bigint,bigint,boolean) FROM public;
1463 REVOKE EXECUTE ON FUNCTION pg_replication_origin_advance(text, pg_lsn) FROM public;
1464 REVOKE EXECUTE ON FUNCTION pg_replication_origin_create(text) FROM public;
1465 REVOKE EXECUTE ON FUNCTION pg_replication_origin_drop(text) FROM public;
1466 REVOKE EXECUTE ON FUNCTION pg_replication_origin_oid(text) FROM public;
1467 REVOKE EXECUTE ON FUNCTION pg_replication_origin_progress(text, boolean) FROM public;
1468 REVOKE EXECUTE ON FUNCTION pg_replication_origin_session_is_setup() FROM public;
1469 REVOKE EXECUTE ON FUNCTION pg_replication_origin_session_progress(boolean) FROM public;
1470 REVOKE EXECUTE ON FUNCTION pg_replication_origin_session_reset() FROM public;
1471 REVOKE EXECUTE ON FUNCTION pg_replication_origin_session_setup(text) FROM public;
1472 REVOKE EXECUTE ON FUNCTION pg_replication_origin_xact_reset() FROM public;
1473 REVOKE EXECUTE ON FUNCTION pg_replication_origin_xact_setup(pg_lsn, timestamp with time zone) FROM public;
1474 REVOKE EXECUTE ON FUNCTION pg_show_replication_origin_status() FROM public;
1476 REVOKE EXECUTE ON FUNCTION pg_stat_file(text) FROM public;
1477 REVOKE EXECUTE ON FUNCTION pg_stat_file(text,boolean) FROM public;
1479 REVOKE EXECUTE ON FUNCTION pg_ls_dir(text) FROM public;
1480 REVOKE EXECUTE ON FUNCTION pg_ls_dir(text,boolean,boolean) FROM public;
1483 -- We also set up some things as accessible to standard roles.
1485 GRANT EXECUTE ON FUNCTION pg_ls_logdir() TO pg_monitor;
1486 GRANT EXECUTE ON FUNCTION pg_ls_waldir() TO pg_monitor;
1487 GRANT EXECUTE ON FUNCTION pg_ls_archive_statusdir() TO pg_monitor;
1488 GRANT EXECUTE ON FUNCTION pg_ls_tmpdir() TO pg_monitor;
1489 GRANT EXECUTE ON FUNCTION pg_ls_tmpdir(oid) TO pg_monitor;
1491 GRANT pg_read_all_settings TO pg_monitor;
1492 GRANT pg_read_all_stats TO pg_monitor;
1493 GRANT pg_stat_scan_tables TO pg_monitor;