system_views.sql 31.4 KB
Newer Older
1 2 3
/*
 * PostgreSQL System Views
 *
B
Bruce Momjian 已提交
4
 * Copyright (c) 1996-2015, PostgreSQL Global Development Group
5
 *
6
 * src/backend/catalog/system_views.sql
7 8
 */

9 10
CREATE VIEW pg_roles AS
    SELECT
11
        rolname,
12 13 14 15 16 17 18
        rolsuper,
        rolinherit,
        rolcreaterole,
        rolcreatedb,
        rolcatupdate,
        rolcanlogin,
        rolreplication,
19
        rolconnlimit,
20 21
        '********'::text as rolpassword,
        rolvaliduntil,
22
        rolbypassrls,
23 24 25 26
        setconfig as rolconfig,
        pg_authid.oid
    FROM pg_authid LEFT JOIN pg_db_role_setting s
    ON (pg_authid.oid = setrole AND setdatabase = 0);
27 28 29 30

CREATE VIEW pg_shadow AS
    SELECT
        rolname AS usename,
31
        pg_authid.oid AS usesysid,
32 33 34 35
        rolcreatedb AS usecreatedb,
        rolsuper AS usesuper,
        rolcatupdate AS usecatupd,
        rolreplication AS userepl,
36 37
        rolpassword AS passwd,
        rolvaliduntil::abstime AS valuntil,
38 39 40
        setconfig AS useconfig
    FROM pg_authid LEFT JOIN pg_db_role_setting s
    ON (pg_authid.oid = setrole AND setdatabase = 0)
41
    WHERE rolcanlogin;
42 43 44 45 46 47 48 49 50

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
51
    WHERE NOT rolcanlogin;
52

53 54 55 56 57 58 59
CREATE VIEW pg_user AS
    SELECT
        usename,
        usesysid,
        usecreatedb,
        usesuper,
        usecatupd,
60
        userepl,
61 62 63
        '********'::text as passwd,
        valuntil,
        useconfig
64 65
    FROM pg_shadow;

66 67
CREATE VIEW pg_policies AS
    SELECT
68 69
        N.nspname AS schemaname,
        C.relname AS tablename,
70
        pol.polname AS policyname,
71
        CASE
72
            WHEN pol.polroles = '{0}' THEN
73 74 75 76 77 78
                string_to_array('public', '')
            ELSE
                ARRAY
                (
                    SELECT rolname
                    FROM pg_catalog.pg_authid
79
                    WHERE oid = ANY (pol.polroles) ORDER BY 1
80 81
                )
        END AS roles,
82 83 84 85 86 87
        CASE pol.polcmd
            WHEN 'r' THEN 'SELECT'
            WHEN 'a' THEN 'INSERT'
            WHEN 'w' THEN 'UPDATE'
            WHEN 'd' THEN 'DELETE'
            WHEN '*' THEN 'ALL'
88
        END AS cmd,
89 90 91 92
        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)
93
    LEFT JOIN pg_catalog.pg_namespace N ON (N.oid = C.relnamespace);
94

95 96 97 98 99 100 101 102
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)
103 104
    WHERE R.rulename != '_RETURN';

105 106 107 108 109 110 111
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)
112 113
    WHERE C.relkind = 'v';

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

128 129 130 131 132 133 134
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,
135
        C.relispopulated AS ispopulated,
136 137 138 139 140
        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';

141 142 143 144 145
CREATE VIEW pg_indexes AS
    SELECT
        N.nspname AS schemaname,
        C.relname AS tablename,
        I.relname AS indexname,
146
        T.spcname AS tablespace,
147 148 149 150
        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)
151
         LEFT JOIN pg_tablespace T ON (T.oid = I.reltablespace)
152
    WHERE C.relkind IN ('r', 'm') AND I.relkind = 'i';
153

154 155 156 157 158 159 160 161 162
CREATE VIEW pg_stats AS
    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,
163
        CASE
164 165 166 167 168
            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
169 170
        END AS most_common_vals,
        CASE
171 172 173 174 175
            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
176 177 178 179 180 181
        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
182
            WHEN stakind5 = 2 THEN stavalues5
183 184 185 186 187 188
        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]
189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211
            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
212 213 214
    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)
215
    WHERE NOT attisdropped AND has_column_privilege(c.oid, a.attnum, 'select');
216 217 218

REVOKE ALL on pg_statistic FROM public;

219
CREATE VIEW pg_locks AS
220
    SELECT * FROM pg_lock_status() AS L;
221

222
CREATE VIEW pg_cursors AS
223
    SELECT * FROM pg_cursor() AS C;
224

225
CREATE VIEW pg_available_extensions AS
226 227
    SELECT E.name, E.default_version, X.extversion AS installed_version,
           E.comment
228
      FROM pg_available_extensions() AS E
229 230 231 232
           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,
233
           E.superuser, E.relocatable, E.schema, E.requires, E.comment
234 235 236
      FROM pg_available_extension_versions() AS E
           LEFT JOIN pg_extension AS X
             ON E.name = X.extname AND E.version = X.extversion;
237

238
CREATE VIEW pg_prepared_xacts AS
239
    SELECT P.transaction, P.gid, P.prepared,
240
           U.rolname AS owner, D.datname AS database
241
    FROM pg_prepared_xact() AS P
242
         LEFT JOIN pg_authid U ON P.ownerid = U.oid
243
         LEFT JOIN pg_database D ON P.dbid = D.oid;
244

245
CREATE VIEW pg_prepared_statements AS
246
    SELECT * FROM pg_prepared_statement() AS P;
247

R
Robert Haas 已提交
248 249 250 251
CREATE VIEW pg_seclabels AS
SELECT
	l.objoid, l.classoid, l.objsubid,
	CASE WHEN rel.relkind = 'r' THEN 'table'::text
R
Robert Haas 已提交
252
		 WHEN rel.relkind = 'v' THEN 'view'::text
253
		 WHEN rel.relkind = 'm' THEN 'materialized view'::text
R
Robert Haas 已提交
254 255
		 WHEN rel.relkind = 'S' THEN 'sequence'::text
		 WHEN rel.relkind = 'f' THEN 'foreign table'::text END AS objtype,
R
Robert Haas 已提交
256 257 258 259 260 261 262 263 264 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
	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
356 357
	l.objsubid = 0
UNION ALL
358 359 360 361 362 363 364 365 366 367 368 369 370
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
371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399
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 已提交
400

401 402
CREATE VIEW pg_settings AS
    SELECT * FROM pg_show_all_settings() AS A;
403

404 405 406
CREATE RULE pg_settings_u AS
    ON UPDATE TO pg_settings
    WHERE new.name = old.name DO
407 408
    SELECT set_config(old.name, new.setting, 'f');

409 410
CREATE RULE pg_settings_n AS
    ON UPDATE TO pg_settings
411 412 413 414
    DO INSTEAD NOTHING;

GRANT SELECT, UPDATE ON pg_settings TO PUBLIC;

415 416 417 418 419
CREATE VIEW pg_timezone_abbrevs AS
    SELECT * FROM pg_timezone_abbrevs();

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

421 422
-- Statistics views

423 424 425 426 427 428 429 430
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,
431
            sum(pg_stat_get_tuples_fetched(I.indexrelid))::bigint +
432 433 434
            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,
435
            pg_stat_get_tuples_deleted(C.oid) AS n_tup_del,
436
            pg_stat_get_tuples_hot_updated(C.oid) AS n_tup_hot_upd,
437
            pg_stat_get_live_tuples(C.oid) AS n_live_tup,
438
            pg_stat_get_dead_tuples(C.oid) AS n_dead_tup,
439
            pg_stat_get_mod_since_analyze(C.oid) AS n_mod_since_analyze,
440 441 442
            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,
443 444 445 446 447
            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
448 449 450
    FROM pg_class C LEFT JOIN
         pg_index I ON C.oid = I.indrelid
         LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
451
    WHERE C.relkind IN ('r', 't', 'm')
452 453
    GROUP BY C.oid, N.nspname, C.relname;

454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470
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)
471
    WHERE C.relkind IN ('r', 't', 'm')
472 473
    GROUP BY C.oid, N.nspname, C.relname;

474 475
CREATE VIEW pg_stat_sys_tables AS
    SELECT * FROM pg_stat_all_tables
476 477
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
478

479 480 481 482 483
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';

484 485
CREATE VIEW pg_stat_user_tables AS
    SELECT * FROM pg_stat_all_tables
486 487
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
488

489 490 491 492 493
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';

494 495 496 497 498 499 500 501 502 503 504 505 506 507
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 已提交
508 509 510
            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
511 512 513
    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 已提交
514
            pg_index X ON T.oid = X.indrelid
515
            LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
516
    WHERE C.relkind IN ('r', 't', 'm')
F
Fujii Masao 已提交
517
    GROUP BY C.oid, N.nspname, C.relname, T.oid, X.indrelid;
518

519 520
CREATE VIEW pg_statio_sys_tables AS
    SELECT * FROM pg_statio_all_tables
521 522
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
523

524 525
CREATE VIEW pg_statio_user_tables AS
    SELECT * FROM pg_statio_all_tables
526 527
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
528

529 530 531 532 533 534 535 536 537 538 539 540 541 542
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)
543
    WHERE C.relkind IN ('r', 't', 'm');
544

545 546
CREATE VIEW pg_stat_sys_indexes AS
    SELECT * FROM pg_stat_all_indexes
547 548
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
549

550 551
CREATE VIEW pg_stat_user_indexes AS
    SELECT * FROM pg_stat_all_indexes
552 553
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
554

555 556 557 558 559 560 561 562 563 564 565 566 567 568
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)
569
    WHERE C.relkind IN ('r', 't', 'm');
570

571 572
CREATE VIEW pg_statio_sys_indexes AS
    SELECT * FROM pg_statio_all_indexes
573 574
    WHERE schemaname IN ('pg_catalog', 'information_schema') OR
          schemaname ~ '^pg_toast';
575

576 577
CREATE VIEW pg_statio_user_indexes AS
    SELECT * FROM pg_statio_all_indexes
578 579
    WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
          schemaname !~ '^pg_toast';
580

581 582 583 584 585 586 587 588 589 590
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)
591 592
    WHERE C.relkind = 'S';

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

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

603 604
CREATE VIEW pg_stat_activity AS
    SELECT
605 606
            S.datid AS datid,
            D.datname AS datname,
607
            S.pid,
608 609
            S.usesysid,
            U.rolname AS usename,
610
            S.application_name,
611
            S.client_addr,
612
            S.client_hostname,
613 614
            S.client_port,
            S.backend_start,
615 616
            S.xact_start,
            S.query_start,
617
            S.state_change,
618
            S.waiting,
619
            S.state,
620 621
            S.backend_xid,
            s.backend_xmin,
622
            S.query
623
    FROM pg_database D, pg_stat_get_activity(NULL) AS S, pg_authid U
624
    WHERE S.datid = D.oid AND
625
            S.usesysid = U.oid;
626

627 628
CREATE VIEW pg_stat_replication AS
    SELECT
629
            S.pid,
630 631 632 633
            S.usesysid,
            U.rolname AS usename,
            S.application_name,
            S.client_addr,
634
            S.client_hostname,
635 636
            S.client_port,
            S.backend_start,
637
            S.backend_xmin,
638
            W.state,
639 640 641
            W.sent_location,
            W.write_location,
            W.flush_location,
642 643 644
            W.replay_location,
            W.sync_priority,
            W.sync_state
645 646 647
    FROM pg_stat_get_activity(NULL) AS S, pg_authid U,
            pg_stat_get_wal_senders() AS W
    WHERE S.usesysid = U.oid AND
648
            S.pid = W.pid;
649

R
Robert Haas 已提交
650 651 652
CREATE VIEW pg_replication_slots AS
    SELECT
            L.slot_name,
R
Robert Haas 已提交
653
            L.plugin,
R
Robert Haas 已提交
654 655 656 657 658
            L.slot_type,
            L.datoid,
            D.datname AS database,
            L.active,
            L.xmin,
R
Robert Haas 已提交
659
            L.catalog_xmin,
R
Robert Haas 已提交
660 661 662 663
            L.restart_lsn
    FROM pg_get_replication_slots() AS L
            LEFT JOIN pg_database D ON (L.datoid = D.oid);

664 665 666 667 668 669 670 671 672
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,
673 674 675 676 677
            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,
678
            pg_stat_get_db_tuples_deleted(D.oid) AS tup_deleted,
679
            pg_stat_get_db_conflict_all(D.oid) AS conflicts,
680 681
            pg_stat_get_db_temp_files(D.oid) AS temp_files,
            pg_stat_get_db_temp_bytes(D.oid) AS temp_bytes,
682
            pg_stat_get_db_deadlocks(D.oid) AS deadlocks,
683 684
            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,
685
            pg_stat_get_db_stat_reset_time(D.oid) AS stats_reset
686 687 688 689 690 691 692 693 694 695 696
    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
697
    FROM pg_database D;
698

699
CREATE VIEW pg_stat_user_functions AS
700
    SELECT
701
            P.oid AS funcid,
702 703 704
            N.nspname AS schemaname,
            P.proname AS funcname,
            pg_stat_get_function_calls(P.oid) AS calls,
705 706
            pg_stat_get_function_total_time(P.oid) AS total_time,
            pg_stat_get_function_self_time(P.oid) AS self_time
707
    FROM pg_proc P LEFT JOIN pg_namespace N ON (N.oid = P.pronamespace)
708
    WHERE P.prolang != 12  -- fast check to eliminate built-in functions
709 710
          AND pg_stat_get_function_calls(P.oid) IS NOT NULL;

711 712 713 714 715 716
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,
717 718
            pg_stat_get_xact_function_total_time(P.oid) AS total_time,
            pg_stat_get_xact_function_self_time(P.oid) AS self_time
719 720 721 722
    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;

723 724 725 726 727 728 729 730 731 732 733
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;

734
CREATE VIEW pg_stat_bgwriter AS
735 736 737
    SELECT
        pg_stat_get_bgwriter_timed_checkpoints() AS checkpoints_timed,
        pg_stat_get_bgwriter_requested_checkpoints() AS checkpoints_req,
738
        pg_stat_get_checkpoint_write_time() AS checkpoint_write_time,
R
Robert Haas 已提交
739
        pg_stat_get_checkpoint_sync_time() AS checkpoint_sync_time,
740 741
        pg_stat_get_bgwriter_buf_written_checkpoints() AS buffers_checkpoint,
        pg_stat_get_bgwriter_buf_written_clean() AS buffers_clean,
742 743
        pg_stat_get_bgwriter_maxwritten_clean() AS maxwritten_clean,
        pg_stat_get_buf_written_backend() AS buffers_backend,
744
        pg_stat_get_buf_fsync_backend() AS buffers_backend_fsync,
745 746
        pg_stat_get_buf_alloc() AS buffers_alloc,
        pg_stat_get_bgwriter_stat_reset_time() AS stats_reset;
747

748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769
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;

770 771 772 773 774 775
--
-- 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.
--

776
-- Tsearch debug function.  Defined here because it'd be pretty unwieldy
777 778
-- to put it into pg_proc.h

779 780 781 782 783 784 785 786
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
787
$$
788
SELECT
789 790 791
    tt.alias AS alias,
    tt.description AS description,
    parse.token AS token,
792 793 794
    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
795
            ORDER BY m.mapseqno )
796 797 798 799 800 801 802 803 804 805 806 807 808
    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
809
FROM pg_catalog.ts_parse(
810
        (SELECT cfgparser FROM pg_catalog.pg_ts_config WHERE oid = $1 ), $2
811 812 813 814 815
    ) 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
816
$$
817
LANGUAGE SQL STRICT STABLE;
818

819 820
COMMENT ON FUNCTION ts_debug(regconfig,text) IS
    'debug function for text search configuration';
821

822 823 824 825 826 827 828 829
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
830
$$
831
    SELECT * FROM pg_catalog.ts_debug( pg_catalog.get_current_ts_config(), $1);
832
$$
833
LANGUAGE SQL STRICT STABLE;
834

835 836
COMMENT ON FUNCTION ts_debug(text) IS
    'debug function for current text search configuration';
837 838 839 840 841 842 843 844 845 846 847 848

--
-- 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)
849
  RETURNS pg_lsn STRICT VOLATILE LANGUAGE internal AS 'pg_start_backup';
850

851
-- legacy definition for compatibility with 9.3
852
CREATE OR REPLACE FUNCTION
853 854 855
  json_populate_record(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
  RETURNS anyelement LANGUAGE internal STABLE AS 'json_populate_record';

856
-- legacy definition for compatibility with 9.3
857
CREATE OR REPLACE FUNCTION
858 859
  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 已提交
860 861

CREATE OR REPLACE FUNCTION pg_logical_slot_get_changes(
862
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
863 864 865 866 867 868 869
    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(
870
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
871 872 873 874 875 876 877
    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(
878
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
879 880 881 882 883 884 885
    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(
886
    IN slot_name name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
R
Robert Haas 已提交
887 888 889 890 891
    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';
892 893 894 895 896 897 898 899 900

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';