-- pg_regress should ensure that this default value applies; however -- we can't rely on any specific default value of vacuum_cost_delay SHOW datestyle; -- SET to some nondefault value SET vacuum_cost_delay TO 400; SET datestyle = 'ISO, YMD'; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- SET LOCAL has no effect outside of a transaction SET LOCAL vacuum_cost_delay TO 500; SHOW vacuum_cost_delay; SET LOCAL datestyle = 'SQL'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- SET LOCAL within a transaction that commits BEGIN; SET LOCAL vacuum_cost_delay TO 500; SHOW vacuum_cost_delay; SET LOCAL datestyle = 'SQL'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; COMMIT; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- SET should be reverted after ROLLBACK BEGIN; SET vacuum_cost_delay TO 600; SHOW vacuum_cost_delay; SET datestyle = 'German'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- Some tests with subtransactions BEGIN; SET vacuum_cost_delay TO 700; SET datestyle = 'MDY'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; SAVEPOINT first_sp; SET vacuum_cost_delay TO 800; SHOW vacuum_cost_delay; SET datestyle = 'German, DMY'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK TO first_sp; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; SAVEPOINT second_sp; SET vacuum_cost_delay TO 900; SET datestyle = 'SQL, YMD'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; SAVEPOINT third_sp; SET vacuum_cost_delay TO 1000; SHOW vacuum_cost_delay; SET datestyle = 'Postgres, MDY'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK TO third_sp; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK TO second_sp; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- SET LOCAL with Savepoints BEGIN; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; SAVEPOINT sp; SET LOCAL vacuum_cost_delay TO 300; SHOW vacuum_cost_delay; SET LOCAL datestyle = 'Postgres, MDY'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK TO sp; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- SET LOCAL persists through RELEASE (which was not true in 8.0-8.2) BEGIN; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; SAVEPOINT sp; SET LOCAL vacuum_cost_delay TO 300; SHOW vacuum_cost_delay; SET LOCAL datestyle = 'Postgres, MDY'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; RELEASE SAVEPOINT sp; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; ROLLBACK; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- SET followed by SET LOCAL BEGIN; SET vacuum_cost_delay TO 400; SET LOCAL vacuum_cost_delay TO 500; SHOW vacuum_cost_delay; SET datestyle = 'ISO, DMY'; SET LOCAL datestyle = 'Postgres, MDY'; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; COMMIT; SHOW vacuum_cost_delay; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- -- Test RESET. We use datestyle because the reset value is forced by -- pg_regress, so it doesn't depend on the installation's configuration. -- SET datestyle = iso, ymd; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; RESET datestyle; SHOW datestyle; SELECT '2006-08-13 12:34:56'::timestamptz; -- -- Test DISCARD TEMP -- CREATE TEMP TABLE reset_test ( data text ) ON COMMIT DELETE ROWS; SELECT relname FROM pg_class WHERE relname = 'reset_test'; DISCARD TEMP; SELECT relname FROM pg_class WHERE relname = 'reset_test'; -- -- Test DISCARD ALL -- -- do changes DECLARE foo CURSOR WITH HOLD FOR SELECT 1; PREPARE foo AS SELECT 1; LISTEN foo_event; SET vacuum_cost_delay = 13; CREATE TEMP TABLE tmp_foo (data text) ON COMMIT DELETE ROWS; CREATE ROLE temp_reset_user; SET SESSION AUTHORIZATION temp_reset_user; -- look changes SELECT relname FROM pg_listener; SELECT name FROM pg_prepared_statements; SELECT name FROM pg_cursors; SHOW vacuum_cost_delay; SELECT relname from pg_class where relname = 'tmp_foo'; SELECT current_user = 'temp_reset_user'; -- discard everything DISCARD ALL; -- look again SELECT relname FROM pg_listener; SELECT name FROM pg_prepared_statements; SELECT name FROM pg_cursors; SHOW vacuum_cost_delay; SELECT relname from pg_class where relname = 'tmp_foo'; SELECT current_user = 'temp_reset_user'; DROP ROLE temp_reset_user; -- -- Tests for function-local GUC settings -- set regex_flavor = advanced; create function report_guc(text) returns text as $$ select current_setting($1) $$ language sql set regex_flavor = basic; select report_guc('regex_flavor'), current_setting('regex_flavor'); -- this should draw only a warning alter function report_guc(text) set search_path = no_such_schema; -- with error occurring here select report_guc('regex_flavor'), current_setting('regex_flavor'); alter function report_guc(text) reset search_path set regex_flavor = extended; select report_guc('regex_flavor'), current_setting('regex_flavor'); alter function report_guc(text) reset all; select report_guc('regex_flavor'), current_setting('regex_flavor'); -- SET LOCAL is restricted by a function SET option create or replace function myfunc(int) returns text as $$ begin set local regex_flavor = extended; return current_setting('regex_flavor'); end $$ language plpgsql set regex_flavor = basic; select myfunc(0), current_setting('regex_flavor'); alter function myfunc(int) reset all; select myfunc(0), current_setting('regex_flavor'); set regex_flavor = advanced; -- but SET isn't create or replace function myfunc(int) returns text as $$ begin set regex_flavor = extended; return current_setting('regex_flavor'); end $$ language plpgsql set regex_flavor = basic; select myfunc(0), current_setting('regex_flavor'); set regex_flavor = advanced; -- it should roll back on error, though create or replace function myfunc(int) returns text as $$ begin set regex_flavor = extended; perform 1/$1; return current_setting('regex_flavor'); end $$ language plpgsql set regex_flavor = basic; select myfunc(0); select current_setting('regex_flavor'); select myfunc(1), current_setting('regex_flavor');