mirror of
https://github.com/postgres/postgres.git
synced 2026-02-15 08:37:56 -05:00
Those tables have no physical storage, making this option unusable with partition trees as at commit time an actual truncation was attempted. There are still issues with the way ON COMMIT actions are done when mixing several action types, however this impacts as well inheritance trees, so this issue will be dealt with later. Reported-by: Rajkumar Raghuwanshi Author: Amit Langote Reviewed-by: Michael Paquier, Tom Lane Discussion: https://postgr.es/m/CAKcux6mhgcjSiB_egqEAEFgX462QZtncU8QCAJ2HZwM-wWGVew@mail.gmail.com
167 lines
3.4 KiB
PL/PgSQL
167 lines
3.4 KiB
PL/PgSQL
--
|
|
-- TEMP
|
|
-- Test temp relations and indexes
|
|
--
|
|
|
|
-- test temp table/index masking
|
|
|
|
CREATE TABLE temptest(col int);
|
|
|
|
CREATE INDEX i_temptest ON temptest(col);
|
|
|
|
CREATE TEMP TABLE temptest(tcol int);
|
|
|
|
CREATE INDEX i_temptest ON temptest(tcol);
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
DROP INDEX i_temptest;
|
|
|
|
DROP TABLE temptest;
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
DROP INDEX i_temptest;
|
|
|
|
DROP TABLE temptest;
|
|
|
|
-- test temp table selects
|
|
|
|
CREATE TABLE temptest(col int);
|
|
|
|
INSERT INTO temptest VALUES (1);
|
|
|
|
CREATE TEMP TABLE temptest(tcol float);
|
|
|
|
INSERT INTO temptest VALUES (2.1);
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
DROP TABLE temptest;
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
DROP TABLE temptest;
|
|
|
|
-- test temp table deletion
|
|
|
|
CREATE TEMP TABLE temptest(col int);
|
|
|
|
\c
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
-- Test ON COMMIT DELETE ROWS
|
|
|
|
CREATE TEMP TABLE temptest(col int) ON COMMIT DELETE ROWS;
|
|
|
|
BEGIN;
|
|
INSERT INTO temptest VALUES (1);
|
|
INSERT INTO temptest VALUES (2);
|
|
|
|
SELECT * FROM temptest;
|
|
COMMIT;
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
DROP TABLE temptest;
|
|
|
|
BEGIN;
|
|
CREATE TEMP TABLE temptest(col) ON COMMIT DELETE ROWS AS SELECT 1;
|
|
|
|
SELECT * FROM temptest;
|
|
COMMIT;
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
DROP TABLE temptest;
|
|
|
|
-- Test ON COMMIT DROP
|
|
|
|
BEGIN;
|
|
|
|
CREATE TEMP TABLE temptest(col int) ON COMMIT DROP;
|
|
|
|
INSERT INTO temptest VALUES (1);
|
|
INSERT INTO temptest VALUES (2);
|
|
|
|
SELECT * FROM temptest;
|
|
COMMIT;
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
BEGIN;
|
|
CREATE TEMP TABLE temptest(col) ON COMMIT DROP AS SELECT 1;
|
|
|
|
SELECT * FROM temptest;
|
|
COMMIT;
|
|
|
|
SELECT * FROM temptest;
|
|
|
|
-- ON COMMIT is only allowed for TEMP
|
|
|
|
CREATE TABLE temptest(col int) ON COMMIT DELETE ROWS;
|
|
CREATE TABLE temptest(col) ON COMMIT DELETE ROWS AS SELECT 1;
|
|
|
|
-- Test foreign keys
|
|
BEGIN;
|
|
CREATE TEMP TABLE temptest1(col int PRIMARY KEY);
|
|
CREATE TEMP TABLE temptest2(col int REFERENCES temptest1)
|
|
ON COMMIT DELETE ROWS;
|
|
INSERT INTO temptest1 VALUES (1);
|
|
INSERT INTO temptest2 VALUES (1);
|
|
COMMIT;
|
|
SELECT * FROM temptest1;
|
|
SELECT * FROM temptest2;
|
|
|
|
BEGIN;
|
|
CREATE TEMP TABLE temptest3(col int PRIMARY KEY) ON COMMIT DELETE ROWS;
|
|
CREATE TEMP TABLE temptest4(col int REFERENCES temptest3);
|
|
COMMIT;
|
|
|
|
-- Test manipulation of temp schema's placement in search path
|
|
|
|
create table public.whereami (f1 text);
|
|
insert into public.whereami values ('public');
|
|
|
|
create temp table whereami (f1 text);
|
|
insert into whereami values ('temp');
|
|
|
|
create function public.whoami() returns text
|
|
as $$select 'public'::text$$ language sql;
|
|
|
|
create function pg_temp.whoami() returns text
|
|
as $$select 'temp'::text$$ language sql;
|
|
|
|
-- default should have pg_temp implicitly first, but only for tables
|
|
select * from whereami;
|
|
select whoami();
|
|
|
|
-- can list temp first explicitly, but it still doesn't affect functions
|
|
set search_path = pg_temp, public;
|
|
select * from whereami;
|
|
select whoami();
|
|
|
|
-- or put it last for security
|
|
set search_path = public, pg_temp;
|
|
select * from whereami;
|
|
select whoami();
|
|
|
|
-- you can invoke a temp function explicitly, though
|
|
select pg_temp.whoami();
|
|
|
|
drop table public.whereami;
|
|
|
|
-- For partitioned temp tables, ON COMMIT actions ignore storage-less
|
|
-- partitioned tables.
|
|
begin;
|
|
create temp table temp_parted_oncommit (a int)
|
|
partition by list (a) on commit delete rows;
|
|
create temp table temp_parted_oncommit_1
|
|
partition of temp_parted_oncommit
|
|
for values in (1) on commit delete rows;
|
|
insert into temp_parted_oncommit values (1);
|
|
commit;
|
|
-- partitions are emptied by the previous commit
|
|
select * from temp_parted_oncommit;
|
|
drop table temp_parted_oncommit;
|