From 1b42ad7e59e03dbacf880b72cfae4c16e6d3be49 Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Sat, 14 Dec 2002 00:24:35 +0000 Subject: [PATCH] Initial version of the SQL information schema --- doc/src/sgml/features.sgml | 146 ++--- doc/src/sgml/release.sgml | 3 +- src/backend/Makefile | 6 +- src/backend/catalog/Makefile | 13 +- src/backend/catalog/information_schema.sql | 516 ++++++++++++++++++ src/bin/initdb/initdb.sh | 6 +- src/test/regress/expected/rules.out | 2 +- src/test/regress/expected/type_sanity.out | 2 +- .../regress/input/create_function_2.source | 5 +- .../regress/output/create_function_2.source | 5 +- src/test/regress/sql/rules.sql | 2 +- src/test/regress/sql/type_sanity.sql | 2 +- 12 files changed, 616 insertions(+), 92 deletions(-) create mode 100644 src/backend/catalog/information_schema.sql diff --git a/doc/src/sgml/features.sgml b/doc/src/sgml/features.sgml index 437d43c27e..30f20bf51e 100644 --- a/doc/src/sgml/features.sgml +++ b/doc/src/sgml/features.sgml @@ -1,5 +1,5 @@ @@ -655,6 +655,48 @@ $Header: /cvsroot/pgsql/doc/src/sgml/features.sgml,v 2.11 2002/12/06 05:07:12 mo SQL comments using leading double minus + + F021 + Core + Basic information schema + + + + F021-01 + Core + COLUMNS view + + + + F021-02 + Core + TABLES view + + + + F021-03 + Core + VIEWS view + + + + F021-04 + Core + TABLE_CONSTRAINTS view + + + + F021-05 + Core + REFERENTIAL_CONSTRAINTS view + + + + F021-06 + Core + CHECK_CONSTRAINTS view + + F031 Core @@ -905,6 +947,30 @@ $Header: /cvsroot/pgsql/doc/src/sgml/features.sgml,v 2.11 2002/12/06 05:07:12 mo INSERT statement: DEFAULT VALUES clause + + F231 + + Privilege Tables + + + + F231-01 + + TABLE_PRIVILEGES view + + + + F231-02 + + COLUMN_PRIVILEGES view + + + + F231-03 + + USAGE_PRIVILEGES view + + F251 @@ -1133,6 +1199,12 @@ $Header: /cvsroot/pgsql/doc/src/sgml/features.sgml,v 2.11 2002/12/06 05:07:12 mo Constraint management + + F501-03 + Core + SQL_LANGUAGES view + + F511 @@ -1557,48 +1629,6 @@ $Header: /cvsroot/pgsql/doc/src/sgml/features.sgml,v 2.11 2002/12/06 05:07:12 mo Module language - - F021 - Core - Basic information schema - - - - F021-01 - Core - COLUMNS view - - - - F021-02 - Core - TABLES view - - - - F021-03 - Core - VIEWS view - - - - F021-04 - Core - TABLE_CONSTRAINTS view - - - - F021-05 - Core - REFERENTIAL_CONSTRAINTS view - - - - F021-06 - Core - CHECK_CONSTRAINTS view - - F031-19 Core @@ -1667,30 +1697,6 @@ $Header: /cvsroot/pgsql/doc/src/sgml/features.sgml,v 2.11 2002/12/06 05:07:12 mo SET TRANSACTION statement: DIAGNOSTICS SIZE clause - - F231 - - Privilege Tables - - - - F231-01 - - TABLE_PRIVILEGES view - - - - F231-02 - - COLUMN_PRIVILEGES view - - - - F231-03 - - USAGE_PRIVILEGES view - - F291 @@ -1769,12 +1775,6 @@ $Header: /cvsroot/pgsql/doc/src/sgml/features.sgml,v 2.11 2002/12/06 05:07:12 mo SQL_SIZING view - - F501-03 - Core - SQL_LANGUAGES view - - F502 diff --git a/doc/src/sgml/release.sgml b/doc/src/sgml/release.sgml index ce54952e02..50e157654a 100644 --- a/doc/src/sgml/release.sgml +++ b/doc/src/sgml/release.sgml @@ -1,5 +1,5 @@ @@ -24,6 +24,7 @@ CDATA means the content is "SGML-free", so you can write without worries about funny characters. --> diff --git a/src/backend/Makefile b/src/backend/Makefile index 5cdfecac54..2365b21efd 100644 --- a/src/backend/Makefile +++ b/src/backend/Makefile @@ -4,7 +4,7 @@ # # Copyright (c) 1994, Regents of the University of California # -# $Header: /cvsroot/pgsql/src/backend/Makefile,v 1.88 2002/10/09 16:21:54 momjian Exp $ +# $Header: /cvsroot/pgsql/src/backend/Makefile,v 1.89 2002/12/14 00:24:23 petere Exp $ # #------------------------------------------------------------------------- @@ -131,7 +131,7 @@ ifeq ($(MAKE_DLL), true) $(INSTALL_DATA) libpostgres.a $(DESTDIR)$(libdir)/libpostgres.a endif endif - $(MAKE) -C catalog install-bki + $(MAKE) -C catalog install-data $(INSTALL_DATA) $(srcdir)/libpq/pg_hba.conf.sample $(DESTDIR)$(datadir)/pg_hba.conf.sample $(INSTALL_DATA) $(srcdir)/libpq/pg_ident.conf.sample $(DESTDIR)$(datadir)/pg_ident.conf.sample $(INSTALL_DATA) $(srcdir)/utils/misc/postgresql.conf.sample $(DESTDIR)$(datadir)/postgresql.conf.sample @@ -170,7 +170,7 @@ ifeq ($(MAKE_DLL), true) rm -f $(DESTDIR)$(libdir)/libpostgres.a endif endif - $(MAKE) -C catalog uninstall-bki + $(MAKE) -C catalog uninstall-data rm -f $(DESTDIR)$(datadir)/pg_hba.conf.sample \ $(DESTDIR)$(datadir)/pg_ident.conf.sample \ $(DESTDIR)$(datadir)/postgresql.conf.sample diff --git a/src/backend/catalog/Makefile b/src/backend/catalog/Makefile index 37681565ec..eb6201d548 100644 --- a/src/backend/catalog/Makefile +++ b/src/backend/catalog/Makefile @@ -2,7 +2,7 @@ # # Makefile for backend/catalog # -# $Header: /cvsroot/pgsql/src/backend/catalog/Makefile,v 1.42 2002/07/18 23:11:27 petere Exp $ +# $Header: /cvsroot/pgsql/src/backend/catalog/Makefile,v 1.43 2002/12/14 00:24:24 petere Exp $ # #------------------------------------------------------------------------- @@ -41,17 +41,18 @@ postgres.bki postgres.description: genbki.sh $(POSTGRES_BKI_SRCS) \ $(top_srcdir)/src/include/postgres_ext.h $(top_builddir)/src/include/pg_config.h CPP='$(CPP)' AWK='$(AWK)' $(SHELL) $< $(BKIOPTS) -o postgres $(pg_includes) $(POSTGRES_BKI_SRCS) --set-version=$(VERSION) -.PHONY: install-bki -install-bki: $(BKIFILES) installdirs +.PHONY: install-data +install-data: $(BKIFILES) installdirs $(INSTALL_DATA) postgres.bki $(DESTDIR)$(datadir)/postgres.bki $(INSTALL_DATA) postgres.description $(DESTDIR)$(datadir)/postgres.description + $(INSTALL_DATA) information_schema.sql $(DESTDIR)$(datadir)/information_schema.sql installdirs: $(mkinstalldirs) $(DESTDIR)$(datadir) -.PHONY: uninstall-bki -uninstall-bki: - rm -f $(addprefix $(DESTDIR)$(datadir)/, $(BKIFILES)) +.PHONY: uninstall-data +uninstall-data: + rm -f $(addprefix $(DESTDIR)$(datadir)/, $(BKIFILES) information_schema.sql) clean: diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql new file mode 100644 index 0000000000..58e26ea48a --- /dev/null +++ b/src/backend/catalog/information_schema.sql @@ -0,0 +1,516 @@ +/* + * SQL Information Schema + * as defined in ISO 9075-2:1999 chapter 20 + * + * Copyright 2002, PostgreSQL Global Development Group + * + * $Id: information_schema.sql,v 1.1 2002/12/14 00:24:24 petere Exp $ + */ + + +/* + * 20.2 + * INFORMATION_SCHEMA schema + */ + +CREATE SCHEMA information_schema; +GRANT USAGE ON SCHEMA information_schema TO PUBLIC; +SET search_path TO information_schema, public; + + +-- Note: 20.3 follows later. Some genius screwed up the order in the standard. + + +/* + * 20.4 + * CARDINAL_NUMBER domain + */ + +CREATE DOMAIN cardinal_number AS integer + CONSTRAINT cardinal_number_domain_check CHECK (value >= 0); + + +/* + * 20.5 + * CHARACTER_DATA domain + */ + +CREATE DOMAIN character_data AS character varying; + + +/* + * 20.6 + * SQL_IDENTIFIER domain + */ + +CREATE DOMAIN sql_identifier AS character varying; + + +/* + * 20.3 + * INFORMATION_SCHEMA_CATALOG_NAME view + */ + +CREATE VIEW information_schema_catalog_name AS + SELECT CAST(current_database() AS sql_identifier) AS catalog_name; + +GRANT SELECT ON information_schema_catalog_name TO PUBLIC; + + +/* + * 20.7 + * TIME_STAMP domain + */ + +CREATE DOMAIN time_stamp AS timestamp(2) + DEFAULT current_timestamp(2); + + +/* + * 20.13 + * CHECK_CONSTRAINTS view + */ + +CREATE VIEW check_constraints AS + SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog, + CAST(rs.nspname AS sql_identifier) AS constraint_schema, + CAST(con.conname AS sql_identifier) AS constraint_name, + CAST(con.consrc AS character_data) AS check_clause + FROM pg_namespace rs, pg_class c, pg_constraint con, pg_user u + WHERE rs.oid = c.relnamespace AND c.oid = con.conrelid + AND c.relowner = u.usesysid AND u.usename = current_user + AND con.contype = 'c'; + +GRANT SELECT ON check_constraints TO PUBLIC; + + +/* + * 20.15 + * COLUMN_DOMAIN_USAGE view + */ + +CREATE VIEW column_domain_usage AS + SELECT CAST(current_database() AS sql_identifier) AS domain_catalog, + CAST(nt.nspname AS sql_identifier) AS domain_schema, + CAST(t.typname AS sql_identifier) AS domain_name, + CAST(current_database() AS sql_identifier) AS table_catalog, + CAST(nc.nspname AS sql_identifier) AS table_schema, + CAST(c.relname AS sql_identifier) AS table_name, + CAST(a.attname AS sql_identifier) AS column_name + + FROM pg_type t, pg_namespace nt, pg_class c, pg_namespace nc, + pg_attribute a, pg_user u + + WHERE t.typnamespace = nt.oid AND t.typtype = 'd' + AND c.relnamespace = nc.oid AND a.attrelid = c.oid + AND a.atttypid = t.oid AND t.typowner = u.usesysid + AND u.usename = current_user; + +GRANT SELECT ON column_domain_usage TO PUBLIC; + + +/* + * 20.16 + * COLUMN_PRIVILEGES + */ + +-- PostgreSQL does not have column privileges, so this view is empty. +-- (Table privileges do not also count as column privileges.) + +CREATE VIEW column_privileges AS + SELECT CAST(null AS sql_identifier) AS grantor, + CAST(null AS sql_identifier) AS grantee, + CAST(null AS sql_identifier) AS table_catalog, + CAST(null AS sql_identifier) AS table_schema, + CAST(null AS sql_identifier) AS table_name, + CAST(null AS sql_identifier) AS column_name, + CAST(null AS character_data) AS privilege_type, + CAST(null AS character_data) AS is_grantable + WHERE false; + +GRANT SELECT ON column_privileges TO PUBLIC; + + +/* + * 20.18 + * COLUMNS view + */ + +CREATE VIEW columns AS + SELECT CAST(current_database() AS sql_identifier) AS table_catalog, + CAST(nc.nspname AS sql_identifier) AS table_schema, + CAST(c.relname AS sql_identifier) AS table_name, + CAST(a.attname AS sql_identifier) AS column_name, + CAST(a.attnum AS cardinal_number) AS ordinal_position, + CAST( + CASE WHEN u.usename = current_user THEN a.adsrc ELSE null END + AS character_data) + AS column_default, + CAST(CASE WHEN a.attnotnull THEN 'NO' ELSE 'YES' END + AS character_data) + AS is_nullable, + CAST(format_type(a.atttypid, null) AS character_data) + AS data_type, + + CAST( + CASE WHEN a.atttypid IN (25, 1042, 1043, 1560, 1562) AND a.atttypmod <> -1 + THEN a.atttypmod - 4 + ELSE null END + AS cardinal_number) + AS character_maximum_length, + + CAST( + CASE WHEN a.atttypid IN (25, 1042, 1043) THEN 2^30 ELSE null END + AS cardinal_number) + AS character_octet_length, + + CAST( + CASE WHEN a.atttypid IN (1700) THEN ((a.atttypmod - 4) >> 16) & 65535 ELSE null END + AS cardinal_number) + AS numeric_precision, + + CAST( + CASE WHEN a.atttypid IN (1700) THEN 10 ELSE null END + AS cardinal_number) + AS numeric_precision_radix, + + CAST( + CASE WHEN a.atttypid IN (1700) THEN (a.atttypmod - 4) & 65535 ELSE null END + AS cardinal_number) + AS numeric_scale, + + CAST( + CASE WHEN a.atttypid IN (1083, 1114, 1184, 1266) + THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod ELSE null END) + WHEN a.atttypid IN (1186) + THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod & 65535 ELSE null END) + ELSE null END + AS cardinal_number) + AS datetime_precision, + + CAST(null AS character_data) AS interval_type, -- XXX + CAST(null AS character_data) AS interval_precision, -- XXX + + CAST(null AS sql_identifier) AS character_set_catalog, + CAST(null AS sql_identifier) AS character_set_schema, + CAST(null AS sql_identifier) AS character_set_name, + + CAST(null AS sql_identifier) AS collation_catalog, + CAST(null AS sql_identifier) AS collation_schema, + CAST(null AS sql_identifier) AS collation_name, + + CAST(CASE WHEN t.typbasetype <> 0 THEN current_database() ELSE null END + AS sql_identifier) AS domain_catalog, + CAST(CASE WHEN t.typbasetype <> 0 THEN nt.nspname ELSE null END + AS sql_identifier) AS domain_schema, + CAST(CASE WHEN t.typbasetype <> 0 THEN t.typname ELSE null END + AS sql_identifier) AS domain_name, + + CAST(CASE WHEN t.typbasetype = 0 THEN current_database() ELSE null END + AS sql_identifier) AS udt_catalog, + CAST(CASE WHEN t.typbasetype = 0 THEN nt.nspname ELSE null END + AS sql_identifier) AS udt_schema, + CAST(CASE WHEN t.typbasetype = 0 THEN t.typname ELSE null END + AS sql_identifier) AS udt_name, + + CAST(null AS sql_identifier) AS scope_catalog, + CAST(null AS sql_identifier) AS scope_schema, + CAST(null AS sql_identifier) AS scope_name, + + CAST(null AS cardinal_number) AS maximum_cardinality, + CAST(null AS sql_identifier) AS dtd_identifier, + CAST('NO' AS character_data) AS is_self_referencing + + FROM (pg_attribute LEFT JOIN pg_attrdef ON attrelid = adrelid AND attnum = adnum) AS a, + pg_class c, pg_namespace nc, pg_type t, pg_namespace nt, pg_user u + + WHERE a.attrelid = c.oid + AND a.atttypid = t.oid + AND u.usesysid = c.relowner + AND nc.oid = c.relnamespace + AND nt.oid = t.typnamespace + AND u.usename = current_user + + AND a.attnum > 0 AND NOT a.attisdropped AND c.relkind in ('r', 'v'); + +GRANT SELECT ON columns TO PUBLIC; + + +/* + * 20.35 + * REFERENTIAL_CONSTRAINTS view + */ + +CREATE VIEW referential_constraints AS + SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog, + CAST(ncon.nspname AS sql_identifier) AS constraint_schema, + CAST(con.conname AS sql_identifier) AS constraint_name, + CAST(current_database() AS sql_identifier) AS unique_constraint_catalog, + CAST(null AS sql_identifier) AS unique_constraint_schema, -- XXX + CAST(null AS sql_identifier) AS unique_constraint_name, -- XXX + + CAST( + CASE con.confmatchtype WHEN 'f' THEN 'FULL' + WHEN 'p' THEN 'PARTIAL' + WHEN 'u' THEN 'NONE' END + AS character_data) AS match_option, + + CAST( + CASE con.confupdtype WHEN 'c' THEN 'CASCADE' + WHEN 'n' THEN 'SET NULL' + WHEN 'd' THEN 'SET DEFAULT' + WHEN 'r' THEN 'RESTRICT' + WHEN 'a' THEN 'NOACTION' END + AS character_data) AS update_rule, + + CAST( + CASE con.confdeltype WHEN 'c' THEN 'CASCADE' + WHEN 'n' THEN 'SET NULL' + WHEN 'd' THEN 'SET DEFAULT' + WHEN 'r' THEN 'RESTRICT' + WHEN 'a' THEN 'NOACTION' END + AS character_data) AS delete_rule + + FROM pg_namespace ncon, + pg_constraint con, + pg_class r, + pg_user u + + WHERE ncon.oid = con.connamespace + AND con.conrelid = r.oid AND r.relowner = u.usesysid + AND u.usename = current_user; + +GRANT SELECT ON referential_constraints TO PUBLIC; + + +/* + * 20.46 + * SCHEMATA view + */ + +CREATE VIEW schemata AS + SELECT CAST(current_database() AS sql_identifier) AS catalog_name, + CAST(n.nspname AS sql_identifier) AS schema_name, + CAST(u.usename AS sql_identifier) AS schema_owner, + CAST(null AS sql_identifier) AS default_character_set_catalog, + CAST(null AS sql_identifier) AS default_character_set_schema, + CAST(null AS sql_identifier) AS default_character_set_name, + CAST(null AS character_data) AS sql_path + FROM pg_namespace n, pg_user u + WHERE n.nspowner = u.usesysid AND u.usename = current_user; + +GRANT SELECT ON schemata TO PUBLIC; + + +/* + * 20.47 + * SQL_FEATURES table + */ + +CREATE TABLE sql_features ( + feature_id character_data, + feature_name character_data, + sub_feature_id character_data, + sub_feature_name character_data, + feature_subfeature_package_code character_data, + is_supported character_data, + is_verified_by character_data, + comments character_data +); + +-- FIXME: Fill this in using the information in User's Guide Appendix +-- C, and then figure out a way to generate the documentation from this +-- table. + +GRANT SELECT ON sql_features TO PUBLIC; + + +/* + * 20.49 + * SQL_LANGUAGES table + */ + +CREATE TABLE sql_languages ( + sql_language_source character_data, + sql_language_year character_data, + sql_language_conformance character_data, + sql_language_integrity character_data, + sql_language_implementation character_data, + sql_language_binding_style character_data, + sql_language_programming_language character_data +); + +INSERT INTO sql_languages VALUES ('ISO 9075', '1999', 'CORE', NULL, NULL, 'DIRECT', NULL); +INSERT INTO sql_languages VALUES ('ISO 9075', '1999', 'CORE', NULL, NULL, 'EMBEDDED', 'C'); + +GRANT SELECT ON sql_languages TO PUBLIC; + + +/* + * 20.53 + * TABLE_CONSTRAINTS view + */ + +CREATE VIEW table_constraints AS + SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog, + CAST(nc.nspname AS sql_identifier) AS constraint_schema, + CAST(c.conname AS sql_identifier) AS constraint_name, + CAST(current_database() AS sql_identifier) AS table_catalog, + CAST(nr.nspname AS sql_identifier) AS table_schema, + CAST(r.relname AS sql_identifier) AS table_name, + CAST( + CASE c.contype WHEN 'c' THEN 'CHECK' + WHEN 'f' THEN 'FOREIGN KEY' + WHEN 'p' THEN 'PRIMARY KEY' + WHEN 'u' THEN 'UNIQUE' END + AS character_data) AS constraint_type, + CAST(CASE WHEN c.condeferrable THEN 'YES' ELSE 'NO' END AS character_data) + AS is_deferrable, + CAST(CASE WHEN c.condeferred THEN 'YES' ELSE 'NO' END AS character_data) + AS initially_deferred + + FROM pg_namespace nc, + pg_namespace nr, + pg_constraint c, + pg_class r, + pg_user u + + WHERE nc.oid = c.connamespace AND nr.oid = r.relnamespace + AND c.conrelid = r.oid AND r.relowner = u.usesysid + AND u.usename = current_user; + +-- FIMXE: Not-null constraints are missing here. + +GRANT SELECT ON table_constraints TO PUBLIC; + + +/* + * 20.55 + * TABLE_PRIVILEGES view + */ + +CREATE VIEW table_privileges AS + SELECT CAST(u_owner.usename AS sql_identifier) AS grantor, + CAST(u_grantee.usename AS sql_identifier) AS grantee, + CAST(current_database() AS sql_identifier) AS table_catalog, + CAST(nc.nspname AS sql_identifier) AS table_schema, + CAST(c.relname AS sql_identifier) AS table_name, + CAST(pr.type AS character_data) AS privilege_type, + CAST('NO' AS character_data) AS is_grantable, + CAST('NO' AS character_data) AS with_hierarchy + + FROM pg_user u_owner, + pg_user u_grantee, + pg_namespace nc, + pg_class c, + (SELECT 'SELECT' UNION SELECT 'DELETE' UNION SELECT 'INSERT' UNION SELECT 'UPDATE' + UNION SELECT 'REFERENCES' UNION SELECT 'TRIGGER') AS pr (type) + + WHERE u_owner.usesysid = c.relowner + AND c.relnamespace = nc.oid + AND has_table_privilege(u_grantee.usename, c.oid, pr.type) + + AND (u_owner.usename = current_user OR u_grantee.usename = current_user); + +GRANT SELECT ON table_privileges TO PUBLIC; + + +/* + * 20.56 + * TABLES view + */ + +CREATE VIEW tables AS + SELECT CAST(current_database() AS sql_identifier) AS table_catalog, + CAST(nc.nspname AS sql_identifier) AS table_schema, + CAST(c.relname AS sql_identifier) AS table_name, + + CAST( + CASE WHEN nc.nspname LIKE 'pg!_temp!_%' ESCAPE '!' THEN 'LOCAL TEMPORARY' + WHEN c.relkind = 'r' THEN 'BASE TABLE' + WHEN c.relkind = 'v' THEN 'VIEW' + ELSE null END + AS character_data) AS table_type, + + CAST(null AS sql_identifier) AS self_referencing_column_name, + CAST(null AS character_data) AS reference_generation, + + CAST(null AS sql_identifier) AS user_defined_type_catalog, + CAST(null AS sql_identifier) AS user_defined_type_schema, + CAST(null AS sql_identifier) AS user_defined_name + + FROM pg_namespace nc, pg_class c, pg_user u + + WHERE c.relnamespace = nc.oid AND u.usesysid = c.relowner + AND (u.usename = current_user + OR EXISTS(SELECT 1 FROM information_schema.table_privileges tp + WHERE tp.table_schema = nc.nspname + AND tp.table_name = c.relname + AND tp.grantee = current_user)) + + AND c.relkind IN ('r', 'v'); + +GRANT SELECT ON tables TO PUBLIC; + + +/* + * 20.63 + * USAGE_PRIVILEGES view + */ + +-- Of the things currently implemented in PostgreSQL, usage privileges +-- apply only to domains. Since domains have no real privileges, we +-- represent all domains with implicit usage privilege here. + +CREATE VIEW usage_privileges AS + SELECT CAST(u.usename AS sql_identifier) AS grantor, + CAST('PUBLIC' AS sql_identifier) AS grantee, + CAST(current_database() AS sql_identifier) AS object_catalog, + CAST(n.nspname AS sql_identifier) AS object_schema, + CAST(t.typname AS sql_identifier) AS object_name, + CAST('DOMAIN' AS character_data) AS object_type, + CAST('USAGE' AS character_data) AS privilege_type, + CAST('NO' AS character_data) AS is_grantable + + FROM pg_user u, + pg_namespace n, + pg_type t + + WHERE u.usesysid = t.typowner + AND t.typnamespace = n.oid + AND t.typtype = 'd'; + +GRANT SELECT ON usage_privileges TO PUBLIC; + + +/* + * 20.68 + * VIEWS view + */ + +CREATE VIEW views AS + SELECT CAST(current_database() AS sql_identifier) AS table_catalog, + CAST(nc.nspname AS sql_identifier) AS table_schema, + CAST(c.relname AS sql_identifier) AS table_name, + + CAST( + CASE WHEN u.usename = current_user THEN pg_get_viewdef(c.oid) + ELSE null END + AS character_data) AS view_definition, + + CAST('NONE' AS character_data) AS check_option, + CAST(null AS character_data) AS is_updatable, -- FIXME + CAST(null AS character_data) AS is_insertable_into -- FIXME + + FROM pg_namespace nc, pg_class c, pg_user u + + WHERE c.relnamespace = nc.oid AND u.usesysid = c.relowner + AND (u.usename = current_user + OR EXISTS(SELECT 1 FROM information_schema.table_privileges tp + WHERE tp.table_schema = nc.nspname + AND tp.table_name = c.relname + AND tp.grantee = current_user)) + + AND c.relkind = 'v'; + +GRANT SELECT ON views TO PUBLIC; diff --git a/src/bin/initdb/initdb.sh b/src/bin/initdb/initdb.sh index cfdf0fa0b9..a1c806cc7e 100644 --- a/src/bin/initdb/initdb.sh +++ b/src/bin/initdb/initdb.sh @@ -27,7 +27,7 @@ # Portions Copyright (c) 1996-2002, 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.177 2002/11/25 21:41:46 momjian Exp $ +# $Header: /cvsroot/pgsql/src/bin/initdb/Attic/initdb.sh,v 1.178 2002/12/14 00:24:24 petere Exp $ # #------------------------------------------------------------------------- @@ -1042,6 +1042,10 @@ EOF | "$PGPATH"/postgres $PGSQL_OPT template1 > /dev/null || exit_nicely echo "ok" +$ECHO_N "creating information schema... "$ECHO_C +"$PGPATH"/postgres $PGSQL_OPT -N template1 > /dev/null < "$datadir"/information_schema.sql || exit_nicely +echo "ok" + $ECHO_N "vacuuming database template1... "$ECHO_C "$PGPATH"/postgres $PGSQL_OPT template1 >/dev/null < 'information_schema' ORDER BY viewname; 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); diff --git a/src/test/regress/expected/type_sanity.out b/src/test/regress/expected/type_sanity.out index 03fbae2cad..46c153e5d1 100644 --- a/src/test/regress/expected/type_sanity.out +++ b/src/test/regress/expected/type_sanity.out @@ -59,7 +59,7 @@ WHERE (p1.typtype = 'c' AND p1.typrelid = 0) OR -- NOTE: as of 7.3, this check finds SET, smgr, and unknown. SELECT p1.oid, p1.typname FROM pg_type as p1 -WHERE p1.typtype in ('b','d') AND p1.typname NOT LIKE '\\_%' AND NOT EXISTS +WHERE p1.typtype in ('b') AND p1.typname NOT LIKE '\\_%' AND NOT EXISTS (SELECT 1 FROM pg_type as p2 WHERE p2.typname = ('_' || p1.typname)::name AND p2.typelem = p1.oid); diff --git a/src/test/regress/input/create_function_2.source b/src/test/regress/input/create_function_2.source index 4bcf24c601..07d26c1d8f 100644 --- a/src/test/regress/input/create_function_2.source +++ b/src/test/regress/input/create_function_2.source @@ -28,8 +28,9 @@ CREATE FUNCTION equipment(hobbies_r) CREATE FUNCTION user_relns() RETURNS setof name AS 'select relname - from pg_class - where relname !~ ''pg_.*'' and + from pg_class c, pg_namespace n + where relnamespace = n.oid and + (nspname !~ ''pg_.*'' and nspname <> ''information_schema'') and relkind <> ''i'' ' LANGUAGE 'sql'; diff --git a/src/test/regress/output/create_function_2.source b/src/test/regress/output/create_function_2.source index 4d508497cf..58a3c550f6 100644 --- a/src/test/regress/output/create_function_2.source +++ b/src/test/regress/output/create_function_2.source @@ -22,8 +22,9 @@ CREATE FUNCTION equipment(hobbies_r) CREATE FUNCTION user_relns() RETURNS setof name AS 'select relname - from pg_class - where relname !~ ''pg_.*'' and + from pg_class c, pg_namespace n + where relnamespace = n.oid and + (nspname !~ ''pg_.*'' and nspname <> ''information_schema'') and relkind <> ''i'' ' LANGUAGE 'sql'; CREATE FUNCTION pt_in_widget(point, widget) diff --git a/src/test/regress/sql/rules.sql b/src/test/regress/sql/rules.sql index 3179a851eb..a2c01c6e93 100644 --- a/src/test/regress/sql/rules.sql +++ b/src/test/regress/sql/rules.sql @@ -763,7 +763,7 @@ drop table cchild; -- -- Check that ruleutils are working -- -SELECT viewname, definition FROM pg_views ORDER BY viewname; +SELECT viewname, definition FROM pg_views WHERE schemaname <> 'information_schema' ORDER BY viewname; SELECT tablename, rulename, definition FROM pg_rules ORDER BY tablename, rulename; diff --git a/src/test/regress/sql/type_sanity.sql b/src/test/regress/sql/type_sanity.sql index 4f827cd8ba..0cc4748fa8 100644 --- a/src/test/regress/sql/type_sanity.sql +++ b/src/test/regress/sql/type_sanity.sql @@ -54,7 +54,7 @@ WHERE (p1.typtype = 'c' AND p1.typrelid = 0) OR SELECT p1.oid, p1.typname FROM pg_type as p1 -WHERE p1.typtype in ('b','d') AND p1.typname NOT LIKE '\\_%' AND NOT EXISTS +WHERE p1.typtype in ('b') AND p1.typname NOT LIKE '\\_%' AND NOT EXISTS (SELECT 1 FROM pg_type as p2 WHERE p2.typname = ('_' || p1.typname)::name AND p2.typelem = p1.oid);