-
Notifications
You must be signed in to change notification settings - Fork 5
/
pg_global_temp_tables_tests.sql
271 lines (228 loc) · 8.94 KB
/
pg_global_temp_tables_tests.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
-- pg_global_temp_tables_tests -- tests for pg_global_temp_tables
-- uses PGUnit: https://github.com/adrianandrei-ca/pgunit
--
-- PGUnit framework should be installed in the 'pgunit' schema:
-- select * from pgunit.test_run_suite('pg_global_temp_tables')
--
-- Emulates Oracle-style global temporary tables in PostgreSQL
-- Written by Alexey Yakovlev <[email protected]>
create or replace function test_case_pg_global_temp_tables_create_fails_on_nonexistent() returns void as $$
begin
-- use begin..exception block to simulate the inner transaction
begin
perform create_permanent_temp_table('pg_global_temp_tables_nonexistent_table');
-- roll back all changes, including the created database objects
raise exception 'Failed' using errcode = 'UTEST';
exception
when sqlstate 'UTMP1' then
raise notice 'OK, transaction rolled back';
end;
end;
$$ language plpgsql
set search_path from current;
create or replace function test_case_pg_global_temp_tables_create_succeeds_with_pkey() returns void as $$
declare
v_count int;
begin
-- use begin..exception block to simulate the inner transaction
begin
create temporary table if not exists pg_global_temp_tables_test_table
(
id bigint primary key,
name varchar,
dt timestamptz(0),
count integer
);
insert into
pg_global_temp_tables_test_table(id, name, dt, count)
values
(1, 'create_permanent_temp_table', now(), 123),
(2, 'drop_permanent_temp_table', clock_timestamp(), 321);
perform create_permanent_temp_table('pg_global_temp_tables_test_table');
-- check that the data still exists
select count(*)
into v_count
from pg_global_temp_tables_test_table;
perform pgunit.test_assertTrue('row count should be 2', v_count = 2);
-- insert more data
insert into
pg_global_temp_tables_test_table(id, name, dt, count)
values
(3, 'test_case_pg_global_temp_tables_create', clock_timestamp(), 111);
select count(*)
into v_count
from pg_global_temp_tables_test_table;
perform pgunit.test_assertTrue('row count should be 3', v_count = 3);
-- update a few rows
update pg_global_temp_tables_test_table
set count = 10
where id = 2;
select count(*)
into v_count
from pg_global_temp_tables_test_table
where count = 10;
perform pgunit.test_assertTrue('row count should be 1', v_count = 1);
-- delete a row
delete from pg_global_temp_tables_test_table where id = 1;
select count(*)
into v_count
from pg_global_temp_tables_test_table;
perform pgunit.test_assertTrue('row count should be 2 again', v_count = 2);
-- roll back all changes, including the created database objects
raise exception 'OK' using errcode = 'UTEST';
exception
when sqlstate 'UTEST' then
raise notice 'OK, transaction rolled back';
end;
end;
$$ language plpgsql
set search_path from current;
create or replace function test_case_pg_global_temp_tables_create_succeeds_without_pkey() returns void as $$
declare
v_count int;
begin
-- use begin..exception block to simulate the inner transaction
begin
create temporary table if not exists pg_global_temp_tables_test_table
(
id bigint,
name varchar,
dt timestamptz(0),
count integer
);
insert into
pg_global_temp_tables_test_table(id, name, dt, count)
values
(1, 'create_permanent_temp_table', now(), 123),
(2, 'drop_permanent_temp_table', clock_timestamp(), 321);
perform create_permanent_temp_table('pg_global_temp_tables_test_table');
-- check that the data still exists
select count(*)
into v_count
from pg_global_temp_tables_test_table;
perform pgunit.test_assertTrue('row count should be 2', v_count = 2);
-- insert more data
insert into
pg_global_temp_tables_test_table(id, name, dt, count)
values
(3, 'test_case_pg_global_temp_tables_create', clock_timestamp(), 111);
select count(*)
into v_count
from pg_global_temp_tables_test_table;
perform pgunit.test_assertTrue('row count should be 3', v_count = 3);
-- update a few rows
update pg_global_temp_tables_test_table
set count = 10
where id = 2;
select count(*)
into v_count
from pg_global_temp_tables_test_table
where count = 10;
perform pgunit.test_assertTrue('row count should be 1', v_count = 1);
-- delete a row
delete from pg_global_temp_tables_test_table where id = 1;
select count(*)
into v_count
from pg_global_temp_tables_test_table;
perform pgunit.test_assertTrue('row count should be 2 again', v_count = 2);
-- roll back all changes, including the created database objects
raise exception 'OK' using errcode = 'UTEST';
exception
when sqlstate 'UTEST' then
raise notice 'OK, transaction rolled back';
end;
end;
$$ language plpgsql
set search_path from current;
create or replace function test_case_pg_global_temp_tables_drop_fails_on_nonexistent_table() returns void as $$
begin
-- use begin..exception block to simulate the inner transaction
begin
perform drop_permanent_temp_table('pg_global_temp_tables_nonexistent_table');
-- roll back all changes, including the created database objects
raise exception 'Failed' using errcode = 'UTEST';
exception
when sqlstate 'UTMP2' then
raise notice 'OK, transaction rolled back';
end;
end;
$$ language plpgsql
set search_path from current;
create or replace function test_case_pg_global_temp_tables_drop_succeeds() returns void as $$
begin
-- use begin..exception block to simulate the inner transaction
begin
create temporary table if not exists pg_global_temp_tables_test_table
(
id bigint primary key,
name varchar,
dt timestamptz(0),
count integer
);
perform create_permanent_temp_table('pg_global_temp_tables_test_table');
perform drop_permanent_temp_table('pg_global_temp_tables_test_table');
-- roll back all changes, including the created database objects
raise exception 'OK' using errcode = 'UTEST';
exception
when sqlstate 'UTEST' then
raise notice 'OK, transaction rolled back';
end;
end;
$$ language plpgsql
set search_path from current;
create or replace function test_case_pg_global_temp_tables_with_default_value() returns void as $$
declare
v_rec RECORD;
begin
-- use begin..exception block to simulate the inner transaction
begin
create temporary table if not exists pg_global_temp_tables_test_table
(
id bigint primary key,
varchar_without_def varchar,
varchar_with_def varchar default 'def_varchar',
integer_with_def integer default 1,
numeric_with_def numeric(4,1) default 201.8,
date_with_def date default date'2018-01-01',
timestamp_with_def timestamp default timestamp'2018-01-01 10:00:00.000'
);
perform create_permanent_temp_table('pg_global_temp_tables_test_table');
-- only insert the primary key
insert into
pg_global_temp_tables_test_table(id)
values
(1);
-- check default values
select *
into v_rec
from pg_global_temp_tables_test_table where id = 1;
perform pgunit.test_assertTrue('varchar_without_def should be [null] when not set', v_rec.varchar_without_def is null);
perform pgunit.test_assertTrue('varchar_with_def should be [def_varchar] when not set', v_rec.varchar_with_def = 'def_varchar');
perform pgunit.test_assertTrue('integer_with_def should be [1] when not set', v_rec.integer_with_def = 1);
perform pgunit.test_assertTrue('numeric_with_def should be [201.8] when not set', v_rec.numeric_with_def = 201.8);
perform pgunit.test_assertTrue('date_with_def should be [2018-01-01] when not set', v_rec.date_with_def = date'2018-01-01');
perform pgunit.test_assertTrue('timestamp_with_def should be [2018-01-01 10:00:00.000] when not set', v_rec.timestamp_with_def = timestamp'2018-01-01 10:00:00.000');
-- insert all values
insert into
pg_global_temp_tables_test_table(id, varchar_without_def, varchar_with_def, integer_with_def, numeric_with_def, date_with_def, timestamp_with_def)
values
(2, 'inserted_varchar', 'inserted_varchar2', 2, 202.8, date'2018-01-02', timestamp'2018-01-02 10:00:00.000');
-- check inserted values
select *
into v_rec
from pg_global_temp_tables_test_table where id = 2;
perform pgunit.test_assertTrue('varchar_without_def should be [inserted_varchar] when set', v_rec.varchar_without_def = 'inserted_varchar');
perform pgunit.test_assertTrue('varchar_with_def should be [inserted_varchar2] when set', v_rec.varchar_with_def = 'inserted_varchar2');
perform pgunit.test_assertTrue('integer_with_def should be [2] when set', v_rec.integer_with_def = 2);
perform pgunit.test_assertTrue('numeric_with_def should be [201.9] when set', v_rec.numeric_with_def = 202.8);
perform pgunit.test_assertTrue('date_with_def should be [2018-01-02] when set', v_rec.date_with_def = date'2018-01-02');
perform pgunit.test_assertTrue('timestamp_with_def should be [2018-01-02 10:00:00.000] when set', v_rec.timestamp_with_def = timestamp'2018-01-02 10:00:00.000');
-- roll back all changes, including the created database objects
raise exception 'OK' using errcode = 'UTEST';
exception
when sqlstate 'UTEST' then
raise notice 'OK, transaction rolled back';
end;
end;
$$ language plpgsql
set search_path from current;