system_views.sql 33.8 KB
Newer Older
1 2 3
/*
 * PostgreSQL System Views
 *
B
Bruce Momjian 已提交
4
 * Copyright (c) 1996-2016, PostgreSQL Global Development Group
5
 *
6
 * src/backend/catalog/system_views.sql
7 8 9 10 11 12 13 14
 *
 * Note: this file is read in single-user -j mode, which means that the
 * command terminator is semicolon-newline-newline; whenever the backend
 * sees that, it stops and executes what it's got.  If you write a lot of
 * statements without empty lines between, they'll all get quoted to you
 * in any error message about one of them, so don't do that.  Also, you
 * cannot write a semicolon immediately followed by an empty line in a
 * string literal (including a function body!) or a multiline comment.
15 16
 */

17 18
CREATE VIEW pg_roles AS
    SELECT
19
        rolname,
20 21 22 23 24 25
        rolsuper,
        rolinherit,
        rolcreaterole,
        rolcreatedb,
        rolcanlogin,
        rolreplication,
26
        rolconnlimit,
27 28
        '********'::text as rolpassword,
        rolvaliduntil,
29
        rolbypassrls,
30 31 32 33
        setconfig as rolconfig,
        pg_authid.oid
    FROM pg_authid LEFT JOIN pg_db_role_setting s
    ON (pg_authid.oid = setrole AND setdatabase = 0);
34 35 36 37

CREATE VIEW pg_shadow AS
    SELECT
        rolname AS usename,
38
        pg_authid.oid AS usesysid,
39 40 41
        rolcreatedb AS usecreatedb,
        rolsuper AS usesuper,
        rolreplication AS userepl,
42
        rolbypassrls AS usebypassrls,
43 44
        rolpassword AS passwd,
        rolvaliduntil::abstime AS valuntil,
45 46 47
        setconfig AS useconfig
    FROM pg_authid LEFT JOIN pg_db_role_setting s
    ON (pg_authid.oid = setrole AND setdatabase = 0)
48
    WHERE rolcanlogin;
49 50 51 52 53 54 55 56 57

REVOKE ALL on pg_shadow FROM public;

CREATE VIEW pg_group AS
    SELECT
        rolname AS groname,
        oid AS grosysid,
        ARRAY(SELECT member FROM pg_auth_members WHERE roleid = oid) AS grolist
    FROM pg_authid
58
    WHERE NOT rolcanlogin;
59

60 61 62 63 64 65
CREATE VIEW pg_user AS
    SELECT
        usename,
        usesysid,
        usecreatedb,
        usesuper,
66
        userepl,
67
        usebypassrls,
68 69 70
        '********'::text as passwd,
        valuntil,
        useconfig
71 72
    FROM pg_shadow;

73 74
CREATE VIEW pg_policies AS
    SELECT
75 76
        N.nspname AS schemaname,
        C.relname AS tablename,
77
        pol.polname AS policyname,
78
        CASE
79
            WHEN pol.polroles = '{0}' THEN
80 81 82 83 84 85
                string_to_array('public', '')
            ELSE
                ARRAY
                (
                    SELECT rolname
                    FROM pg_catalog.pg_authid
86
                    WHERE oid = ANY (pol.polroles) ORDER BY 1
87 88
                )
        END AS roles,
89 90 91 92 93 94
        CASE pol.polcmd
            WHEN 'r' THEN 'SELECT'
            WHEN 'a' THEN 'INSERT'
            WHEN 'w' THEN 'UPDATE'
            WHEN 'd' THEN 'DELETE'
            WHEN '*' THEN 'ALL'
95
        END AS cmd,
96 97 98 99
        pg_catalog.pg_get_expr(pol.polqual, pol.polrelid) AS qual,
        pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid) AS with_check
    FROM pg_catalog.pg_policy pol
    JOIN pg_catalog.pg_class C ON (C.oid = pol.polrelid)
100
    LEFT JOIN pg_catalog.pg_namespace N ON (N.oid = C.relnamespace);
101

102 103 104 105 106 107 108 109
CREATE VIEW pg_rules AS
    SELECT
        N.nspname AS schemaname,
        C.relname AS tablename,
        R.rulename AS rulename,
        pg_get_ruledef(R.oid) AS definition
    FROM (pg_rewrite R JOIN pg_class C ON (C.oid = R.ev_class))
        LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
110 111
    WHERE R.rulename != '_RETURN';

112 113 114 115 116 117 118
CREATE VIEW pg_views AS
    SELECT
        N.nspname AS schemaname,
        C.relname AS viewname,
        pg_get_userbyid(C.relowner) AS viewowner,
        pg_get_viewdef(C.oid) AS definition
    FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
119 120
    WHERE C.relkind = 'v';

121 122 123 124 125
CREATE VIEW pg_tables AS
    SELECT
        N.nspname AS schemaname,
        C.relname AS tablename,
        pg_get_userbyid(C.relowner) AS tableowner,
126
        T.spcname AS tablespace,
127 128
        C.relhasindex AS hasindexes,
        C.relhasrules AS hasrules,
129
        C.relhastriggers AS hastriggers,
S
Stephen Frost 已提交
130
        C.relrowsecurity AS rowsecurity
131
    FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
132
         LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
133 134
    WHERE C.relkind = 'r';

135 136 137 138 139 140 141
CREATE VIEW pg_matviews AS
    SELECT
        N.nspname AS schemaname,
        C.relname AS matviewname,
        pg_get_userbyid(C.relowner) AS matviewowner,
        T.spcname AS tablespace,
        C.relhasindex AS hasindexes,
142
        C.relispopulated AS ispopulated,
143 144 145 146 147
        pg_get_viewdef(C.oid) AS definition
    FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
         LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
    WHERE C.relkind = 'm';

148 149 150 151 152
CREATE VIEW pg_indexes AS
    SELECT
        N.nspname AS schemaname,
        C.relname AS tablename,
        I.relname AS indexname,
153
        T.spcname AS tablespace,
154 155 156 157
        pg_get_indexdef(I.oid) AS indexdef
    FROM pg_index X JOIN pg_class C ON (C.oid = X.indrelid)
         JOIN pg_class I ON (I.oid = X.indexrelid)
         LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
158
         LEFT JOIN pg_tablespace T ON (T.oid = I.reltablespace)
159
    WHERE C.relkind IN ('r', 'm') AND I.relkind = 'i';
160

161
CREATE VIEW pg_stats WITH (security_barrier) AS
162 163 164 165 166 167 168 169
    SELECT
        nspname AS schemaname,
        relname AS tablename,
        attname AS attname,
        stainherit AS inherited,
        stanullfrac AS null_frac,
        stawidth AS avg_width,
        stadistinct AS n_distinct,
170
        CASE
171 172 173 174 175
            WHEN stakind1 = 1 THEN stavalues1
            WHEN stakind2 = 1 THEN stavalues2
            WHEN stakind3 = 1 THEN stavalues3
            WHEN stakind4 = 1 THEN stavalues4
            WHEN stakind5 = 1 THEN stavalues5
176 177
        END AS most_common_vals,
        CASE
178 179 180 181 182
            WHEN stakind1 = 1 THEN stanumbers1
            WHEN stakind2 = 1 THEN stanumbers2
            WHEN stakind3 = 1 THEN stanumbers3
            WHEN stakind4 = 1 THEN stanumbers4
            WHEN stakind5 = 1 THEN stanumbers5
183 184 185 186 187 188
        END AS most_common_freqs,
        CASE
            WHEN stakind1 = 2 THEN stavalues1
            WHEN stakind2 = 2 THEN stavalues2
            WHEN stakind3 = 2 THEN stavalues3
            WHEN stakind4 = 2 THEN stavalues4
189
            WHEN stakind5 = 2 THEN stavalues5
190 191 192 193 194 195
        END AS histogram_bounds,
        CASE
            WHEN stakind1 = 3 THEN stanumbers1[1]
            WHEN stakind2 = 3 THEN stanumbers2[1]
            WHEN stakind3 = 3 THEN stanumbers3[1]
            WHEN stakind4 = 3 THEN stanumbers4[1]
196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218
            WHEN stakind5 = 3 THEN stanumbers5[1]
        END AS correlation,
        CASE
            WHEN stakind1 = 4 THEN stavalues1
            WHEN stakind2 = 4 THEN stavalues2
            WHEN stakind3 = 4 THEN stavalues3
            WHEN stakind4 = 4 THEN stavalues4
            WHEN stakind5 = 4 THEN stavalues5
        END AS most_common_elems,
        CASE
            WHEN stakind1 = 4 THEN stanumbers1
            WHEN stakind2 = 4 THEN stanumbers2
            WHEN stakind3 = 4 THEN stanumbers3
            WHEN stakind4 = 4 THEN stanumbers4
            WHEN stakind5 = 4 THEN stanumbers5
        END AS most_common_elem_freqs,
        CASE
            WHEN stakind1 = 5 THEN stanumbers1
            WHEN stakind2 = 5 THEN stanumbers2
            WHEN stakind3 = 5 THEN stanumbers3
            WHEN stakind4 = 5 THEN stanumbers4
            WHEN stakind5 = 5 THEN stanumbers5
        END AS elem_count_histogram
219 220 221
    FROM pg_statistic s JOIN pg_class c ON (c.oid = s.starelid)
         JOIN pg_attribute a ON (c.oid = attrelid AND attnum = s.staattnum)
         LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace)
222 223 224
    WHERE NOT attisdropped
    AND has_column_privilege(c.oid, a.attnum, 'select')
    AND (c.relrowsecurity = false OR NOT row_security_active(c.oid));
225 226 227

REVOKE ALL on pg_statistic FROM public;

228
CREATE VIEW pg_locks AS
229
    SELECT * FROM pg_lock_status() AS L;
230

231
CREATE VIEW pg_cursors AS
232
    SELECT * FROM pg_cursor() AS C;
233

234
CREATE VIEW pg_available_extensions AS
235 236
    SELECT E.name, E.default_version, X.extversion AS installed_version,
           E.comment
237
      FROM pg_available_extensions() AS E
238 239 240 241
           LEFT JOIN pg_extension AS X ON E.name = X.extname;

CREATE VIEW pg_available_extension_versions AS
    SELECT E.name, E.version, (X.extname IS NOT NULL) AS installed,
242
           E.superuser, E.relocatable, E.schema, E.requires, E.comment
243 244 245
      FROM pg_available_extension_versions() AS E
           LEFT JOIN pg_extension AS X
             ON E.name = X.extname AND E.version = X.extversion;
246

247
CREATE VIEW pg_prepared_xacts AS
248
    SELECT P.transaction, P.gid, P.prepared,
249
           U.rolname AS owner, D.datname AS database
250
    FROM pg_prepared_xact() AS P
251
         LEFT JOIN pg_authid U ON P.ownerid = U.oid
252
         LEFT JOIN pg_database D ON P.dbid = D.oid;
253

254
CREATE VIEW pg_prepared_statements AS
255
    SELECT * FROM pg_prepared_statement() AS P;
256

R
Robert Haas 已提交
257 258 259 260
CREATE VIEW pg_seclabels AS
SELECT
	l.objoid, l.classoid, l.objsubid,
	CASE WHEN rel.relkind = 'r' THEN 'table'::text
R
Robert Haas 已提交
261
		 WHEN rel.relkind = 'v' THEN 'view'::text
262
		 WHEN rel.relkind = 'm' THEN 'materialized view'::text
R
Robert Haas 已提交
263 264
		 WHEN rel.relkind = 'S' THEN 'sequence'::text
		 WHEN rel.relkind = 'f' THEN 'foreign table'::text END AS objtype,
R
Robert Haas 已提交
265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364
	rel.relnamespace AS objnamespace,
	CASE WHEN pg_table_is_visible(rel.oid)
	     THEN quote_ident(rel.relname)
	     ELSE quote_ident(nsp.nspname) || '.' || quote_ident(rel.relname)
	     END AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_class rel ON l.classoid = rel.tableoid AND l.objoid = rel.oid
	JOIN pg_namespace nsp ON rel.relnamespace = nsp.oid
WHERE
	l.objsubid = 0
UNION ALL
SELECT
	l.objoid, l.classoid, l.objsubid,
	'column'::text AS objtype,
	rel.relnamespace AS objnamespace,
	CASE WHEN pg_table_is_visible(rel.oid)
	     THEN quote_ident(rel.relname)
	     ELSE quote_ident(nsp.nspname) || '.' || quote_ident(rel.relname)
	     END || '.' || att.attname AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_class rel ON l.classoid = rel.tableoid AND l.objoid = rel.oid
	JOIN pg_attribute att
	     ON rel.oid = att.attrelid AND l.objsubid = att.attnum
	JOIN pg_namespace nsp ON rel.relnamespace = nsp.oid
WHERE
	l.objsubid != 0
UNION ALL
SELECT
	l.objoid, l.classoid, l.objsubid,
	CASE WHEN pro.proisagg = true THEN 'aggregate'::text
	     WHEN pro.proisagg = false THEN 'function'::text
	END AS objtype,
	pro.pronamespace AS objnamespace,
	CASE WHEN pg_function_is_visible(pro.oid)
	     THEN quote_ident(pro.proname)
	     ELSE quote_ident(nsp.nspname) || '.' || quote_ident(pro.proname)
	END || '(' || pg_catalog.pg_get_function_arguments(pro.oid) || ')' AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_proc pro ON l.classoid = pro.tableoid AND l.objoid = pro.oid
	JOIN pg_namespace nsp ON pro.pronamespace = nsp.oid
WHERE
	l.objsubid = 0
UNION ALL
SELECT
	l.objoid, l.classoid, l.objsubid,
	CASE WHEN typ.typtype = 'd' THEN 'domain'::text
	ELSE 'type'::text END AS objtype,
	typ.typnamespace AS objnamespace,
	CASE WHEN pg_type_is_visible(typ.oid)
	THEN quote_ident(typ.typname)
	ELSE quote_ident(nsp.nspname) || '.' || quote_ident(typ.typname)
	END AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_type typ ON l.classoid = typ.tableoid AND l.objoid = typ.oid
	JOIN pg_namespace nsp ON typ.typnamespace = nsp.oid
WHERE
	l.objsubid = 0
UNION ALL
SELECT
	l.objoid, l.classoid, l.objsubid,
	'large object'::text AS objtype,
	NULL::oid AS objnamespace,
	l.objoid::text AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_largeobject_metadata lom ON l.objoid = lom.oid
WHERE
	l.classoid = 'pg_catalog.pg_largeobject'::regclass AND l.objsubid = 0
UNION ALL
SELECT
	l.objoid, l.classoid, l.objsubid,
	'language'::text AS objtype,
	NULL::oid AS objnamespace,
	quote_ident(lan.lanname) AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_language lan ON l.classoid = lan.tableoid AND l.objoid = lan.oid
WHERE
	l.objsubid = 0
UNION ALL
SELECT
	l.objoid, l.classoid, l.objsubid,
	'schema'::text AS objtype,
	nsp.oid AS objnamespace,
	quote_ident(nsp.nspname) AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_namespace nsp ON l.classoid = nsp.tableoid AND l.objoid = nsp.oid
WHERE
365 366
	l.objsubid = 0
UNION ALL
367 368 369 370 371 372 373 374 375 376 377 378 379
SELECT
	l.objoid, l.classoid, l.objsubid,
	'event trigger'::text AS objtype,
	NULL::oid AS objnamespace,
	quote_ident(evt.evtname) AS objname,
	l.provider, l.label
FROM
	pg_seclabel l
	JOIN pg_event_trigger evt ON l.classoid = evt.tableoid
		AND l.objoid = evt.oid
WHERE
	l.objsubid = 0
UNION ALL
380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408
SELECT
	l.objoid, l.classoid, 0::int4 AS objsubid,
	'database'::text AS objtype,
	NULL::oid AS objnamespace,
	quote_ident(dat.datname) AS objname,
	l.provider, l.label
FROM
	pg_shseclabel l
	JOIN pg_database dat ON l.classoid = dat.tableoid AND l.objoid = dat.oid
UNION ALL
SELECT
	l.objoid, l.classoid, 0::int4 AS objsubid,
	'tablespace'::text AS objtype,
	NULL::oid AS objnamespace,
	quote_ident(spc.spcname) AS objname,
	l.provider, l.label
FROM
	pg_shseclabel l
	JOIN pg_tablespace spc ON l.classoid = spc.tableoid AND l.objoid = spc.oid
UNION ALL
SELECT
	l.objoid, l.classoid, 0::int4 AS objsubid,
	'role'::text AS objtype,
	NULL::oid AS objnamespace,
	quote_ident(rol.rolname) AS objname,
	l.provider, l.label
FROM
	pg_shseclabel l
	JOIN pg_authid rol ON l.classoid = rol.tableoid AND l.objoid = rol.oid;
R
Robert Haas 已提交
409

410 411
CREATE VIEW pg_settings AS
    SELECT * FROM pg_show_all_settings() AS A;
412

413 414 415
CREATE RULE pg_settings_u AS
    ON UPDATE TO pg_settings
    WHERE new.name = old.name DO
416 417
    SELECT set_config(old.name, new.setting, 'f');

418 419
CREATE RULE pg_settings_n AS
    ON UPDATE TO pg_settings
420 421 422 423
    DO INSTEAD NOTHING;

GRANT SELECT, UPDATE ON pg_settings TO PUBLIC;

424 425 426 427 428 429
CREATE VIEW pg_file_settings AS
   SELECT * FROM pg_show_all_file_settings() AS A;

REVOKE ALL on pg_file_settings FROM PUBLIC;
REVOKE EXECUTE ON FUNCTION pg_show_all_file_settings() FROM PUBLIC;

430 431 432 433 434
CREATE VIEW pg_timezone_abbrevs AS
    SELECT * FROM pg_timezone_abbrevs();

CREATE VIEW pg_timezone_names AS
    SELECT * FROM pg_timezone_names();
435

J
Joe Conway 已提交
436 437 438 439 440 441
CREATE VIEW pg_config AS
    SELECT * FROM pg_config();

REVOKE ALL on pg_config FROM PUBLIC;
REVOKE EXECUTE ON FUNCTION pg_config() FROM PUBLIC;

442 443
-- Statistics views

444 445 446 447 448 449 450 451
CREATE VIEW pg_stat_all_tables AS
    SELECT
            C.oid AS relid,
            N.nspname AS schemaname,
            C.relname AS relname,
            pg_stat_get_numscans(C.oid) AS seq_scan,
            pg_stat_get_tuples_returned(C.oid) AS seq_tup_read,
            sum(pg_stat_get_numscans(I.indexrelid))::bigint AS idx_scan,
452
            sum(pg_stat_get_tuples_fetched(I.indexrelid))::bigint +
453 454 455
            pg_stat_get_tuples_fetched(C.oid) AS idx_tup_fetch,
            pg_stat_get_tuples_inserted(C.oid) AS n_tup_ins,
            pg_stat_get_tuples_updated(C.oid) AS n_tup_upd,
456
            pg_stat_get_tuples_deleted(C.oid) AS n_tup_del,
457
            pg_stat_get_tuples_hot_updated(C.oid) AS n_tup_hot_upd,
458
            pg_stat_get_live_tuples(C.oid) AS n_live_tup,
459
            pg_stat_get_dead_tuples(C.oid) AS n_dead_tup,
460
            pg_stat_get_mod_since_analyze(C.oid) AS n_mod_since_analyze,
461 462 463
            pg_stat_get_last_vacuum_time(C.oid) as last_vacuum,
            pg_stat_get_last_autovacuum_time(C.oid) as last_autovacuum,
            pg_stat_get_last_analyze_time(C.oid) as last_analyze,
464 465 466 467 468
            pg_stat_get_last_autoanalyze_time(C.oid) as last_autoanalyze,
            pg_stat_get_vacuum_count(C.oid) AS vacuum_count,
            pg_stat_get_autovacuum_count(C.oid) AS autovacuum_count,
            pg_stat_get_analyze_count(C.oid) AS analyze_count,
            pg_stat_get_autoanalyze_count(C.oid) AS autoanalyze_count
469 470 471
    FROM pg_class C LEFT JOIN
         pg_index I ON C.oid = I.indrelid
         LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
472
    WHERE C.relkind IN ('r', 't', 'm')
473 474
    GROUP BY C.oid, N.nspname, C.relname;

475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491
CREATE VIEW pg_stat_xact_all_tables AS
    SELECT
            C.oid AS relid,
            N.nspname AS schemaname,
            C.relname AS relname,
            pg_stat_get_xact_numscans(C.oid) AS seq_scan,
            pg_stat_get_xact_tuples_returned(C.oid) AS seq_tup_read,
            sum(pg_stat_get_xact_numscans(I.indexrelid))::bigint AS idx_scan,
            sum(pg_stat_get_xact_tuples_fetched(I.indexrelid))::bigint +
            pg_stat_get_xact_tuples_fetched(C.oid) AS idx_tup_fetch,
            pg_stat_get_xact_tuples_inserted(C.oid) AS n_tup_ins,
            pg_stat_get_xact_tuples_updated(C.oid) AS n_tup_upd,
            pg_stat_get_xact_tuples_deleted(C.oid) AS n_tup_del,
            pg_stat_get_xact_tuples_hot_updated(C.oid) AS n_tup_hot_upd
    FROM pg_class C LEFT JOIN
         pg_index I ON C.oid = I.indrelid
         LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
492
    WHERE C.relkind IN ('r', 't', 'm')
493 494
    GROUP BY C.oid, N.nspname, C.relname;

495 496
CREATE VIEW pg_stat_sys_tables AS
    SELECT * FROM pg_stat_all_tables
497 498
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
499

500 501 502 503 504
CREATE VIEW pg_stat_xact_sys_tables AS
    SELECT * FROM pg_stat_xact_all_tables
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';

505 506
CREATE VIEW pg_stat_user_tables AS
    SELECT * FROM pg_stat_all_tables
507 508
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
509

510 511 512 513 514
CREATE VIEW pg_stat_xact_user_tables AS
    SELECT * FROM pg_stat_xact_all_tables
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';

515 516 517 518 519 520 521 522 523 524 525 526 527 528
CREATE VIEW pg_statio_all_tables AS
    SELECT
            C.oid AS relid,
            N.nspname AS schemaname,
            C.relname AS relname,
            pg_stat_get_blocks_fetched(C.oid) -
                    pg_stat_get_blocks_hit(C.oid) AS heap_blks_read,
            pg_stat_get_blocks_hit(C.oid) AS heap_blks_hit,
            sum(pg_stat_get_blocks_fetched(I.indexrelid) -
                    pg_stat_get_blocks_hit(I.indexrelid))::bigint AS idx_blks_read,
            sum(pg_stat_get_blocks_hit(I.indexrelid))::bigint AS idx_blks_hit,
            pg_stat_get_blocks_fetched(T.oid) -
                    pg_stat_get_blocks_hit(T.oid) AS toast_blks_read,
            pg_stat_get_blocks_hit(T.oid) AS toast_blks_hit,
F
Fujii Masao 已提交
529 530 531
            sum(pg_stat_get_blocks_fetched(X.indexrelid) -
                    pg_stat_get_blocks_hit(X.indexrelid))::bigint AS tidx_blks_read,
            sum(pg_stat_get_blocks_hit(X.indexrelid))::bigint AS tidx_blks_hit
532 533 534
    FROM pg_class C LEFT JOIN
            pg_index I ON C.oid = I.indrelid LEFT JOIN
            pg_class T ON C.reltoastrelid = T.oid LEFT JOIN
F
Fujii Masao 已提交
535
            pg_index X ON T.oid = X.indrelid
536
            LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
537
    WHERE C.relkind IN ('r', 't', 'm')
F
Fujii Masao 已提交
538
    GROUP BY C.oid, N.nspname, C.relname, T.oid, X.indrelid;
539

540 541
CREATE VIEW pg_statio_sys_tables AS
    SELECT * FROM pg_statio_all_tables
542 543
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
544

545 546
CREATE VIEW pg_statio_user_tables AS
    SELECT * FROM pg_statio_all_tables
547 548
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
549

550 551 552 553 554 555 556 557 558 559 560 561 562 563
CREATE VIEW pg_stat_all_indexes AS
    SELECT
            C.oid AS relid,
            I.oid AS indexrelid,
            N.nspname AS schemaname,
            C.relname AS relname,
            I.relname AS indexrelname,
            pg_stat_get_numscans(I.oid) AS idx_scan,
            pg_stat_get_tuples_returned(I.oid) AS idx_tup_read,
            pg_stat_get_tuples_fetched(I.oid) AS idx_tup_fetch
    FROM pg_class C JOIN
            pg_index X ON C.oid = X.indrelid JOIN
            pg_class I ON I.oid = X.indexrelid
            LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
564
    WHERE C.relkind IN ('r', 't', 'm');
565

566 567
CREATE VIEW pg_stat_sys_indexes AS
    SELECT * FROM pg_stat_all_indexes
568 569
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
570

571 572
CREATE VIEW pg_stat_user_indexes AS
    SELECT * FROM pg_stat_all_indexes
573 574
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
575

576 577 578 579 580 581 582 583 584 585 586 587 588 589
CREATE VIEW pg_statio_all_indexes AS
    SELECT
            C.oid AS relid,
            I.oid AS indexrelid,
            N.nspname AS schemaname,
            C.relname AS relname,
            I.relname AS indexrelname,
            pg_stat_get_blocks_fetched(I.oid) -
                    pg_stat_get_blocks_hit(I.oid) AS idx_blks_read,
            pg_stat_get_blocks_hit(I.oid) AS idx_blks_hit
    FROM pg_class C JOIN
            pg_index X ON C.oid = X.indrelid JOIN
            pg_class I ON I.oid = X.indexrelid
            LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
590
    WHERE C.relkind IN ('r', 't', 'm');
591

592 593
CREATE VIEW pg_statio_sys_indexes AS
    SELECT * FROM pg_statio_all_indexes
594 595
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
596

597 598
CREATE VIEW pg_statio_user_indexes AS
    SELECT * FROM pg_statio_all_indexes
599 600
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
601

602 603 604 605 606 607 608 609 610 611
CREATE VIEW pg_statio_all_sequences AS
    SELECT
            C.oid AS relid,
            N.nspname AS schemaname,
            C.relname AS relname,
            pg_stat_get_blocks_fetched(C.oid) -
                    pg_stat_get_blocks_hit(C.oid) AS blks_read,
            pg_stat_get_blocks_hit(C.oid) AS blks_hit
    FROM pg_class C
            LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
612 613
    WHERE C.relkind = 'S';

614 615
CREATE VIEW pg_statio_sys_sequences AS
    SELECT * FROM pg_statio_all_sequences
616 617
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
618

619 620
CREATE VIEW pg_statio_user_sequences AS
    SELECT * FROM pg_statio_all_sequences
621 622
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
623

624 625
CREATE VIEW pg_stat_activity AS
    SELECT
626 627
            S.datid AS datid,
            D.datname AS datname,
628
            S.pid,
629 630
            S.usesysid,
            U.rolname AS usename,
631
            S.application_name,
632
            S.client_addr,
633
            S.client_hostname,
634 635
            S.client_port,
            S.backend_start,
636 637
            S.xact_start,
            S.query_start,
638
            S.state_change,
639
            S.waiting,
640
            S.state,
641 642
            S.backend_xid,
            s.backend_xmin,
643
            S.query
644
    FROM pg_database D, pg_stat_get_activity(NULL) AS S, pg_authid U
645
    WHERE S.datid = D.oid AND
646
            S.usesysid = U.oid;
647

648 649
CREATE VIEW pg_stat_replication AS
    SELECT
650
            S.pid,
651 652 653 654
            S.usesysid,
            U.rolname AS usename,
            S.application_name,
            S.client_addr,
655
            S.client_hostname,
656 657
            S.client_port,
            S.backend_start,
658
            S.backend_xmin,
659
            W.state,
660 661 662
            W.sent_location,
            W.write_location,
            W.flush_location,
663 664 665
            W.replay_location,
            W.sync_priority,
            W.sync_state
666 667 668
    FROM pg_stat_get_activity(NULL) AS S, pg_authid U,
            pg_stat_get_wal_senders() AS W
    WHERE S.usesysid = U.oid AND
669
            S.pid = W.pid;
670

671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686
CREATE VIEW pg_stat_wal_receiver AS
    SELECT
            s.pid,
            s.status,
            s.receive_start_lsn,
            s.receive_start_tli,
            s.received_lsn,
            s.received_tli,
            s.last_msg_send_time,
            s.last_msg_receipt_time,
            s.latest_end_lsn,
            s.latest_end_time,
            s.slot_name
    FROM pg_stat_get_wal_receiver() s
    WHERE s.pid IS NOT NULL;

M
Magnus Hagander 已提交
687 688 689 690 691 692 693 694 695 696 697
CREATE VIEW pg_stat_ssl AS
    SELECT
            S.pid,
            S.ssl,
            S.sslversion AS version,
            S.sslcipher AS cipher,
            S.sslbits AS bits,
            S.sslcompression AS compression,
            S.sslclientdn AS clientdn
    FROM pg_stat_get_activity(NULL) AS S;

R
Robert Haas 已提交
698 699 700
CREATE VIEW pg_replication_slots AS
    SELECT
            L.slot_name,
R
Robert Haas 已提交
701
            L.plugin,
R
Robert Haas 已提交
702 703 704 705
            L.slot_type,
            L.datoid,
            D.datname AS database,
            L.active,
706
            L.active_pid,
R
Robert Haas 已提交
707
            L.xmin,
R
Robert Haas 已提交
708
            L.catalog_xmin,
709 710
            L.restart_lsn,
            L.confirmed_flush_lsn
R
Robert Haas 已提交
711 712 713
    FROM pg_get_replication_slots() AS L
            LEFT JOIN pg_database D ON (L.datoid = D.oid);

714 715 716 717 718 719 720 721 722
CREATE VIEW pg_stat_database AS
    SELECT
            D.oid AS datid,
            D.datname AS datname,
            pg_stat_get_db_numbackends(D.oid) AS numbackends,
            pg_stat_get_db_xact_commit(D.oid) AS xact_commit,
            pg_stat_get_db_xact_rollback(D.oid) AS xact_rollback,
            pg_stat_get_db_blocks_fetched(D.oid) -
                    pg_stat_get_db_blocks_hit(D.oid) AS blks_read,
723 724 725 726 727
            pg_stat_get_db_blocks_hit(D.oid) AS blks_hit,
            pg_stat_get_db_tuples_returned(D.oid) AS tup_returned,
            pg_stat_get_db_tuples_fetched(D.oid) AS tup_fetched,
            pg_stat_get_db_tuples_inserted(D.oid) AS tup_inserted,
            pg_stat_get_db_tuples_updated(D.oid) AS tup_updated,
728
            pg_stat_get_db_tuples_deleted(D.oid) AS tup_deleted,
729
            pg_stat_get_db_conflict_all(D.oid) AS conflicts,
730 731
            pg_stat_get_db_temp_files(D.oid) AS temp_files,
            pg_stat_get_db_temp_bytes(D.oid) AS temp_bytes,
732
            pg_stat_get_db_deadlocks(D.oid) AS deadlocks,
733 734
            pg_stat_get_db_blk_read_time(D.oid) AS blk_read_time,
            pg_stat_get_db_blk_write_time(D.oid) AS blk_write_time,
735
            pg_stat_get_db_stat_reset_time(D.oid) AS stats_reset
736 737 738 739 740 741 742 743 744 745 746
    FROM pg_database D;

CREATE VIEW pg_stat_database_conflicts AS
    SELECT
            D.oid AS datid,
            D.datname AS datname,
            pg_stat_get_db_conflict_tablespace(D.oid) AS confl_tablespace,
            pg_stat_get_db_conflict_lock(D.oid) AS confl_lock,
            pg_stat_get_db_conflict_snapshot(D.oid) AS confl_snapshot,
            pg_stat_get_db_conflict_bufferpin(D.oid) AS confl_bufferpin,
            pg_stat_get_db_conflict_startup_deadlock(D.oid) AS confl_deadlock
747
    FROM pg_database D;
748

749
CREATE VIEW pg_stat_user_functions AS
750
    SELECT
751
            P.oid AS funcid,
752 753 754
            N.nspname AS schemaname,
            P.proname AS funcname,
            pg_stat_get_function_calls(P.oid) AS calls,
755 756
            pg_stat_get_function_total_time(P.oid) AS total_time,
            pg_stat_get_function_self_time(P.oid) AS self_time
757
    FROM pg_proc P LEFT JOIN pg_namespace N ON (N.oid = P.pronamespace)
758
    WHERE P.prolang != 12  -- fast check to eliminate built-in functions
759 760
          AND pg_stat_get_function_calls(P.oid) IS NOT NULL;

761 762 763 764 765 766
CREATE VIEW pg_stat_xact_user_functions AS
    SELECT
            P.oid AS funcid,
            N.nspname AS schemaname,
            P.proname AS funcname,
            pg_stat_get_xact_function_calls(P.oid) AS calls,
767 768
            pg_stat_get_xact_function_total_time(P.oid) AS total_time,
            pg_stat_get_xact_function_self_time(P.oid) AS self_time
769 770 771 772
    FROM pg_proc P LEFT JOIN pg_namespace N ON (N.oid = P.pronamespace)
    WHERE P.prolang != 12  -- fast check to eliminate built-in functions
          AND pg_stat_get_xact_function_calls(P.oid) IS NOT NULL;

773 774 775 776 777 778 779 780 781 782 783
CREATE VIEW pg_stat_archiver AS
    SELECT
        s.archived_count,
        s.last_archived_wal,
        s.last_archived_time,
        s.failed_count,
        s.last_failed_wal,
        s.last_failed_time,
        s.stats_reset
    FROM pg_stat_get_archiver() s;

784
CREATE VIEW pg_stat_bgwriter AS
785 786 787
    SELECT
        pg_stat_get_bgwriter_timed_checkpoints() AS checkpoints_timed,
        pg_stat_get_bgwriter_requested_checkpoints() AS checkpoints_req,
788
        pg_stat_get_checkpoint_write_time() AS checkpoint_write_time,
R
Robert Haas 已提交
789
        pg_stat_get_checkpoint_sync_time() AS checkpoint_sync_time,
790 791
        pg_stat_get_bgwriter_buf_written_checkpoints() AS buffers_checkpoint,
        pg_stat_get_bgwriter_buf_written_clean() AS buffers_clean,
792 793
        pg_stat_get_bgwriter_maxwritten_clean() AS maxwritten_clean,
        pg_stat_get_buf_written_backend() AS buffers_backend,
794
        pg_stat_get_buf_fsync_backend() AS buffers_backend_fsync,
795 796
        pg_stat_get_buf_alloc() AS buffers_alloc,
        pg_stat_get_bgwriter_stat_reset_time() AS stats_reset;
797

798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819
CREATE VIEW pg_user_mappings AS
    SELECT
        U.oid       AS umid,
        S.oid       AS srvid,
        S.srvname   AS srvname,
        U.umuser    AS umuser,
        CASE WHEN U.umuser = 0 THEN
            'public'
        ELSE
            A.rolname
        END AS usename,
        CASE WHEN pg_has_role(S.srvowner, 'USAGE') OR has_server_privilege(S.oid, 'USAGE') THEN
            U.umoptions
        ELSE
            NULL
        END AS umoptions
    FROM pg_user_mapping U
         LEFT JOIN pg_authid A ON (A.oid = U.umuser) JOIN
        pg_foreign_server S ON (U.umserver = S.oid);

REVOKE ALL on pg_user_mapping FROM public;

820 821 822 823 824 825 826

CREATE VIEW pg_replication_origin_status AS
    SELECT *
    FROM pg_show_replication_origin_status();

REVOKE ALL ON pg_replication_origin_status FROM public;

827 828 829 830 831 832
--
-- We have a few function definitions in here, too.
-- At some point there might be enough to justify breaking them out into
-- a separate "system_functions.sql" file.
--

833
-- Tsearch debug function.  Defined here because it'd be pretty unwieldy
834 835
-- to put it into pg_proc.h

836 837 838 839 840 841 842 843
CREATE FUNCTION ts_debug(IN config regconfig, IN document text,
    OUT alias text,
    OUT description text,
    OUT token text,
    OUT dictionaries regdictionary[],
    OUT dictionary regdictionary,
    OUT lexemes text[])
RETURNS SETOF record AS
844
$$
845
SELECT
846 847 848
    tt.alias AS alias,
    tt.description AS description,
    parse.token AS token,
849 850 851
    ARRAY ( SELECT m.mapdict::pg_catalog.regdictionary
            FROM pg_catalog.pg_ts_config_map AS m
            WHERE m.mapcfg = $1 AND m.maptokentype = parse.tokid
852
            ORDER BY m.mapseqno )
853 854 855 856 857 858 859 860 861 862 863 864 865
    AS dictionaries,
    ( SELECT mapdict::pg_catalog.regdictionary
      FROM pg_catalog.pg_ts_config_map AS m
      WHERE m.mapcfg = $1 AND m.maptokentype = parse.tokid
      ORDER BY pg_catalog.ts_lexize(mapdict, parse.token) IS NULL, m.mapseqno
      LIMIT 1
    ) AS dictionary,
    ( SELECT pg_catalog.ts_lexize(mapdict, parse.token)
      FROM pg_catalog.pg_ts_config_map AS m
      WHERE m.mapcfg = $1 AND m.maptokentype = parse.tokid
      ORDER BY pg_catalog.ts_lexize(mapdict, parse.token) IS NULL, m.mapseqno
      LIMIT 1
    ) AS lexemes
866
FROM pg_catalog.ts_parse(
867
        (SELECT cfgparser FROM pg_catalog.pg_ts_config WHERE oid = $1 ), $2
868 869 870 871 872
    ) AS parse,
     pg_catalog.ts_token_type(
        (SELECT cfgparser FROM pg_catalog.pg_ts_config WHERE oid = $1 )
    ) AS tt
WHERE tt.tokid = parse.tokid
873
$$
874
LANGUAGE SQL STRICT STABLE;
875

876 877
COMMENT ON FUNCTION ts_debug(regconfig,text) IS
    'debug function for text search configuration';
878

879 880 881 882 883 884 885 886
CREATE FUNCTION ts_debug(IN document text,
    OUT alias text,
    OUT description text,
    OUT token text,
    OUT dictionaries regdictionary[],
    OUT dictionary regdictionary,
    OUT lexemes text[])
RETURNS SETOF record AS
887
$$
888
    SELECT * FROM pg_catalog.ts_debug( pg_catalog.get_current_ts_config(), $1);
889
$$
890
LANGUAGE SQL STRICT STABLE;
891

892 893
COMMENT ON FUNCTION ts_debug(text) IS
    'debug function for current text search configuration';
894 895 896 897 898 899 900 901 902 903 904 905

--
-- Redeclare built-in functions that need default values attached to their
-- arguments.  It's impractical to set those up directly in pg_proc.h because
-- of the complexity and platform-dependency of the expression tree
-- representation.  (Note that internal functions still have to have entries
-- in pg_proc.h; we are merely causing their proargnames and proargdefaults
-- to get filled in.)
--

CREATE OR REPLACE FUNCTION
  pg_start_backup(label text, fast boolean DEFAULT false)
906
  RETURNS pg_lsn STRICT VOLATILE LANGUAGE internal AS 'pg_start_backup';
907

908
-- legacy definition for compatibility with 9.3
909
CREATE OR REPLACE FUNCTION
910 911 912
  json_populate_record(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
  RETURNS anyelement LANGUAGE internal STABLE AS 'json_populate_record';

913
-- legacy definition for compatibility with 9.3
914
CREATE OR REPLACE FUNCTION
915 916
  json_populate_recordset(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
  RETURNS SETOF anyelement LANGUAGE internal STABLE ROWS 100  AS 'json_populate_recordset';
R
Robert Haas 已提交
917 918

CREATE OR REPLACE FUNCTION pg_logical_slot_get_changes(
919
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
920 921 922 923 924 925 926
    OUT location pg_lsn, OUT xid xid, OUT data text)
RETURNS SETOF RECORD
LANGUAGE INTERNAL
VOLATILE ROWS 1000 COST 1000
AS 'pg_logical_slot_get_changes';

CREATE OR REPLACE FUNCTION pg_logical_slot_peek_changes(
927
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
928 929 930 931 932 933 934
    OUT location pg_lsn, OUT xid xid, OUT data text)
RETURNS SETOF RECORD
LANGUAGE INTERNAL
VOLATILE ROWS 1000 COST 1000
AS 'pg_logical_slot_peek_changes';

CREATE OR REPLACE FUNCTION pg_logical_slot_get_binary_changes(
935
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
936 937 938 939 940 941 942
    OUT location pg_lsn, OUT xid xid, OUT data bytea)
RETURNS SETOF RECORD
LANGUAGE INTERNAL
VOLATILE ROWS 1000 COST 1000
AS 'pg_logical_slot_get_binary_changes';

CREATE OR REPLACE FUNCTION pg_logical_slot_peek_binary_changes(
943
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
944 945 946 947 948
    OUT location pg_lsn, OUT xid xid, OUT data bytea)
RETURNS SETOF RECORD
LANGUAGE INTERNAL
VOLATILE ROWS 1000 COST 1000
AS 'pg_logical_slot_peek_binary_changes';
949

950 951 952 953 954
CREATE OR REPLACE FUNCTION pg_create_physical_replication_slot(
    IN slot_name name, IN immediately_reserve boolean DEFAULT false,
    OUT slot_name name, OUT xlog_position pg_lsn)
RETURNS RECORD
LANGUAGE INTERNAL
955
STRICT VOLATILE
956 957
AS 'pg_create_physical_replication_slot';

958 959 960 961 962 963 964 965
CREATE OR REPLACE FUNCTION
  make_interval(years int4 DEFAULT 0, months int4 DEFAULT 0, weeks int4 DEFAULT 0,
                days int4 DEFAULT 0, hours int4 DEFAULT 0, mins int4 DEFAULT 0,
                secs double precision DEFAULT 0.0)
RETURNS interval
LANGUAGE INTERNAL
STRICT IMMUTABLE
AS 'make_interval';
966 967 968 969 970 971 972 973

CREATE OR REPLACE FUNCTION
  jsonb_set(jsonb_in jsonb, path text[] , replacement jsonb,
            create_if_missing boolean DEFAULT true)
RETURNS jsonb
LANGUAGE INTERNAL
STRICT IMMUTABLE
AS 'jsonb_set';