postgresql/contrib/sepgsql/sql/alter.sql
Andres Freund 578b229718 Remove WITH OIDS support, change oid catalog column visibility.
Previously tables declared WITH OIDS, including a significant fraction
of the catalog tables, stored the oid column not as a normal column,
but as part of the tuple header.

This special column was not shown by default, which was somewhat odd,
as it's often (consider e.g. pg_class.oid) one of the more important
parts of a row.  Neither pg_dump nor COPY included the contents of the
oid column by default.

The fact that the oid column was not an ordinary column necessitated a
significant amount of special case code to support oid columns. That
already was painful for the existing, but upcoming work aiming to make
table storage pluggable, would have required expanding and duplicating
that "specialness" significantly.

WITH OIDS has been deprecated since 2005 (commit ff02d0a05280e0).
Remove it.

Removing includes:
- CREATE TABLE and ALTER TABLE syntax for declaring the table to be
  WITH OIDS has been removed (WITH (oids[ = true]) will error out)
- pg_dump does not support dumping tables declared WITH OIDS and will
  issue a warning when dumping one (and ignore the oid column).
- restoring an pg_dump archive with pg_restore will warn when
  restoring a table with oid contents (and ignore the oid column)
- COPY will refuse to load binary dump that includes oids.
- pg_upgrade will error out when encountering tables declared WITH
  OIDS, they have to be altered to remove the oid column first.
- Functionality to access the oid of the last inserted row (like
  plpgsql's RESULT_OID, spi's SPI_lastoid, ...) has been removed.

The syntax for declaring a table WITHOUT OIDS (or WITH (oids = false)
for CREATE TABLE) is still supported. While that requires a bit of
support code, it seems unnecessary to break applications / dumps that
do not use oids, and are explicit about not using them.

The biggest user of WITH OID columns was postgres' catalog. This
commit changes all 'magic' oid columns to be columns that are normally
declared and stored. To reduce unnecessary query breakage all the
newly added columns are still named 'oid', even if a table's column
naming scheme would indicate 'reloid' or such.  This obviously
requires adapting a lot code, mostly replacing oid access via
HeapTupleGetOid() with access to the underlying Form_pg_*->oid column.

The bootstrap process now assigns oids for all oid columns in
genbki.pl that do not have an explicit value (starting at the largest
oid previously used), only oids assigned later by oids will be above
FirstBootstrapObjectId. As the oid column now is a normal column the
special bootstrap syntax for oids has been removed.

Oids are not automatically assigned during insertion anymore, all
backend code explicitly assigns oids with GetNewOidWithIndex(). For
the rare case that insertions into the catalog via SQL are called for
the new pg_nextoid() function can be used (which only works on catalog
tables).

The fact that oid columns on system tables are now normal columns
means that they will be included in the set of columns expanded
by * (i.e. SELECT * FROM pg_class will now include the table's oid,
previously it did not). It'd not technically be hard to hide oid
column by default, but that'd mean confusing behavior would either
have to be carried forward forever, or it'd cause breakage down the
line.

While it's not unlikely that further adjustments are needed, the
scope/invasiveness of the patch makes it worthwhile to get merge this
now. It's painful to maintain externally, too complicated to commit
after the code code freeze, and a dependency of a number of other
patches.

Catversion bump, for obvious reasons.

Author: Andres Freund, with contributions by John Naylor
Discussion: https://postgr.es/m/20180930034810.ywp2c7awz7opzcfr@alap3.anarazel.de
2018-11-20 16:00:17 -08:00

198 lines
8.1 KiB
PL/PgSQL

--
-- Test for various ALTER statements
--
-- clean-up in case a prior regression run failed
SET client_min_messages TO 'warning';
DROP DATABASE IF EXISTS sepgsql_test_regression_1;
DROP DATABASE IF EXISTS sepgsql_test_regression;
DROP USER IF EXISTS regress_sepgsql_test_user;
RESET client_min_messages;
-- @SECURITY-CONTEXT=unconfined_u:unconfined_r:sepgsql_regtest_superuser_t:s0
--
-- CREATE Objects to be altered (with debug_audit being silent)
--
CREATE DATABASE sepgsql_test_regression_1;
CREATE USER regress_sepgsql_test_user;
CREATE SCHEMA regtest_schema_1;
CREATE SCHEMA regtest_schema_2;
GRANT ALL ON SCHEMA regtest_schema_1 TO public;
GRANT ALL ON SCHEMA regtest_schema_2 TO public;
SET search_path = regtest_schema_1, regtest_schema_2, public;
CREATE TABLE regtest_table_1 (a int, b text);
CREATE TABLE regtest_table_2 (c text) inherits (regtest_table_1);
CREATE TABLE regtest_table_3 (x int primary key, y text);
---
-- partitioned table parent
CREATE TABLE regtest_ptable_1 (o int, p text) PARTITION BY RANGE (o);
-- partitioned table children
CREATE TABLE regtest_ptable_1_ones PARTITION OF regtest_ptable_1 FOR VALUES FROM ('0') TO ('10');
CREATE TABLE regtest_ptable_1_tens PARTITION OF regtest_ptable_1 FOR VALUES FROM ('10') TO ('100');
---
CREATE SEQUENCE regtest_seq_1;
CREATE VIEW regtest_view_1 AS SELECT * FROM regtest_table_1 WHERE a > 0;
CREATE FUNCTION regtest_func_1 (text) RETURNS bool
AS 'BEGIN RETURN true; END' LANGUAGE 'plpgsql';
-- switch on debug_audit
SET sepgsql.debug_audit = true;
SET client_min_messages = LOG;
--
-- ALTER xxx OWNER TO
--
-- XXX: It should take db_xxx:{setattr} permission checks even if
-- owner is not actually changed.
--
ALTER DATABASE sepgsql_test_regression_1 OWNER TO regress_sepgsql_test_user;
ALTER DATABASE sepgsql_test_regression_1 OWNER TO regress_sepgsql_test_user;
ALTER SCHEMA regtest_schema_1 OWNER TO regress_sepgsql_test_user;
ALTER SCHEMA regtest_schema_1 OWNER TO regress_sepgsql_test_user;
ALTER TABLE regtest_table_1 OWNER TO regress_sepgsql_test_user;
ALTER TABLE regtest_table_1 OWNER TO regress_sepgsql_test_user;
ALTER TABLE regtest_ptable_1 OWNER TO regress_sepgsql_test_user;
ALTER TABLE regtest_ptable_1_ones OWNER TO regress_sepgsql_test_user;
ALTER SEQUENCE regtest_seq_1 OWNER TO regress_sepgsql_test_user;
ALTER SEQUENCE regtest_seq_1 OWNER TO regress_sepgsql_test_user;
ALTER VIEW regtest_view_1 OWNER TO regress_sepgsql_test_user;
ALTER VIEW regtest_view_1 OWNER TO regress_sepgsql_test_user;
ALTER FUNCTION regtest_func_1(text) OWNER TO regress_sepgsql_test_user;
ALTER FUNCTION regtest_func_1(text) OWNER TO regress_sepgsql_test_user;
--
-- ALTER xxx SET SCHEMA
--
ALTER TABLE regtest_table_1 SET SCHEMA regtest_schema_2;
ALTER TABLE regtest_ptable_1 SET SCHEMA regtest_schema_2;
ALTER TABLE regtest_ptable_1_ones SET SCHEMA regtest_schema_2;
ALTER SEQUENCE regtest_seq_1 SET SCHEMA regtest_schema_2;
ALTER VIEW regtest_view_1 SET SCHEMA regtest_schema_2;
ALTER FUNCTION regtest_func_1(text) SET SCHEMA regtest_schema_2;
--
-- ALTER xxx RENAME TO
--
ALTER DATABASE sepgsql_test_regression_1 RENAME TO sepgsql_test_regression;
ALTER SCHEMA regtest_schema_1 RENAME TO regtest_schema;
ALTER TABLE regtest_table_1 RENAME TO regtest_table;
---
-- partitioned table parent
ALTER TABLE regtest_ptable_1 RENAME TO regtest_ptable;
-- partitioned table child
ALTER TABLE regtest_ptable_1_ones RENAME TO regtest_table_part;
---
ALTER SEQUENCE regtest_seq_1 RENAME TO regtest_seq;
ALTER VIEW regtest_view_1 RENAME TO regtest_view;
ALTER FUNCTION regtest_func_1(text) RENAME TO regtest_func;
SET search_path = regtest_schema, regtest_schema_2, public;
--
-- misc ALTER commands
--
ALTER DATABASE sepgsql_test_regression CONNECTION LIMIT 999;
ALTER DATABASE sepgsql_test_regression SET search_path TO regtest_schema, public; -- not supported yet
ALTER TABLE regtest_table ADD COLUMN d float;
ALTER TABLE regtest_table DROP COLUMN d;
ALTER TABLE regtest_table ALTER b SET DEFAULT 'abcd'; -- not supported yet
ALTER TABLE regtest_table ALTER b SET DEFAULT 'XYZ'; -- not supported yet
ALTER TABLE regtest_table ALTER b DROP DEFAULT; -- not supported yet
ALTER TABLE regtest_table ALTER b SET NOT NULL;
ALTER TABLE regtest_table ALTER b DROP NOT NULL;
ALTER TABLE regtest_table ALTER b SET STATISTICS -1;
ALTER TABLE regtest_table ALTER b SET (n_distinct = 999);
ALTER TABLE regtest_table ALTER b SET STORAGE PLAIN;
ALTER TABLE regtest_table ADD CONSTRAINT test_fk FOREIGN KEY (a) REFERENCES regtest_table_3(x); -- not supported
ALTER TABLE regtest_table ADD CONSTRAINT test_ck CHECK (b like '%abc%') NOT VALID; -- not supported
ALTER TABLE regtest_table VALIDATE CONSTRAINT test_ck; -- not supported
ALTER TABLE regtest_table DROP CONSTRAINT test_ck; -- not supported
CREATE TRIGGER regtest_test_trig BEFORE UPDATE ON regtest_table
FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
ALTER TABLE regtest_table DISABLE TRIGGER regtest_test_trig; -- not supported
ALTER TABLE regtest_table ENABLE TRIGGER regtest_test_trig; -- not supported
CREATE RULE regtest_test_rule AS ON INSERT TO regtest_table_3 DO ALSO NOTHING;
ALTER TABLE regtest_table_3 DISABLE RULE regtest_test_rule; -- not supported
ALTER TABLE regtest_table_3 ENABLE RULE regtest_test_rule; -- not supported
ALTER TABLE regtest_table SET (fillfactor = 75);
ALTER TABLE regtest_table RESET (fillfactor);
ALTER TABLE regtest_table_2 NO INHERIT regtest_table; -- not supported
ALTER TABLE regtest_table_2 INHERIT regtest_table; -- not supported
ALTER TABLE regtest_table SET TABLESPACE pg_default;
---
-- partitioned table parent
ALTER TABLE regtest_ptable ADD COLUMN d float;
ALTER TABLE regtest_ptable DROP COLUMN d;
ALTER TABLE regtest_ptable ALTER p SET DEFAULT 'abcd'; -- not supported by sepgsql
ALTER TABLE regtest_ptable ALTER p SET DEFAULT 'XYZ'; -- not supported by sepgsql
ALTER TABLE regtest_ptable ALTER p DROP DEFAULT; -- not supported by sepgsql
ALTER TABLE regtest_ptable ALTER p SET NOT NULL;
ALTER TABLE regtest_ptable ALTER p DROP NOT NULL;
ALTER TABLE regtest_ptable ALTER p SET STATISTICS -1;
ALTER TABLE regtest_ptable ALTER p SET (n_distinct = 999);
ALTER TABLE regtest_ptable ALTER p SET STORAGE PLAIN;
ALTER TABLE regtest_ptable ADD CONSTRAINT test_ck CHECK (p like '%abc%') NOT VALID; -- not supported by sepgsql
ALTER TABLE regtest_ptable DROP CONSTRAINT test_ck; -- not supported by sepgsql
ALTER TABLE regtest_ptable SET TABLESPACE pg_default;
-- partitioned table child
ALTER TABLE regtest_table_part ALTER p SET DEFAULT 'abcd'; -- not supported by sepgsql
ALTER TABLE regtest_table_part ALTER p SET DEFAULT 'XYZ'; -- not supported by sepgsql
ALTER TABLE regtest_table_part ALTER p DROP DEFAULT; -- not supported by sepgsql
ALTER TABLE regtest_table_part ALTER p SET NOT NULL;
ALTER TABLE regtest_table_part ALTER p DROP NOT NULL;
ALTER TABLE regtest_table_part ALTER p SET STATISTICS -1;
ALTER TABLE regtest_table_part ALTER p SET (n_distinct = 999);
ALTER TABLE regtest_table_part ALTER p SET STORAGE PLAIN;
ALTER TABLE regtest_table_part ADD CONSTRAINT test_ck CHECK (p like '%abc%') NOT VALID; -- not supported by sepgsql
ALTER TABLE regtest_table_part VALIDATE CONSTRAINT test_ck; -- not supported by sepgsql
ALTER TABLE regtest_table_part DROP CONSTRAINT test_ck; -- not supported by sepgsql
CREATE TRIGGER regtest_part_test_trig BEFORE UPDATE ON regtest_table_part
FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
ALTER TABLE regtest_table_part DISABLE TRIGGER regtest_part_test_trig; -- not supported by sepgsql
ALTER TABLE regtest_table_part ENABLE TRIGGER regtest_part_test_trig; -- not supported by sepgsql
ALTER TABLE regtest_table_part SET (fillfactor = 75);
ALTER TABLE regtest_table_part RESET (fillfactor);
ALTER TABLE regtest_table_part SET TABLESPACE pg_default;
---
ALTER VIEW regtest_view SET (security_barrier);
ALTER SEQUENCE regtest_seq INCREMENT BY 10 START WITH 1000;
--
-- clean-up objects
--
RESET sepgsql.debug_audit;
RESET client_min_messages;
DROP DATABASE sepgsql_test_regression;
DROP SCHEMA regtest_schema CASCADE;
DROP SCHEMA regtest_schema_2 CASCADE;
DROP USER regress_sepgsql_test_user;