]> granicus.if.org Git - postgresql/commitdiff
Revoke public read access from pg_statistic, create new system view
authorTom Lane <tgl@sss.pgh.pa.us>
Thu, 14 Jun 2001 19:47:25 +0000 (19:47 +0000)
committerTom Lane <tgl@sss.pgh.pa.us>
Thu, 14 Jun 2001 19:47:25 +0000 (19:47 +0000)
pg_stats to provide controlled (and, hopefully, more readable) access
to statistics.  Comments on definition of pg_stats welcome.
I didn't force initdb, but the rules regress test will fail until you
do one.

src/bin/initdb/initdb.sh
src/test/regress/expected/rules.out

index c14f185cd286aa328bf66c401d90fcbeb017304a..b5c2a0004ee114c5f6402b6bc0b4ff72d2cf0cf4 100644 (file)
@@ -27,7 +27,7 @@
 # Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group
 # Portions Copyright (c) 1994, Regents of the University of California
 #
-# $Header: /cvsroot/pgsql/src/bin/initdb/Attic/initdb.sh,v 1.126 2001/06/12 05:55:50 tgl Exp $
+# $Header: /cvsroot/pgsql/src/bin/initdb/Attic/initdb.sh,v 1.127 2001/06/14 19:47:25 tgl Exp $
 #
 #-------------------------------------------------------------------------
 
@@ -497,7 +497,8 @@ echo "CREATE TRIGGER pg_sync_pg_pwd AFTER INSERT OR UPDATE OR DELETE ON pg_shado
      "FOR EACH ROW EXECUTE PROCEDURE update_pg_pwd()" \
      | "$PGPATH"/postgres $PGSQL_OPT template1 > /dev/null || exit_nicely
 
-# needs to be done before alter user
+# needs to be done before alter user, because alter user checks that
+# pg_shadow is secure ...
 echo "REVOKE ALL on pg_shadow FROM public" \
        | "$PGPATH"/postgres $PGSQL_OPT template1 > /dev/null || exit_nicely
 
@@ -601,6 +602,46 @@ echo "CREATE VIEW pg_indexes AS \
             AND I.oid = X.indexrelid;" \
         | "$PGPATH"/postgres $PGSQL_OPT template1 > /dev/null || exit_nicely
 
+echo "CREATE VIEW pg_stats AS \
+       SELECT \
+           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_class c, pg_attribute a, pg_statistic s \
+       WHERE c.oid = s.starelid AND c.oid = a.attrelid \
+           AND a.attnum = s.staattnum \
+           AND has_table_privilege(c.oid, 'select');" \
+        | "$PGPATH"/postgres $PGSQL_OPT template1 > /dev/null || exit_nicely
+
+echo "REVOKE ALL on pg_statistic FROM public" \
+       | "$PGPATH"/postgres $PGSQL_OPT template1 > /dev/null || exit_nicely
+
 echo "Loading pg_description."
 echo "COPY pg_description FROM STDIN" > $TEMPFILE
 cat "$POSTGRES_DESCR" >> $TEMPFILE
index 1fb6f14f997a4f7c8d1352830ad9c1f41c582b7a..a651ef8327f882002a2aea81bffa7341ba211ee9 100644 (file)
@@ -1264,11 +1264,12 @@ drop table cchild;
 -- Check that ruleutils are working
 --
 SELECT viewname, definition FROM pg_views ORDER BY viewname;
-      viewname      |                                                                                                                               definition                                                                                                                               
---------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+      viewname      |                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                               definition                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                               
+--------------------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  iexit              | SELECT ih.name, ih.thepath, interpt_pp(ih.thepath, r.thepath) AS exit FROM ihighway ih, ramp r WHERE (ih.thepath ## r.thepath);
  pg_indexes         | SELECT c.relname AS tablename, i.relname AS indexname, pg_get_indexdef(x.indexrelid) AS indexdef FROM pg_index x, pg_class c, pg_class i WHERE ((((c.relkind = 'r'::"char") AND (i.relkind = 'i'::"char")) AND (c.oid = x.indrelid)) AND (i.oid = x.indexrelid));
  pg_rules           | SELECT c.relname AS tablename, r.rulename, pg_get_ruledef(r.rulename) AS definition FROM pg_rewrite r, pg_class c WHERE ((r.rulename !~ '^_RET'::text) AND (c.oid = r.ev_class));
+ pg_stats           | SELECT c.relname AS tablename, a.attname, s.stanullfrac AS null_frac, s.stawidth AS avg_width, s.stadistinct AS n_distinct, CASE WHEN (1 = s.stakind1) THEN s.stavalues1 WHEN (1 = s.stakind2) THEN s.stavalues2 WHEN (1 = s.stakind3) THEN s.stavalues3 WHEN (1 = s.stakind4) THEN s.stavalues4 ELSE NULL::"_text" END AS most_common_vals, CASE WHEN (1 = s.stakind1) THEN s.stanumbers1 WHEN (1 = s.stakind2) THEN s.stanumbers2 WHEN (1 = s.stakind3) THEN s.stanumbers3 WHEN (1 = s.stakind4) THEN s.stanumbers4 ELSE NULL::"_float4" END AS most_common_freqs, CASE WHEN (2 = s.stakind1) THEN s.stavalues1 WHEN (2 = s.stakind2) THEN s.stavalues2 WHEN (2 = s.stakind3) THEN s.stavalues3 WHEN (2 = s.stakind4) THEN s.stavalues4 ELSE NULL::"_text" END AS histogram_bounds, CASE WHEN (3 = s.stakind1) THEN s.stanumbers1[1] WHEN (3 = s.stakind2) THEN s.stanumbers2[1] WHEN (3 = s.stakind3) THEN s.stanumbers3[1] WHEN (3 = s.stakind4) THEN s.stanumbers4[1] ELSE NULL::float4 END AS correlation FROM pg_class c, pg_attribute a, pg_statistic s WHERE ((((c.oid = s.starelid) AND (c.oid = a.attrelid)) AND (a.attnum = s.staattnum)) AND has_table_privilege(c.oid, 'select'::text));
  pg_tables          | SELECT c.relname AS tablename, pg_get_userbyid(c.relowner) AS tableowner, c.relhasindex AS hasindexes, c.relhasrules AS hasrules, (c.reltriggers > 0) AS hastriggers FROM pg_class c WHERE ((c.relkind = 'r'::"char") OR (c.relkind = 's'::"char"));
  pg_user            | SELECT pg_shadow.usename, pg_shadow.usesysid, pg_shadow.usecreatedb, pg_shadow.usetrace, pg_shadow.usesuper, pg_shadow.usecatupd, '********'::text AS passwd, pg_shadow.valuntil FROM pg_shadow;
  pg_views           | SELECT c.relname AS viewname, pg_get_userbyid(c.relowner) AS viewowner, pg_get_viewdef(c.relname) AS definition FROM pg_class c WHERE (c.relkind = 'v'::"char");
@@ -1286,7 +1287,7 @@ SELECT viewname, definition FROM pg_views ORDER BY viewname;
  shoelace_obsolete  | SELECT shoelace.sl_name, shoelace.sl_avail, shoelace.sl_color, shoelace.sl_len, shoelace.sl_unit, shoelace.sl_len_cm FROM shoelace WHERE (NOT (EXISTS (SELECT shoe.shoename FROM shoe WHERE (shoe.slcolor = shoelace.sl_color))));
  street             | SELECT r.name, r.thepath, c.cname FROM ONLY road r, real_city c WHERE (c.outline ## r.thepath);
  toyemp             | SELECT emp.name, emp.age, emp."location", (12 * emp.salary) AS annualsal FROM emp;
-(20 rows)
+(21 rows)
 
 SELECT tablename, rulename, definition FROM pg_rules 
        ORDER BY tablename, rulename;