system_views.sql 13.9 KB
Newer Older
1 2 3
/*
 * PostgreSQL System Views
 *
4
 * Copyright (c) 1996-2006, PostgreSQL Global Development Group
5
 *
6
 * $PostgreSQL: pgsql/src/backend/catalog/system_views.sql,v 1.31 2006/09/16 20:14:33 tgl Exp $
7 8
 */

9 10 11 12
CREATE VIEW pg_roles AS 
    SELECT 
        rolname,
        rolsuper,
13
        rolinherit,
14 15 16 17
        rolcreaterole,
        rolcreatedb,
        rolcatupdate,
        rolcanlogin,
18
        rolconnlimit,
19 20
        '********'::text as rolpassword,
        rolvaliduntil,
21 22
        rolconfig,
        oid
23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47
    FROM pg_authid;

CREATE VIEW pg_shadow AS
    SELECT
        rolname AS usename,
        oid AS usesysid,
        rolcreatedb AS usecreatedb,
        rolsuper AS usesuper,
        rolcatupdate AS usecatupd,
        rolpassword AS passwd,
        rolvaliduntil::abstime AS valuntil,
        rolconfig AS useconfig
    FROM pg_authid
    WHERE rolcanlogin;

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

48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83
CREATE VIEW pg_user AS 
    SELECT 
        usename, 
        usesysid, 
        usecreatedb, 
        usesuper, 
        usecatupd, 
        '********'::text as passwd, 
        valuntil, 
        useconfig 
    FROM pg_shadow;

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) 
    WHERE R.rulename != '_RETURN';

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) 
    WHERE C.relkind = 'v';

CREATE VIEW pg_tables AS 
    SELECT 
        N.nspname AS schemaname, 
        C.relname AS tablename, 
        pg_get_userbyid(C.relowner) AS tableowner, 
84
        T.spcname AS tablespace,
85 86 87 88
        C.relhasindex AS hasindexes, 
        C.relhasrules AS hasrules, 
        (C.reltriggers > 0) AS hastriggers 
    FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 
89
         LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
90 91 92 93 94 95 96
    WHERE C.relkind = 'r';

CREATE VIEW pg_indexes AS 
    SELECT 
        N.nspname AS schemaname, 
        C.relname AS tablename, 
        I.relname AS indexname, 
97
        T.spcname AS tablespace,
98 99 100 101
        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) 
102
         LEFT JOIN pg_tablespace T ON (T.oid = I.reltablespace)
103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143
    WHERE C.relkind = 'r' AND I.relkind = 'i';

CREATE VIEW pg_stats AS 
    SELECT 
        nspname AS schemaname, 
        relname AS tablename, 
        attname AS attname, 
        stanullfrac AS null_frac, 
        stawidth AS avg_width, 
        stadistinct AS n_distinct, 
        CASE 1 
            WHEN stakind1 THEN stavalues1 
            WHEN stakind2 THEN stavalues2 
            WHEN stakind3 THEN stavalues3 
            WHEN stakind4 THEN stavalues4 
        END AS most_common_vals, 
        CASE 1 
            WHEN stakind1 THEN stanumbers1 
            WHEN stakind2 THEN stanumbers2 
            WHEN stakind3 THEN stanumbers3 
            WHEN stakind4 THEN stanumbers4 
        END AS most_common_freqs, 
        CASE 2 
            WHEN stakind1 THEN stavalues1 
            WHEN stakind2 THEN stavalues2 
            WHEN stakind3 THEN stavalues3 
            WHEN stakind4 THEN stavalues4 
        END AS histogram_bounds, 
        CASE 3 
            WHEN stakind1 THEN stanumbers1[1] 
            WHEN stakind2 THEN stanumbers2[1] 
            WHEN stakind3 THEN stanumbers3[1] 
            WHEN stakind4 THEN stanumbers4[1] 
        END AS correlation 
    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) 
    WHERE has_table_privilege(c.oid, 'select');

REVOKE ALL on pg_statistic FROM public;

144 145 146 147
CREATE VIEW pg_locks AS 
    SELECT * 
    FROM pg_lock_status() AS L
    (locktype text, database oid, relation oid, page int4, tuple int2,
148 149
     transactionid xid, classid oid, objid oid, objsubid int2,
     transaction xid, pid int4, mode text, granted boolean);
150

151 152 153 154 155 156 157
CREATE VIEW pg_cursors AS
    SELECT C.name, C.statement, C.is_holdable, C.is_binary,
           C.is_scrollable, C.creation_time
    FROM pg_cursor() AS C
         (name text, statement text, is_holdable boolean, is_binary boolean,
          is_scrollable boolean, creation_time timestamptz);

158
CREATE VIEW pg_prepared_xacts AS
159
    SELECT P.transaction, P.gid, P.prepared,
160
           U.rolname AS owner, D.datname AS database
161
    FROM pg_prepared_xact() AS P
162 163
    (transaction xid, gid text, prepared timestamptz, ownerid oid, dbid oid)
         LEFT JOIN pg_authid U ON P.ownerid = U.oid
164
         LEFT JOIN pg_database D ON P.dbid = D.oid;
165

166 167 168 169
CREATE VIEW pg_prepared_statements AS
    SELECT P.name, P.statement, P.prepare_time, P.parameter_types, P.from_sql
    FROM pg_prepared_statement() AS P
    (name text, statement text, prepare_time timestamptz,
170
     parameter_types regtype[], from_sql boolean);
171

172 173 174
CREATE VIEW pg_settings AS 
    SELECT * 
    FROM pg_show_all_settings() AS A 
175
    (name text, setting text, unit text, category text, short_desc text, extra_desc text,
176 177 178 179 180 181 182 183 184 185 186 187 188
     context text, vartype text, source text, min_val text, max_val text);

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

CREATE RULE pg_settings_n AS 
    ON UPDATE TO pg_settings 
    DO INSTEAD NOTHING;

GRANT SELECT, UPDATE ON pg_settings TO PUBLIC;

189 190 191 192 193
CREATE VIEW pg_timezone_abbrevs AS
    SELECT * FROM pg_timezone_abbrevs();

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

195 196
-- Statistics views

197 198 199 200 201
CREATE VIEW pg_stat_all_tables AS 
    SELECT 
            C.oid AS relid, 
            N.nspname AS schemaname, 
            C.relname AS relname, 
202 203 204 205
            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,
            pg_stat_get_last_autoanalyze_time(C.oid) as last_autoanalyze,
206 207
            pg_stat_get_numscans(C.oid) AS seq_scan, 
            pg_stat_get_tuples_returned(C.oid) AS seq_tup_read, 
208 209 210
            sum(pg_stat_get_numscans(I.indexrelid))::bigint AS idx_scan, 
            sum(pg_stat_get_tuples_fetched(I.indexrelid))::bigint +
                    pg_stat_get_tuples_fetched(C.oid) AS idx_tup_fetch, 
211 212 213 214 215 216
            pg_stat_get_tuples_inserted(C.oid) AS n_tup_ins, 
            pg_stat_get_tuples_updated(C.oid) AS n_tup_upd, 
            pg_stat_get_tuples_deleted(C.oid) AS n_tup_del 
    FROM pg_class C LEFT JOIN 
         pg_index I ON C.oid = I.indrelid 
         LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 
217
    WHERE C.relkind IN ('r', 't')
218 219 220 221
    GROUP BY C.oid, N.nspname, C.relname;

CREATE VIEW pg_stat_sys_tables AS 
    SELECT * FROM pg_stat_all_tables 
222
    WHERE schemaname IN ('pg_catalog', 'pg_toast', 'information_schema');
223 224 225

CREATE VIEW pg_stat_user_tables AS 
    SELECT * FROM pg_stat_all_tables 
226
    WHERE schemaname NOT IN ('pg_catalog', 'pg_toast', 'information_schema');
227 228 229 230 231 232 233 234 235 236

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) - 
237 238
                    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, 
239 240 241 242 243 244 245 246 247 248 249
            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, 
            pg_stat_get_blocks_fetched(X.oid) - 
                    pg_stat_get_blocks_hit(X.oid) AS tidx_blks_read, 
            pg_stat_get_blocks_hit(X.oid) AS tidx_blks_hit 
    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 
            pg_class X ON T.reltoastidxid = X.oid 
            LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 
250
    WHERE C.relkind IN ('r', 't')
251 252 253 254
    GROUP BY C.oid, N.nspname, C.relname, T.oid, X.oid;

CREATE VIEW pg_statio_sys_tables AS 
    SELECT * FROM pg_statio_all_tables 
255
    WHERE schemaname IN ('pg_catalog', 'pg_toast', 'information_schema');
256 257 258

CREATE VIEW pg_statio_user_tables AS 
    SELECT * FROM pg_statio_all_tables 
259
    WHERE schemaname NOT IN ('pg_catalog', 'pg_toast', 'information_schema');
260 261 262 263 264 265 266 267 268 269 270 271 272 273 274

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) 
275
    WHERE C.relkind IN ('r', 't');
276 277 278

CREATE VIEW pg_stat_sys_indexes AS 
    SELECT * FROM pg_stat_all_indexes 
279
    WHERE schemaname IN ('pg_catalog', 'pg_toast', 'information_schema');
280 281 282

CREATE VIEW pg_stat_user_indexes AS 
    SELECT * FROM pg_stat_all_indexes 
283
    WHERE schemaname NOT IN ('pg_catalog', 'pg_toast', 'information_schema');
284 285 286 287 288 289 290 291 292 293 294 295 296 297 298

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) 
299
    WHERE C.relkind IN ('r', 't');
300 301 302

CREATE VIEW pg_statio_sys_indexes AS 
    SELECT * FROM pg_statio_all_indexes 
303
    WHERE schemaname IN ('pg_catalog', 'pg_toast', 'information_schema');
304 305 306

CREATE VIEW pg_statio_user_indexes AS 
    SELECT * FROM pg_statio_all_indexes 
307
    WHERE schemaname NOT IN ('pg_catalog', 'pg_toast', 'information_schema');
308 309 310 311 312 313 314 315 316 317 318 319 320 321 322

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) 
    WHERE C.relkind = 'S';

CREATE VIEW pg_statio_sys_sequences AS 
    SELECT * FROM pg_statio_all_sequences 
323
    WHERE schemaname IN ('pg_catalog', 'pg_toast', 'information_schema');
324 325 326

CREATE VIEW pg_statio_user_sequences AS 
    SELECT * FROM pg_statio_all_sequences 
327
    WHERE schemaname NOT IN ('pg_catalog', 'pg_toast', 'information_schema');
328 329 330 331 332 333 334

CREATE VIEW pg_stat_activity AS 
    SELECT 
            D.oid AS datid, 
            D.datname AS datname, 
            pg_stat_get_backend_pid(S.backendid) AS procpid, 
            pg_stat_get_backend_userid(S.backendid) AS usesysid, 
335
            U.rolname AS usename, 
336 337
            pg_stat_get_backend_activity(S.backendid) AS current_query,
            pg_stat_get_backend_waiting(S.backendid) AS waiting,
N
Neil Conway 已提交
338 339 340 341
            pg_stat_get_backend_activity_start(S.backendid) AS query_start,
            pg_stat_get_backend_start(S.backendid) AS backend_start,
            pg_stat_get_backend_client_addr(S.backendid) AS client_addr,
            pg_stat_get_backend_client_port(S.backendid) AS client_port
342 343
    FROM pg_database D, 
            (SELECT pg_stat_get_backend_idset() AS backendid) AS S, 
344
            pg_authid U 
345
    WHERE pg_stat_get_backend_dbid(S.backendid) = D.oid AND 
346
            pg_stat_get_backend_userid(S.backendid) = U.oid;
347 348 349 350 351 352 353 354 355 356 357 358

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, 
            pg_stat_get_db_blocks_hit(D.oid) AS blks_hit 
    FROM pg_database D;
359 360 361 362 363 364 365 366 367 368 369 370 371 372 373

--
-- Fix up built-in functions that make use of OUT parameters.
-- We can't currently fill these values in during bootstrap, because
-- array_in doesn't work in bootstrap mode.  Eventually that should be
-- fixed, but for now the path of least resistance is to patch their
-- pg_proc entries later during initdb.
--

UPDATE pg_proc SET
  proallargtypes = ARRAY['text'::regtype,
                         'int8',
                         'timestamptz',
                         'timestamptz',
                         'timestamptz',
374
                         'timestamptz',
375
                         'bool'],
376 377
  proargmodes = ARRAY['i'::"char", 'o', 'o', 'o', 'o', 'o', 'o'],
  proargnames = ARRAY['filename'::text, 'size', 'access', 'modification',
378
                      'change', 'creation', 'isdir']
379
WHERE oid = 'pg_stat_file(text)'::regprocedure;