From 3d3c8bf658f57cb2dd7d4688f65d769616e01b31 Mon Sep 17 00:00:00 2001
From: Robins Tharakan <robins@pobox.com>
Date: Sat, 16 Mar 2013 04:20:46 +0530
Subject: [PATCH] Add regression tests for SCHEMA

---
 src/test/regress/expected/schema.out |  144 ++++++++++++++++++++++++++++++++++
 src/test/regress/parallel_schedule   |    2 +-
 src/test/regress/sql/schema.sql      |  141 +++++++++++++++++++++++++++++++++
 3 files changed, 286 insertions(+), 1 deletion(-)
 create mode 100644 src/test/regress/expected/schema.out
 create mode 100644 src/test/regress/sql/schema.sql

diff --git a/src/test/regress/expected/schema.out b/src/test/regress/expected/schema.out
new file mode 100644
index 0000000..8a87337
--- /dev/null
+++ b/src/test/regress/expected/schema.out
@@ -0,0 +1,144 @@
+--
+-- SCHEMA Commands
+--
+CREATE SCHEMA schema_sch1;
+DROP SCHEMA schema_sch1;
+-- Should fail. Disallow CREATE SCHEMA by ROLE with insufficient permission
+CREATE ROLE role_sch1;
+SET ROLE role_sch1;
+CREATE SCHEMA schema_sch2;
+ERROR:  permission denied for database regression
+RESET ROLE;
+DROP ROLE role_sch1;
+-- Should fail. Disallow CREATE SCHEMA if using a reserved name
+CREATE SCHEMA pg_asdf;
+ERROR:  unacceptable schema name "pg_asdf"
+DETAIL:  The prefix "pg_" is reserved for system schemas.
+-- Should fail. Disallow CREATE SCHEMA if already exists
+CREATE SCHEMA public;
+ERROR:  schema "public" already exists
+-- Ensure CREATE SCHEMA uses current_user (and not necessarily session_user)
+CREATE ROLE role_sch1;
+GRANT CREATE ON DATABASE regression to role_sch1;
+SET ROLE role_sch1;
+CREATE SCHEMA schema_sch2;
+SELECT schema_owner
+FROM information_schema.schemata
+WHERE schema_name <> 'information_schema'
+  AND schema_name !~ E'^pg_';
+ schema_owner 
+--------------
+ role_sch1
+(1 row)
+
+DROP SCHEMA schema_sch2;
+RESET ROLE;
+REVOKE CREATE ON DATABASE regression FROM role_sch1;
+DROP ROLE role_sch1;
+-- RENAME SCHEMA
+CREATE SCHEMA schema_sch1;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+DROP SCHEMA schema_sch2;
+-- ALTER SCHEMA ok for user created IN ROLE of one with CREATE DATABASE rights
+CREATE ROLE role_sch3;
+GRANT CREATE ON DATABASE regression to role_sch3;
+CREATE ROLE role_sch4 IN ROLE role_sch3;
+SET ROLE role_sch3;
+CREATE SCHEMA schema_sch3;
+SET ROLE role_sch4;
+ALTER SCHEMA schema_sch3 RENAME TO schema_sch5;
+ALTER SCHEMA schema_sch5 OWNER TO role_sch4;
+DROP SCHEMA schema_sch5;
+RESET ROLE;
+REVOKE CREATE ON DATABASE regression FROM role_sch3;
+SET ROLE role_sch3;
+RESET ROLE;
+DROP ROLE role_sch4;
+DROP ROLE role_sch3;
+-- Should work, REASSIGN OWNED objects to another OWNER
+CREATE ROLE role_sch3;
+GRANT CREATE ON DATABASE regression to role_sch3;
+CREATE ROLE role_sch4;
+SET ROLE role_sch3;
+CREATE SCHEMA schema_sch3;
+RESET ROLE;
+REVOKE CREATE ON DATABASE regression FROM role_sch3;
+REASSIGN OWNED BY role_sch3 TO role_sch4;
+SET ROLE role_sch4;
+DROP SCHEMA schema_sch3;
+RESET ROLE;
+DROP ROLE role_sch4;
+DROP ROLE role_sch3;
+-- Should fail. Shouldn't RENAME SCHEMA if invalid / already existing / etc.
+CREATE SCHEMA schema_sch1;
+CREATE SCHEMA schema_sch3;
+ALTER SCHEMA schema_sch3 RENAME TO schema_sch1;
+ERROR:  schema "schema_sch1" already exists
+ALTER SCHEMA schema_sch3 RENAME TO public;
+ERROR:  schema "public" already exists
+ALTER SCHEMA schema_sch3 RENAME TO pg_asdf;
+ERROR:  unacceptable schema name "pg_asdf"
+DETAIL:  The prefix "pg_" is reserved for system schemas.
+DROP SCHEMA schema_sch1;
+DROP SCHEMA schema_sch3;
+-- Should fail. Shouldn't ALTER SCHEMA if not OWNER
+CREATE SCHEMA schema_sch1;
+CREATE ROLE role_sch1;
+SET ROLE role_sch1;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+ERROR:  must be owner of schema schema_sch1
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+ERROR:  must be owner of schema schema_sch1
+RESET ROLE;
+DROP SCHEMA schema_sch1;
+DROP ROLE role_sch1;
+-- Should work. Non-Owner with CREATE ON DATABASE priviledge can RENAME SCHEMA
+CREATE ROLE role_sch1;
+GRANT CREATE ON DATABASE regression to role_sch1;
+SET ROLE role_sch1;
+CREATE SCHEMA schema_sch1;
+RESET ROLE;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+DROP SCHEMA schema_sch2;
+REVOKE CREATE ON DATABASE regression FROM role_sch1;
+DROP ROLE role_sch1;
+-- Should fail. OWNER without CREATE ON DATABASE can't ALTER OWNER SCHEMA
+CREATE ROLE role_sch1;
+CREATE SCHEMA schema_sch1 AUTHORIZATION role_sch1;
+CREATE ROLE role_sch2;
+GRANT role_sch2 TO role_sch1;
+SET ROLE role_sch1;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+ERROR:  permission denied for database regression
+ALTER SCHEMA schema_sch1 OWNER TO role_sch2;
+ERROR:  permission denied for database regression
+RESET ROLE;
+DROP SCHEMA schema_sch1;
+REVOKE role_sch2 FROM role_sch1;
+DROP ROLE role_sch2;
+DROP ROLE role_sch1;
+-- Should work. Try to have multiple OWNERships for a ROLE
+CREATE ROLE role_sch1;
+CREATE ROLE role_sch2;
+CREATE SCHEMA schema_sch1;
+GRANT CREATE ON SCHEMA schema_sch1 TO role_sch1;
+GRANT ALL ON SCHEMA schema_sch1 TO role_sch2;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+REVOKE CREATE ON SCHEMA schema_sch1 FROM role_sch1;
+REVOKE ALL ON SCHEMA schema_sch1 FROM role_sch2;
+DROP SCHEMA schema_sch1;
+DROP ROLE role_sch2;
+DROP ROLE role_sch1;
+-- Change OWNER of SCHEMA
+CREATE SCHEMA schema_sch1;
+CREATE ROLE role_sch1;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+DROP SCHEMA schema_sch1;
+DROP ROLE role_sch1;
+-- Should fail. Can't change OWNER of SCHEMA if doesn't exist/invalid name/etc.
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+ERROR:  schema "schema_sch1" does not exist
+CREATE ROLE role_sch1;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+ERROR:  schema "schema_sch1" does not exist
+DROP ROLE role_sch1;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2af28b1..7d23aaa 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ ignore: random
 # ----------
 # Another group of parallel tests
 # ----------
-test: select_into select_distinct select_distinct_on select_implicit select_having subselect union case join aggregates transactions random portals arrays btree_index hash_index update namespace prepared_xacts delete
+test: select_into select_distinct select_distinct_on select_implicit select_having subselect union case join aggregates transactions random portals arrays btree_index hash_index update namespace prepared_xacts delete schema
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/schema.sql b/src/test/regress/sql/schema.sql
new file mode 100644
index 0000000..0207729
--- /dev/null
+++ b/src/test/regress/sql/schema.sql
@@ -0,0 +1,141 @@
+--
+-- SCHEMA Commands
+--
+
+CREATE SCHEMA schema_sch1;
+DROP SCHEMA schema_sch1;
+
+-- Should fail. Disallow CREATE SCHEMA by ROLE with insufficient permission
+CREATE ROLE role_sch1;
+SET ROLE role_sch1;
+CREATE SCHEMA schema_sch2;
+RESET ROLE;
+DROP ROLE role_sch1;
+
+-- Should fail. Disallow CREATE SCHEMA if using a reserved name
+CREATE SCHEMA pg_asdf;
+
+-- Should fail. Disallow CREATE SCHEMA if already exists
+CREATE SCHEMA public;
+
+-- Ensure CREATE SCHEMA uses current_user (and not necessarily session_user)
+CREATE ROLE role_sch1;
+GRANT CREATE ON DATABASE regression to role_sch1;
+SET ROLE role_sch1;
+CREATE SCHEMA schema_sch2;
+SELECT schema_owner
+FROM information_schema.schemata
+WHERE schema_name <> 'information_schema'
+  AND schema_name !~ E'^pg_';
+DROP SCHEMA schema_sch2;
+RESET ROLE;
+REVOKE CREATE ON DATABASE regression FROM role_sch1;
+DROP ROLE role_sch1;
+
+-- RENAME SCHEMA
+CREATE SCHEMA schema_sch1;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+DROP SCHEMA schema_sch2;
+
+-- ALTER SCHEMA ok for user created IN ROLE of one with CREATE DATABASE rights
+CREATE ROLE role_sch3;
+GRANT CREATE ON DATABASE regression to role_sch3;
+CREATE ROLE role_sch4 IN ROLE role_sch3;
+SET ROLE role_sch3;
+CREATE SCHEMA schema_sch3;
+SET ROLE role_sch4;
+ALTER SCHEMA schema_sch3 RENAME TO schema_sch5;
+ALTER SCHEMA schema_sch5 OWNER TO role_sch4;
+DROP SCHEMA schema_sch5;
+RESET ROLE;
+REVOKE CREATE ON DATABASE regression FROM role_sch3;
+SET ROLE role_sch3;
+RESET ROLE;
+DROP ROLE role_sch4;
+DROP ROLE role_sch3;
+
+-- Should work, REASSIGN OWNED objects to another OWNER
+CREATE ROLE role_sch3;
+GRANT CREATE ON DATABASE regression to role_sch3;
+CREATE ROLE role_sch4;
+SET ROLE role_sch3;
+CREATE SCHEMA schema_sch3;
+RESET ROLE;
+REVOKE CREATE ON DATABASE regression FROM role_sch3;
+REASSIGN OWNED BY role_sch3 TO role_sch4;
+SET ROLE role_sch4;
+DROP SCHEMA schema_sch3;
+RESET ROLE;
+DROP ROLE role_sch4;
+DROP ROLE role_sch3;
+
+-- Should fail. Shouldn't RENAME SCHEMA if invalid / already existing / etc.
+CREATE SCHEMA schema_sch1;
+CREATE SCHEMA schema_sch3;
+ALTER SCHEMA schema_sch3 RENAME TO schema_sch1;
+ALTER SCHEMA schema_sch3 RENAME TO public;
+ALTER SCHEMA schema_sch3 RENAME TO pg_asdf;
+DROP SCHEMA schema_sch1;
+DROP SCHEMA schema_sch3;
+
+-- Should fail. Shouldn't ALTER SCHEMA if not OWNER
+CREATE SCHEMA schema_sch1;
+CREATE ROLE role_sch1;
+SET ROLE role_sch1;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+RESET ROLE;
+DROP SCHEMA schema_sch1;
+DROP ROLE role_sch1;
+
+-- Should work. Non-Owner with CREATE ON DATABASE priviledge can RENAME SCHEMA
+CREATE ROLE role_sch1;
+GRANT CREATE ON DATABASE regression to role_sch1;
+SET ROLE role_sch1;
+CREATE SCHEMA schema_sch1;
+RESET ROLE;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+DROP SCHEMA schema_sch2;
+REVOKE CREATE ON DATABASE regression FROM role_sch1;
+DROP ROLE role_sch1;
+
+-- Should fail. OWNER without CREATE ON DATABASE can't ALTER OWNER SCHEMA
+CREATE ROLE role_sch1;
+CREATE SCHEMA schema_sch1 AUTHORIZATION role_sch1;
+CREATE ROLE role_sch2;
+GRANT role_sch2 TO role_sch1;
+SET ROLE role_sch1;
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch2;
+RESET ROLE;
+DROP SCHEMA schema_sch1;
+REVOKE role_sch2 FROM role_sch1;
+DROP ROLE role_sch2;
+DROP ROLE role_sch1;
+
+-- Should work. Try to have multiple OWNERships for a ROLE
+CREATE ROLE role_sch1;
+CREATE ROLE role_sch2;
+CREATE SCHEMA schema_sch1;
+GRANT CREATE ON SCHEMA schema_sch1 TO role_sch1;
+GRANT ALL ON SCHEMA schema_sch1 TO role_sch2;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+REVOKE CREATE ON SCHEMA schema_sch1 FROM role_sch1;
+REVOKE ALL ON SCHEMA schema_sch1 FROM role_sch2;
+DROP SCHEMA schema_sch1;
+DROP ROLE role_sch2;
+DROP ROLE role_sch1;
+
+-- Change OWNER of SCHEMA
+CREATE SCHEMA schema_sch1;
+CREATE ROLE role_sch1;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+DROP SCHEMA schema_sch1;
+DROP ROLE role_sch1;
+
+-- Should fail. Can't change OWNER of SCHEMA if doesn't exist/invalid name/etc.
+ALTER SCHEMA schema_sch1 RENAME TO schema_sch2;
+CREATE ROLE role_sch1;
+ALTER SCHEMA schema_sch1 OWNER TO role_sch1;
+DROP ROLE role_sch1;
+
-- 
1.7.10.4

