1--
2-- TEMP
3-- Test temp relations and indexes
4--
5
6-- test temp table/index masking
7
8CREATE TABLE temptest(col int);
9
10CREATE INDEX i_temptest ON temptest(col);
11
12CREATE TEMP TABLE temptest(tcol int);
13
14CREATE INDEX i_temptest ON temptest(tcol);
15
16SELECT * FROM temptest;
17
18DROP INDEX i_temptest;
19
20DROP TABLE temptest;
21
22SELECT * FROM temptest;
23
24DROP INDEX i_temptest;
25
26DROP TABLE temptest;
27
28-- test temp table selects
29
30CREATE TABLE temptest(col int);
31
32INSERT INTO temptest VALUES (1);
33
34CREATE TEMP TABLE temptest(tcol float);
35
36INSERT INTO temptest VALUES (2.1);
37
38SELECT * FROM temptest;
39
40DROP TABLE temptest;
41
42SELECT * FROM temptest;
43
44DROP TABLE temptest;
45
46-- test temp table deletion
47
48CREATE TEMP TABLE temptest(col int);
49
50\c
51
52SELECT * FROM temptest;
53
54-- Test ON COMMIT DELETE ROWS
55
56CREATE TEMP TABLE temptest(col int) ON COMMIT DELETE ROWS;
57
58-- while we're here, verify successful truncation of index with SQL function
59CREATE INDEX ON temptest(bit_length(''));
60
61BEGIN;
62INSERT INTO temptest VALUES (1);
63INSERT INTO temptest VALUES (2);
64
65SELECT * FROM temptest;
66COMMIT;
67
68SELECT * FROM temptest;
69
70DROP TABLE temptest;
71
72BEGIN;
73CREATE TEMP TABLE temptest(col) ON COMMIT DELETE ROWS AS SELECT 1;
74
75SELECT * FROM temptest;
76COMMIT;
77
78SELECT * FROM temptest;
79
80DROP TABLE temptest;
81
82-- Test ON COMMIT DROP
83
84BEGIN;
85
86CREATE TEMP TABLE temptest(col int) ON COMMIT DROP;
87
88INSERT INTO temptest VALUES (1);
89INSERT INTO temptest VALUES (2);
90
91SELECT * FROM temptest;
92COMMIT;
93
94SELECT * FROM temptest;
95
96BEGIN;
97CREATE TEMP TABLE temptest(col) ON COMMIT DROP AS SELECT 1;
98
99SELECT * FROM temptest;
100COMMIT;
101
102SELECT * FROM temptest;
103
104-- ON COMMIT is only allowed for TEMP
105
106CREATE TABLE temptest(col int) ON COMMIT DELETE ROWS;
107CREATE TABLE temptest(col) ON COMMIT DELETE ROWS AS SELECT 1;
108
109-- Test foreign keys
110BEGIN;
111CREATE TEMP TABLE temptest1(col int PRIMARY KEY);
112CREATE TEMP TABLE temptest2(col int REFERENCES temptest1)
113  ON COMMIT DELETE ROWS;
114INSERT INTO temptest1 VALUES (1);
115INSERT INTO temptest2 VALUES (1);
116COMMIT;
117SELECT * FROM temptest1;
118SELECT * FROM temptest2;
119
120BEGIN;
121CREATE TEMP TABLE temptest3(col int PRIMARY KEY) ON COMMIT DELETE ROWS;
122CREATE TEMP TABLE temptest4(col int REFERENCES temptest3);
123COMMIT;
124
125-- Test manipulation of temp schema's placement in search path
126
127create table public.whereami (f1 text);
128insert into public.whereami values ('public');
129
130create temp table whereami (f1 text);
131insert into whereami values ('temp');
132
133create function public.whoami() returns text
134  as $$select 'public'::text$$ language sql;
135
136create function pg_temp.whoami() returns text
137  as $$select 'temp'::text$$ language sql;
138
139-- default should have pg_temp implicitly first, but only for tables
140select * from whereami;
141select whoami();
142
143-- can list temp first explicitly, but it still doesn't affect functions
144set search_path = pg_temp, public;
145select * from whereami;
146select whoami();
147
148-- or put it last for security
149set search_path = public, pg_temp;
150select * from whereami;
151select whoami();
152
153-- you can invoke a temp function explicitly, though
154select pg_temp.whoami();
155
156drop table public.whereami;
157
158-- types in temp schema
159set search_path = pg_temp, public;
160create domain pg_temp.nonempty as text check (value <> '');
161-- function-syntax invocation of types matches rules for functions
162select nonempty('');
163select pg_temp.nonempty('');
164-- other syntax matches rules for tables
165select ''::nonempty;
166
167reset search_path;
168
169-- For partitioned temp tables, ON COMMIT actions ignore storage-less
170-- partitioned tables.
171begin;
172create temp table temp_parted_oncommit (a int)
173  partition by list (a) on commit delete rows;
174create temp table temp_parted_oncommit_1
175  partition of temp_parted_oncommit
176  for values in (1) on commit delete rows;
177insert into temp_parted_oncommit values (1);
178commit;
179-- partitions are emptied by the previous commit
180select * from temp_parted_oncommit;
181drop table temp_parted_oncommit;
182
183-- Check dependencies between ON COMMIT actions with a partitioned
184-- table and its partitions.  Using ON COMMIT DROP on a parent removes
185-- the whole set.
186begin;
187create temp table temp_parted_oncommit_test (a int)
188  partition by list (a) on commit drop;
189create temp table temp_parted_oncommit_test1
190  partition of temp_parted_oncommit_test
191  for values in (1) on commit delete rows;
192create temp table temp_parted_oncommit_test2
193  partition of temp_parted_oncommit_test
194  for values in (2) on commit drop;
195insert into temp_parted_oncommit_test values (1), (2);
196commit;
197-- no relations remain in this case.
198select relname from pg_class where relname ~ '^temp_parted_oncommit_test';
199-- Using ON COMMIT DELETE on a partitioned table does not remove
200-- all rows if partitions preserve their data.
201begin;
202create temp table temp_parted_oncommit_test (a int)
203  partition by list (a) on commit delete rows;
204create temp table temp_parted_oncommit_test1
205  partition of temp_parted_oncommit_test
206  for values in (1) on commit preserve rows;
207create temp table temp_parted_oncommit_test2
208  partition of temp_parted_oncommit_test
209  for values in (2) on commit drop;
210insert into temp_parted_oncommit_test values (1), (2);
211commit;
212-- Data from the remaining partition is still here as its rows are
213-- preserved.
214select * from temp_parted_oncommit_test;
215-- two relations remain in this case.
216select relname from pg_class where relname ~ '^temp_parted_oncommit_test'
217  order by relname;
218drop table temp_parted_oncommit_test;
219
220-- Check dependencies between ON COMMIT actions with inheritance trees.
221-- Using ON COMMIT DROP on a parent removes the whole set.
222begin;
223create temp table temp_inh_oncommit_test (a int) on commit drop;
224create temp table temp_inh_oncommit_test1 ()
225  inherits(temp_inh_oncommit_test) on commit delete rows;
226insert into temp_inh_oncommit_test1 values (1);
227commit;
228-- no relations remain in this case
229select relname from pg_class where relname ~ '^temp_inh_oncommit_test';
230-- Data on the parent is removed, and the child goes away.
231begin;
232create temp table temp_inh_oncommit_test (a int) on commit delete rows;
233create temp table temp_inh_oncommit_test1 ()
234  inherits(temp_inh_oncommit_test) on commit drop;
235insert into temp_inh_oncommit_test1 values (1);
236insert into temp_inh_oncommit_test values (1);
237commit;
238select * from temp_inh_oncommit_test;
239-- one relation remains
240select relname from pg_class where relname ~ '^temp_inh_oncommit_test';
241drop table temp_inh_oncommit_test;
242
243-- Tests with two-phase commit
244-- Transactions creating objects in a temporary namespace cannot be used
245-- with two-phase commit.
246
247-- These cases generate errors about temporary namespace.
248-- Function creation
249begin;
250create function pg_temp.twophase_func() returns void as
251  $$ select '2pc_func'::text $$ language sql;
252prepare transaction 'twophase_func';
253-- Function drop
254create function pg_temp.twophase_func() returns void as
255  $$ select '2pc_func'::text $$ language sql;
256begin;
257drop function pg_temp.twophase_func();
258prepare transaction 'twophase_func';
259-- Operator creation
260begin;
261create operator pg_temp.@@ (leftarg = int4, rightarg = int4, procedure = int4mi);
262prepare transaction 'twophase_operator';
263
264-- These generate errors about temporary tables.
265begin;
266create type pg_temp.twophase_type as (a int);
267prepare transaction 'twophase_type';
268begin;
269create view pg_temp.twophase_view as select 1;
270prepare transaction 'twophase_view';
271begin;
272create sequence pg_temp.twophase_seq;
273prepare transaction 'twophase_sequence';
274
275-- Temporary tables cannot be used with two-phase commit.
276create temp table twophase_tab (a int);
277begin;
278select a from twophase_tab;
279prepare transaction 'twophase_tab';
280begin;
281insert into twophase_tab values (1);
282prepare transaction 'twophase_tab';
283begin;
284lock twophase_tab in access exclusive mode;
285prepare transaction 'twophase_tab';
286begin;
287drop table twophase_tab;
288prepare transaction 'twophase_tab';
289
290-- Corner case: current_schema may create a temporary schema if namespace
291-- creation is pending, so check after that.  First reset the connection
292-- to remove the temporary namespace.
293\c -
294SET search_path TO 'pg_temp';
295BEGIN;
296SELECT current_schema() ~ 'pg_temp' AS is_temp_schema;
297PREPARE TRANSACTION 'twophase_search';
298