mirror of
https://github.com/postgres/postgres.git
synced 2026-01-13 12:22:55 +03:00
While executing maintenance operations (ANALYZE, CLUSTER, REFRESH MATERIALIZED VIEW, REINDEX, or VACUUM), set search_path to 'pg_catalog, pg_temp' to prevent inconsistent behavior. Functions that are used for functional indexes, in index expressions, or in materialized views and depend on a different search path must be declared with CREATE FUNCTION ... SET search_path='...'. This change was previously committed as05e1737351, then reverted in commit2fcc7ee7afbecause it was too late in the cycle. Preparation for the MAINTAIN privilege, which was previously reverted due to search_path manipulation hazards. Discussion: https://postgr.es/m/d4ccaf3658cb3c281ec88c851a09733cd9482f22.camel@j-davis.com Discussion: https://postgr.es/m/E1q7j7Y-000z1H-Hr%40gemulon.postgresql.org Discussion: https://postgr.es/m/e44327179e5c9015c8dda67351c04da552066017.camel%40j-davis.com Reviewed-by: Greg Stark, Nathan Bossart, Noah Misch
101 lines
3.0 KiB
PL/PgSQL
101 lines
3.0 KiB
PL/PgSQL
--
|
|
-- Regression tests for schemas (namespaces)
|
|
--
|
|
|
|
-- set the whitespace-only search_path to test that the
|
|
-- GUC list syntax is preserved during a schema creation
|
|
SELECT pg_catalog.set_config('search_path', ' ', false);
|
|
|
|
CREATE SCHEMA test_ns_schema_1
|
|
CREATE UNIQUE INDEX abc_a_idx ON abc (a)
|
|
|
|
CREATE VIEW abc_view AS
|
|
SELECT a+1 AS a, b+1 AS b FROM abc
|
|
|
|
CREATE TABLE abc (
|
|
a serial,
|
|
b int UNIQUE
|
|
);
|
|
|
|
-- verify that the correct search_path restored on abort
|
|
SET search_path to public;
|
|
BEGIN;
|
|
SET search_path to public, test_ns_schema_1;
|
|
CREATE SCHEMA test_ns_schema_2
|
|
CREATE VIEW abc_view AS SELECT c FROM abc;
|
|
COMMIT;
|
|
SHOW search_path;
|
|
|
|
-- verify that the correct search_path preserved
|
|
-- after creating the schema and on commit
|
|
BEGIN;
|
|
SET search_path to public, test_ns_schema_1;
|
|
CREATE SCHEMA test_ns_schema_2
|
|
CREATE VIEW abc_view AS SELECT a FROM abc;
|
|
SHOW search_path;
|
|
COMMIT;
|
|
SHOW search_path;
|
|
DROP SCHEMA test_ns_schema_2 CASCADE;
|
|
|
|
-- verify that the objects were created
|
|
SELECT COUNT(*) FROM pg_class WHERE relnamespace =
|
|
(SELECT oid FROM pg_namespace WHERE nspname = 'test_ns_schema_1');
|
|
|
|
INSERT INTO test_ns_schema_1.abc DEFAULT VALUES;
|
|
INSERT INTO test_ns_schema_1.abc DEFAULT VALUES;
|
|
INSERT INTO test_ns_schema_1.abc DEFAULT VALUES;
|
|
|
|
SELECT * FROM test_ns_schema_1.abc;
|
|
SELECT * FROM test_ns_schema_1.abc_view;
|
|
|
|
ALTER SCHEMA test_ns_schema_1 RENAME TO test_ns_schema_renamed;
|
|
SELECT COUNT(*) FROM pg_class WHERE relnamespace =
|
|
(SELECT oid FROM pg_namespace WHERE nspname = 'test_ns_schema_1');
|
|
|
|
-- test IF NOT EXISTS cases
|
|
CREATE SCHEMA test_ns_schema_renamed; -- fail, already exists
|
|
CREATE SCHEMA IF NOT EXISTS test_ns_schema_renamed; -- ok with notice
|
|
CREATE SCHEMA IF NOT EXISTS test_ns_schema_renamed -- fail, disallowed
|
|
CREATE TABLE abc (
|
|
a serial,
|
|
b int UNIQUE
|
|
);
|
|
|
|
DROP SCHEMA test_ns_schema_renamed CASCADE;
|
|
|
|
-- verify that the objects were dropped
|
|
SELECT COUNT(*) FROM pg_class WHERE relnamespace =
|
|
(SELECT oid FROM pg_namespace WHERE nspname = 'test_ns_schema_renamed');
|
|
|
|
--
|
|
-- Verify that search_path is set to a safe value during maintenance
|
|
-- commands.
|
|
--
|
|
|
|
CREATE SCHEMA test_maint_search_path;
|
|
SET search_path = test_maint_search_path;
|
|
|
|
CREATE FUNCTION fn(INT) RETURNS INT IMMUTABLE LANGUAGE plpgsql AS $$
|
|
BEGIN
|
|
RAISE NOTICE 'current search_path: %', current_setting('search_path');
|
|
RETURN $1;
|
|
END;
|
|
$$;
|
|
|
|
CREATE TABLE test_maint(i INT);
|
|
INSERT INTO test_maint VALUES (1), (2);
|
|
CREATE MATERIALIZED VIEW test_maint_mv AS SELECT fn(i) FROM test_maint;
|
|
|
|
-- the following commands should see search_path as pg_catalog, pg_temp
|
|
|
|
CREATE INDEX test_maint_idx ON test_maint_search_path.test_maint (fn(i));
|
|
REINDEX TABLE test_maint_search_path.test_maint;
|
|
ANALYZE test_maint_search_path.test_maint;
|
|
VACUUM FULL test_maint_search_path.test_maint;
|
|
CLUSTER test_maint_search_path.test_maint USING test_maint_idx;
|
|
REFRESH MATERIALIZED VIEW test_maint_search_path.test_maint_mv;
|
|
|
|
RESET search_path;
|
|
|
|
DROP SCHEMA test_maint_search_path CASCADE;
|