1--
2-- CREATE_VIEW
3-- Virtual class definitions
4--	(this also tests the query rewrite system)
5--
6
7CREATE VIEW street AS
8   SELECT r.name, r.thepath, c.cname AS cname
9   FROM ONLY road r, real_city c
10   WHERE c.outline ## r.thepath;
11
12CREATE VIEW iexit AS
13   SELECT ih.name, ih.thepath,
14	interpt_pp(ih.thepath, r.thepath) AS exit
15   FROM ihighway ih, ramp r
16   WHERE ih.thepath ## r.thepath;
17
18CREATE VIEW toyemp AS
19   SELECT name, age, location, 12*salary AS annualsal
20   FROM emp;
21
22-- Test comments
23COMMENT ON VIEW noview IS 'no view';
24COMMENT ON VIEW toyemp IS 'is a view';
25COMMENT ON VIEW toyemp IS NULL;
26
27-- These views are left around mainly to exercise special cases in pg_dump.
28
29CREATE TABLE view_base_table (key int PRIMARY KEY, data varchar(20));
30
31CREATE VIEW key_dependent_view AS
32   SELECT * FROM view_base_table GROUP BY key;
33
34ALTER TABLE view_base_table DROP CONSTRAINT view_base_table_pkey;  -- fails
35
36CREATE VIEW key_dependent_view_no_cols AS
37   SELECT FROM view_base_table GROUP BY key HAVING length(data) > 0;
38
39--
40-- CREATE OR REPLACE VIEW
41--
42
43CREATE TABLE viewtest_tbl (a int, b int);
44COPY viewtest_tbl FROM stdin;
455	10
4610	15
4715	20
4820	25
49\.
50
51CREATE OR REPLACE VIEW viewtest AS
52	SELECT * FROM viewtest_tbl;
53
54CREATE OR REPLACE VIEW viewtest AS
55	SELECT * FROM viewtest_tbl WHERE a > 10;
56
57SELECT * FROM viewtest;
58
59CREATE OR REPLACE VIEW viewtest AS
60	SELECT a, b FROM viewtest_tbl WHERE a > 5 ORDER BY b DESC;
61
62SELECT * FROM viewtest;
63
64-- should fail
65CREATE OR REPLACE VIEW viewtest AS
66	SELECT a FROM viewtest_tbl WHERE a <> 20;
67
68-- should fail
69CREATE OR REPLACE VIEW viewtest AS
70	SELECT 1, * FROM viewtest_tbl;
71
72-- should fail
73CREATE OR REPLACE VIEW viewtest AS
74	SELECT a, b::numeric FROM viewtest_tbl;
75
76-- should work
77CREATE OR REPLACE VIEW viewtest AS
78	SELECT a, b, 0 AS c FROM viewtest_tbl;
79
80DROP VIEW viewtest;
81DROP TABLE viewtest_tbl;
82
83-- tests for temporary views
84
85CREATE SCHEMA temp_view_test
86    CREATE TABLE base_table (a int, id int)
87    CREATE TABLE base_table2 (a int, id int);
88
89SET search_path TO temp_view_test, public;
90
91CREATE TEMPORARY TABLE temp_table (a int, id int);
92
93-- should be created in temp_view_test schema
94CREATE VIEW v1 AS SELECT * FROM base_table;
95-- should be created in temp object schema
96CREATE VIEW v1_temp AS SELECT * FROM temp_table;
97-- should be created in temp object schema
98CREATE TEMP VIEW v2_temp AS SELECT * FROM base_table;
99-- should be created in temp_views schema
100CREATE VIEW temp_view_test.v2 AS SELECT * FROM base_table;
101-- should fail
102CREATE VIEW temp_view_test.v3_temp AS SELECT * FROM temp_table;
103-- should fail
104CREATE SCHEMA test_schema
105    CREATE TEMP VIEW testview AS SELECT 1;
106
107-- joins: if any of the join relations are temporary, the view
108-- should also be temporary
109
110-- should be non-temp
111CREATE VIEW v3 AS
112    SELECT t1.a AS t1_a, t2.a AS t2_a
113    FROM base_table t1, base_table2 t2
114    WHERE t1.id = t2.id;
115-- should be temp (one join rel is temp)
116CREATE VIEW v4_temp AS
117    SELECT t1.a AS t1_a, t2.a AS t2_a
118    FROM base_table t1, temp_table t2
119    WHERE t1.id = t2.id;
120-- should be temp
121CREATE VIEW v5_temp AS
122    SELECT t1.a AS t1_a, t2.a AS t2_a, t3.a AS t3_a
123    FROM base_table t1, base_table2 t2, temp_table t3
124    WHERE t1.id = t2.id and t2.id = t3.id;
125
126-- subqueries
127CREATE VIEW v4 AS SELECT * FROM base_table WHERE id IN (SELECT id FROM base_table2);
128CREATE VIEW v5 AS SELECT t1.id, t2.a FROM base_table t1, (SELECT * FROM base_table2) t2;
129CREATE VIEW v6 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1 FROM base_table2);
130CREATE VIEW v7 AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM base_table2);
131CREATE VIEW v8 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1);
132
133CREATE VIEW v6_temp AS SELECT * FROM base_table WHERE id IN (SELECT id FROM temp_table);
134CREATE VIEW v7_temp AS SELECT t1.id, t2.a FROM base_table t1, (SELECT * FROM temp_table) t2;
135CREATE VIEW v8_temp AS SELECT * FROM base_table WHERE EXISTS (SELECT 1 FROM temp_table);
136CREATE VIEW v9_temp AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM temp_table);
137
138-- a view should also be temporary if it references a temporary view
139CREATE VIEW v10_temp AS SELECT * FROM v7_temp;
140CREATE VIEW v11_temp AS SELECT t1.id, t2.a FROM base_table t1, v10_temp t2;
141CREATE VIEW v12_temp AS SELECT true FROM v11_temp;
142
143-- a view should also be temporary if it references a temporary sequence
144CREATE SEQUENCE seq1;
145CREATE TEMPORARY SEQUENCE seq1_temp;
146CREATE VIEW v9 AS SELECT seq1.is_called FROM seq1;
147CREATE VIEW v13_temp AS SELECT seq1_temp.is_called FROM seq1_temp;
148
149SELECT relname FROM pg_class
150    WHERE relname LIKE 'v_'
151    AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'temp_view_test')
152    ORDER BY relname;
153SELECT relname FROM pg_class
154    WHERE relname LIKE 'v%'
155    AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp%')
156    ORDER BY relname;
157
158CREATE SCHEMA testviewschm2;
159SET search_path TO testviewschm2, public;
160
161CREATE TABLE t1 (num int, name text);
162CREATE TABLE t2 (num2 int, value text);
163CREATE TEMP TABLE tt (num2 int, value text);
164
165CREATE VIEW nontemp1 AS SELECT * FROM t1 CROSS JOIN t2;
166CREATE VIEW temporal1 AS SELECT * FROM t1 CROSS JOIN tt;
167CREATE VIEW nontemp2 AS SELECT * FROM t1 INNER JOIN t2 ON t1.num = t2.num2;
168CREATE VIEW temporal2 AS SELECT * FROM t1 INNER JOIN tt ON t1.num = tt.num2;
169CREATE VIEW nontemp3 AS SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num2;
170CREATE VIEW temporal3 AS SELECT * FROM t1 LEFT JOIN tt ON t1.num = tt.num2;
171CREATE VIEW nontemp4 AS SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num2 AND t2.value = 'xxx';
172CREATE VIEW temporal4 AS SELECT * FROM t1 LEFT JOIN tt ON t1.num = tt.num2 AND tt.value = 'xxx';
173
174SELECT relname FROM pg_class
175    WHERE relname LIKE 'nontemp%'
176    AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'testviewschm2')
177    ORDER BY relname;
178SELECT relname FROM pg_class
179    WHERE relname LIKE 'temporal%'
180    AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp%')
181    ORDER BY relname;
182
183CREATE TABLE tbl1 ( a int, b int);
184CREATE TABLE tbl2 (c int, d int);
185CREATE TABLE tbl3 (e int, f int);
186CREATE TABLE tbl4 (g int, h int);
187CREATE TEMP TABLE tmptbl (i int, j int);
188
189--Should be in testviewschm2
190CREATE   VIEW  pubview AS SELECT * FROM tbl1 WHERE tbl1.a
191BETWEEN (SELECT d FROM tbl2 WHERE c = 1) AND (SELECT e FROM tbl3 WHERE f = 2)
192AND EXISTS (SELECT g FROM tbl4 LEFT JOIN tbl3 ON tbl4.h = tbl3.f);
193
194SELECT count(*) FROM pg_class where relname = 'pubview'
195AND relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname = 'testviewschm2');
196
197--Should be in temp object schema
198CREATE   VIEW  mytempview AS SELECT * FROM tbl1 WHERE tbl1.a
199BETWEEN (SELECT d FROM tbl2 WHERE c = 1) AND (SELECT e FROM tbl3 WHERE f = 2)
200AND EXISTS (SELECT g FROM tbl4 LEFT JOIN tbl3 ON tbl4.h = tbl3.f)
201AND NOT EXISTS (SELECT g FROM tbl4 LEFT JOIN tmptbl ON tbl4.h = tmptbl.j);
202
203SELECT count(*) FROM pg_class where relname LIKE 'mytempview'
204And relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname LIKE 'pg_temp%');
205
206--
207-- CREATE VIEW and WITH(...) clause
208--
209CREATE VIEW mysecview1
210       AS SELECT * FROM tbl1 WHERE a = 0;
211CREATE VIEW mysecview2 WITH (security_barrier=true)
212       AS SELECT * FROM tbl1 WHERE a > 0;
213CREATE VIEW mysecview3 WITH (security_barrier=false)
214       AS SELECT * FROM tbl1 WHERE a < 0;
215CREATE VIEW mysecview4 WITH (security_barrier)
216       AS SELECT * FROM tbl1 WHERE a <> 0;
217CREATE VIEW mysecview5 WITH (security_barrier=100)	-- Error
218       AS SELECT * FROM tbl1 WHERE a > 100;
219CREATE VIEW mysecview6 WITH (invalid_option)		-- Error
220       AS SELECT * FROM tbl1 WHERE a < 100;
221SELECT relname, relkind, reloptions FROM pg_class
222       WHERE oid in ('mysecview1'::regclass, 'mysecview2'::regclass,
223                     'mysecview3'::regclass, 'mysecview4'::regclass)
224       ORDER BY relname;
225
226CREATE OR REPLACE VIEW mysecview1
227       AS SELECT * FROM tbl1 WHERE a = 256;
228CREATE OR REPLACE VIEW mysecview2
229       AS SELECT * FROM tbl1 WHERE a > 256;
230CREATE OR REPLACE VIEW mysecview3 WITH (security_barrier=true)
231       AS SELECT * FROM tbl1 WHERE a < 256;
232CREATE OR REPLACE VIEW mysecview4 WITH (security_barrier=false)
233       AS SELECT * FROM tbl1 WHERE a <> 256;
234SELECT relname, relkind, reloptions FROM pg_class
235       WHERE oid in ('mysecview1'::regclass, 'mysecview2'::regclass,
236                     'mysecview3'::regclass, 'mysecview4'::regclass)
237       ORDER BY relname;
238
239-- This test checks that proper typmods are assigned in a multi-row VALUES
240
241CREATE VIEW tt1 AS
242  SELECT * FROM (
243    VALUES
244       ('abc'::varchar(3), '0123456789', 42, 'abcd'::varchar(4)),
245       ('0123456789', 'abc'::varchar(3), 42.12, 'abc'::varchar(4))
246  ) vv(a,b,c,d);
247\d+ tt1
248SELECT * FROM tt1;
249SELECT a::varchar(3) FROM tt1;
250DROP VIEW tt1;
251
252-- Test view decompilation in the face of relation renaming conflicts
253
254CREATE TABLE tt1 (f1 int, f2 int, f3 text);
255CREATE TABLE tx1 (x1 int, x2 int, x3 text);
256CREATE TABLE temp_view_test.tt1 (y1 int, f2 int, f3 text);
257
258CREATE VIEW aliased_view_1 AS
259  select * from tt1
260    where exists (select 1 from tx1 where tt1.f1 = tx1.x1);
261CREATE VIEW aliased_view_2 AS
262  select * from tt1 a1
263    where exists (select 1 from tx1 where a1.f1 = tx1.x1);
264CREATE VIEW aliased_view_3 AS
265  select * from tt1
266    where exists (select 1 from tx1 a2 where tt1.f1 = a2.x1);
267CREATE VIEW aliased_view_4 AS
268  select * from temp_view_test.tt1
269    where exists (select 1 from tt1 where temp_view_test.tt1.y1 = tt1.f1);
270
271\d+ aliased_view_1
272\d+ aliased_view_2
273\d+ aliased_view_3
274\d+ aliased_view_4
275
276ALTER TABLE tx1 RENAME TO a1;
277
278\d+ aliased_view_1
279\d+ aliased_view_2
280\d+ aliased_view_3
281\d+ aliased_view_4
282
283ALTER TABLE tt1 RENAME TO a2;
284
285\d+ aliased_view_1
286\d+ aliased_view_2
287\d+ aliased_view_3
288\d+ aliased_view_4
289
290ALTER TABLE a1 RENAME TO tt1;
291
292\d+ aliased_view_1
293\d+ aliased_view_2
294\d+ aliased_view_3
295\d+ aliased_view_4
296
297ALTER TABLE a2 RENAME TO tx1;
298ALTER TABLE tx1 SET SCHEMA temp_view_test;
299
300\d+ aliased_view_1
301\d+ aliased_view_2
302\d+ aliased_view_3
303\d+ aliased_view_4
304
305ALTER TABLE temp_view_test.tt1 RENAME TO tmp1;
306ALTER TABLE temp_view_test.tmp1 SET SCHEMA testviewschm2;
307ALTER TABLE tmp1 RENAME TO tx1;
308
309\d+ aliased_view_1
310\d+ aliased_view_2
311\d+ aliased_view_3
312\d+ aliased_view_4
313
314-- Test aliasing of joins
315
316create view view_of_joins as
317select * from
318  (select * from (tbl1 cross join tbl2) same) ss,
319  (tbl3 cross join tbl4) same;
320
321\d+ view_of_joins
322
323-- Test view decompilation in the face of column addition/deletion/renaming
324
325create table tt2 (a int, b int, c int);
326create table tt3 (ax int8, b int2, c numeric);
327create table tt4 (ay int, b int, q int);
328
329create view v1 as select * from tt2 natural join tt3;
330create view v1a as select * from (tt2 natural join tt3) j;
331create view v2 as select * from tt2 join tt3 using (b,c) join tt4 using (b);
332create view v2a as select * from (tt2 join tt3 using (b,c) join tt4 using (b)) j;
333create view v3 as select * from tt2 join tt3 using (b,c) full join tt4 using (b);
334
335select pg_get_viewdef('v1', true);
336select pg_get_viewdef('v1a', true);
337select pg_get_viewdef('v2', true);
338select pg_get_viewdef('v2a', true);
339select pg_get_viewdef('v3', true);
340
341alter table tt2 add column d int;
342alter table tt2 add column e int;
343
344select pg_get_viewdef('v1', true);
345select pg_get_viewdef('v1a', true);
346select pg_get_viewdef('v2', true);
347select pg_get_viewdef('v2a', true);
348select pg_get_viewdef('v3', true);
349
350alter table tt3 rename c to d;
351
352select pg_get_viewdef('v1', true);
353select pg_get_viewdef('v1a', true);
354select pg_get_viewdef('v2', true);
355select pg_get_viewdef('v2a', true);
356select pg_get_viewdef('v3', true);
357
358alter table tt3 add column c int;
359alter table tt3 add column e int;
360
361select pg_get_viewdef('v1', true);
362select pg_get_viewdef('v1a', true);
363select pg_get_viewdef('v2', true);
364select pg_get_viewdef('v2a', true);
365select pg_get_viewdef('v3', true);
366
367alter table tt2 drop column d;
368
369select pg_get_viewdef('v1', true);
370select pg_get_viewdef('v1a', true);
371select pg_get_viewdef('v2', true);
372select pg_get_viewdef('v2a', true);
373select pg_get_viewdef('v3', true);
374
375create table tt5 (a int, b int);
376create table tt6 (c int, d int);
377create view vv1 as select * from (tt5 cross join tt6) j(aa,bb,cc,dd);
378select pg_get_viewdef('vv1', true);
379alter table tt5 add column c int;
380select pg_get_viewdef('vv1', true);
381alter table tt5 add column cc int;
382select pg_get_viewdef('vv1', true);
383alter table tt5 drop column c;
384select pg_get_viewdef('vv1', true);
385
386-- Unnamed FULL JOIN USING is lots of fun too
387
388create table tt7 (x int, xx int, y int);
389alter table tt7 drop column xx;
390create table tt8 (x int, z int);
391
392create view vv2 as
393select * from (values(1,2,3,4,5)) v(a,b,c,d,e)
394union all
395select * from tt7 full join tt8 using (x), tt8 tt8x;
396
397select pg_get_viewdef('vv2', true);
398
399create view vv3 as
400select * from (values(1,2,3,4,5,6)) v(a,b,c,x,e,f)
401union all
402select * from
403  tt7 full join tt8 using (x),
404  tt7 tt7x full join tt8 tt8x using (x);
405
406select pg_get_viewdef('vv3', true);
407
408create view vv4 as
409select * from (values(1,2,3,4,5,6,7)) v(a,b,c,x,e,f,g)
410union all
411select * from
412  tt7 full join tt8 using (x),
413  tt7 tt7x full join tt8 tt8x using (x) full join tt8 tt8y using (x);
414
415select pg_get_viewdef('vv4', true);
416
417alter table tt7 add column zz int;
418alter table tt7 add column z int;
419alter table tt7 drop column zz;
420alter table tt8 add column z2 int;
421
422select pg_get_viewdef('vv2', true);
423select pg_get_viewdef('vv3', true);
424select pg_get_viewdef('vv4', true);
425
426-- Implicit coercions in a JOIN USING create issues similar to FULL JOIN
427
428create table tt7a (x date, xx int, y int);
429alter table tt7a drop column xx;
430create table tt8a (x timestamptz, z int);
431
432create view vv2a as
433select * from (values(now(),2,3,now(),5)) v(a,b,c,d,e)
434union all
435select * from tt7a left join tt8a using (x), tt8a tt8ax;
436
437select pg_get_viewdef('vv2a', true);
438
439--
440-- Also check dropping a column that existed when the view was made
441--
442
443create table tt9 (x int, xx int, y int);
444create table tt10 (x int, z int);
445
446create view vv5 as select x,y,z from tt9 join tt10 using(x);
447
448select pg_get_viewdef('vv5', true);
449
450alter table tt9 drop column xx;
451
452select pg_get_viewdef('vv5', true);
453
454--
455-- Another corner case is that we might add a column to a table below a
456-- JOIN USING, and thereby make the USING column name ambiguous
457--
458
459create table tt11 (x int, y int);
460create table tt12 (x int, z int);
461create table tt13 (z int, q int);
462
463create view vv6 as select x,y,z,q from
464  (tt11 join tt12 using(x)) join tt13 using(z);
465
466select pg_get_viewdef('vv6', true);
467
468alter table tt11 add column z int;
469
470select pg_get_viewdef('vv6', true);
471
472--
473-- Check some cases involving dropped columns in a function's rowtype result
474--
475
476create table tt14t (f1 text, f2 text, f3 text, f4 text);
477insert into tt14t values('foo', 'bar', 'baz', 'quux');
478
479alter table tt14t drop column f2;
480
481create function tt14f() returns setof tt14t as
482$$
483declare
484    rec1 record;
485begin
486    for rec1 in select * from tt14t
487    loop
488        return next rec1;
489    end loop;
490end;
491$$
492language plpgsql;
493
494create view tt14v as select t.* from tt14f() t;
495
496select pg_get_viewdef('tt14v', true);
497select * from tt14v;
498
499-- this perhaps should be rejected, but it isn't:
500alter table tt14t drop column f3;
501
502-- f3 is still in the view but will read as nulls
503select pg_get_viewdef('tt14v', true);
504select * from tt14v;
505
506-- check display of whole-row variables in some corner cases
507
508create type nestedcomposite as (x int8_tbl);
509create view tt15v as select row(i)::nestedcomposite from int8_tbl i;
510select * from tt15v;
511select pg_get_viewdef('tt15v', true);
512select row(i.*::int8_tbl)::nestedcomposite from int8_tbl i;
513
514create view tt16v as select * from int8_tbl i, lateral(values(i)) ss;
515select * from tt16v;
516select pg_get_viewdef('tt16v', true);
517select * from int8_tbl i, lateral(values(i.*::int8_tbl)) ss;
518
519create view tt17v as select * from int8_tbl i where i in (values(i));
520select * from tt17v;
521select pg_get_viewdef('tt17v', true);
522select * from int8_tbl i where i.* in (values(i.*::int8_tbl));
523
524-- check unique-ification of overlength names
525
526create view tt18v as
527  select * from int8_tbl xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxy
528  union all
529  select * from int8_tbl xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxz;
530select pg_get_viewdef('tt18v', true);
531explain (costs off) select * from tt18v;
532
533-- check display of ScalarArrayOp with a sub-select
534
535select 'foo'::text = any(array['abc','def','foo']::text[]);
536select 'foo'::text = any((select array['abc','def','foo']::text[]));  -- fail
537select 'foo'::text = any((select array['abc','def','foo']::text[])::text[]);
538
539create view tt19v as
540select 'foo'::text = any(array['abc','def','foo']::text[]) c1,
541       'foo'::text = any((select array['abc','def','foo']::text[])::text[]) c2;
542select pg_get_viewdef('tt19v', true);
543
544-- check display of assorted RTE_FUNCTION expressions
545
546create view tt20v as
547select * from
548  coalesce(1,2) as c,
549  collation for ('x'::text) col,
550  current_date as d,
551  cast(1+2 as int4) as i4,
552  cast(1+2 as int8) as i8;
553select pg_get_viewdef('tt20v', true);
554
555-- corner cases with empty join conditions
556
557create view tt21v as
558select * from tt5 natural inner join tt6;
559select pg_get_viewdef('tt21v', true);
560
561create view tt22v as
562select * from tt5 natural left join tt6;
563select pg_get_viewdef('tt22v', true);
564
565-- check handling of views with immediately-renamed columns
566
567create view tt23v (col_a, col_b) as
568select q1 as other_name1, q2 as other_name2 from int8_tbl
569union
570select 42, 43;
571
572select pg_get_viewdef('tt23v', true);
573select pg_get_ruledef(oid, true) from pg_rewrite
574  where ev_class = 'tt23v'::regclass and ev_type = '1';
575
576-- clean up all the random objects we made above
577set client_min_messages = warning;
578DROP SCHEMA temp_view_test CASCADE;
579DROP SCHEMA testviewschm2 CASCADE;
580