subselect.sql 26 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939
  1. --
  2. -- SUBSELECT
  3. --
  4. SELECT 1 AS one WHERE 1 IN (SELECT 1);
  5. SELECT 1 AS zero WHERE 1 NOT IN (SELECT 1);
  6. SELECT 1 AS zero WHERE 1 IN (SELECT 2);
  7. -- Check grammar's handling of extra parens in assorted contexts
  8. SELECT * FROM (SELECT 1 AS x) ss;
  9. SELECT * FROM ((SELECT 1 AS x)) ss;
  10. (SELECT 2) UNION SELECT 2;
  11. ((SELECT 2)) UNION SELECT 2;
  12. SELECT ((SELECT 2) UNION SELECT 2);
  13. SELECT (((SELECT 2)) UNION SELECT 2);
  14. SELECT (SELECT ARRAY[1,2,3])[1];
  15. SELECT ((SELECT ARRAY[1,2,3]))[2];
  16. SELECT (((SELECT ARRAY[1,2,3])))[3];
  17. -- Set up some simple test tables
  18. CREATE TABLE SUBSELECT_TBL (
  19. f1 integer,
  20. f2 integer,
  21. f3 float
  22. );
  23. INSERT INTO SUBSELECT_TBL VALUES (1, 2, 3);
  24. INSERT INTO SUBSELECT_TBL VALUES (2, 3, 4);
  25. INSERT INTO SUBSELECT_TBL VALUES (3, 4, 5);
  26. INSERT INTO SUBSELECT_TBL VALUES (1, 1, 1);
  27. INSERT INTO SUBSELECT_TBL VALUES (2, 2, 2);
  28. INSERT INTO SUBSELECT_TBL VALUES (3, 3, 3);
  29. INSERT INTO SUBSELECT_TBL VALUES (6, 7, 8);
  30. INSERT INTO SUBSELECT_TBL VALUES (8, 9, NULL);
  31. SELECT * FROM SUBSELECT_TBL;
  32. -- Uncorrelated subselects
  33. SELECT f1 AS "Constant Select" FROM SUBSELECT_TBL
  34. WHERE f1 IN (SELECT 1);
  35. SELECT f1 AS "Uncorrelated Field" FROM SUBSELECT_TBL
  36. WHERE f1 IN (SELECT f2 FROM SUBSELECT_TBL);
  37. SELECT f1 AS "Uncorrelated Field" FROM SUBSELECT_TBL
  38. WHERE f1 IN (SELECT f2 FROM SUBSELECT_TBL WHERE
  39. f2 IN (SELECT f1 FROM SUBSELECT_TBL));
  40. SELECT f1, f2
  41. FROM SUBSELECT_TBL
  42. WHERE (f1, f2) NOT IN (SELECT f2, CAST(f3 AS int4) FROM SUBSELECT_TBL
  43. WHERE f3 IS NOT NULL);
  44. -- Correlated subselects
  45. SELECT f1 AS "Correlated Field", f2 AS "Second Field"
  46. FROM SUBSELECT_TBL upper
  47. WHERE f1 IN (SELECT f2 FROM SUBSELECT_TBL WHERE f1 = upper.f1);
  48. SELECT f1 AS "Correlated Field", f3 AS "Second Field"
  49. FROM SUBSELECT_TBL upper
  50. WHERE f1 IN
  51. (SELECT f2 FROM SUBSELECT_TBL WHERE CAST(upper.f2 AS float) = f3);
  52. SELECT f1 AS "Correlated Field", f3 AS "Second Field"
  53. FROM SUBSELECT_TBL upper
  54. WHERE f3 IN (SELECT upper.f1 + f2 FROM SUBSELECT_TBL
  55. WHERE f2 = CAST(f3 AS integer));
  56. SELECT f1 AS "Correlated Field"
  57. FROM SUBSELECT_TBL
  58. WHERE (f1, f2) IN (SELECT f2, CAST(f3 AS int4) FROM SUBSELECT_TBL
  59. WHERE f3 IS NOT NULL);
  60. --
  61. -- Use some existing tables in the regression test
  62. --
  63. SELECT ss.f1 AS "Correlated Field", ss.f3 AS "Second Field"
  64. FROM SUBSELECT_TBL ss
  65. WHERE f1 NOT IN (SELECT f1+1 FROM INT4_TBL
  66. WHERE f1 != ss.f1 AND f1 < 2147483647);
  67. select q1, float8(count(*)) / (select count(*) from int8_tbl)
  68. from int8_tbl group by q1 order by q1;
  69. -- Unspecified-type literals in output columns should resolve as text
  70. SELECT *, pg_typeof(f1) FROM
  71. (SELECT 'foo' AS f1 FROM generate_series(1,3)) ss ORDER BY 1;
  72. -- ... unless there's context to suggest differently
  73. explain (verbose, costs off) select '42' union all select '43';
  74. explain (verbose, costs off) select '42' union all select 43;
  75. -- check materialization of an initplan reference (bug #14524)
  76. explain (verbose, costs off)
  77. select 1 = all (select (select 1));
  78. select 1 = all (select (select 1));
  79. --
  80. -- Check EXISTS simplification with LIMIT
  81. --
  82. explain (costs off)
  83. select * from int4_tbl o where exists
  84. (select 1 from int4_tbl i where i.f1=o.f1 limit null);
  85. explain (costs off)
  86. select * from int4_tbl o where not exists
  87. (select 1 from int4_tbl i where i.f1=o.f1 limit 1);
  88. explain (costs off)
  89. select * from int4_tbl o where exists
  90. (select 1 from int4_tbl i where i.f1=o.f1 limit 0);
  91. --
  92. -- Test cases to catch unpleasant interactions between IN-join processing
  93. -- and subquery pullup.
  94. --
  95. select count(*) from
  96. (select 1 from tenk1 a
  97. where unique1 IN (select hundred from tenk1 b)) ss;
  98. select count(distinct ss.ten) from
  99. (select ten from tenk1 a
  100. where unique1 IN (select hundred from tenk1 b)) ss;
  101. select count(*) from
  102. (select 1 from tenk1 a
  103. where unique1 IN (select distinct hundred from tenk1 b)) ss;
  104. select count(distinct ss.ten) from
  105. (select ten from tenk1 a
  106. where unique1 IN (select distinct hundred from tenk1 b)) ss;
  107. --
  108. -- Test cases to check for overenthusiastic optimization of
  109. -- "IN (SELECT DISTINCT ...)" and related cases. Per example from
  110. -- Luca Pireddu and Michael Fuhr.
  111. --
  112. CREATE TEMP TABLE foo (id integer);
  113. CREATE TEMP TABLE bar (id1 integer, id2 integer);
  114. INSERT INTO foo VALUES (1);
  115. INSERT INTO bar VALUES (1, 1);
  116. INSERT INTO bar VALUES (2, 2);
  117. INSERT INTO bar VALUES (3, 1);
  118. -- These cases require an extra level of distinct-ing above subquery s
  119. SELECT * FROM foo WHERE id IN
  120. (SELECT id2 FROM (SELECT DISTINCT id1, id2 FROM bar) AS s);
  121. SELECT * FROM foo WHERE id IN
  122. (SELECT id2 FROM (SELECT id1,id2 FROM bar GROUP BY id1,id2) AS s);
  123. SELECT * FROM foo WHERE id IN
  124. (SELECT id2 FROM (SELECT id1, id2 FROM bar UNION
  125. SELECT id1, id2 FROM bar) AS s);
  126. -- These cases do not
  127. SELECT * FROM foo WHERE id IN
  128. (SELECT id2 FROM (SELECT DISTINCT ON (id2) id1, id2 FROM bar) AS s);
  129. SELECT * FROM foo WHERE id IN
  130. (SELECT id2 FROM (SELECT id2 FROM bar GROUP BY id2) AS s);
  131. SELECT * FROM foo WHERE id IN
  132. (SELECT id2 FROM (SELECT id2 FROM bar UNION
  133. SELECT id2 FROM bar) AS s);
  134. --
  135. -- Test case to catch problems with multiply nested sub-SELECTs not getting
  136. -- recalculated properly. Per bug report from Didier Moens.
  137. --
  138. CREATE TABLE orderstest (
  139. approver_ref integer,
  140. po_ref integer,
  141. ordercanceled boolean
  142. );
  143. INSERT INTO orderstest VALUES (1, 1, false);
  144. INSERT INTO orderstest VALUES (66, 5, false);
  145. INSERT INTO orderstest VALUES (66, 6, false);
  146. INSERT INTO orderstest VALUES (66, 7, false);
  147. INSERT INTO orderstest VALUES (66, 1, true);
  148. INSERT INTO orderstest VALUES (66, 8, false);
  149. INSERT INTO orderstest VALUES (66, 1, false);
  150. INSERT INTO orderstest VALUES (77, 1, false);
  151. INSERT INTO orderstest VALUES (1, 1, false);
  152. INSERT INTO orderstest VALUES (66, 1, false);
  153. INSERT INTO orderstest VALUES (1, 1, false);
  154. CREATE VIEW orders_view AS
  155. SELECT *,
  156. (SELECT CASE
  157. WHEN ord.approver_ref=1 THEN '---' ELSE 'Approved'
  158. END) AS "Approved",
  159. (SELECT CASE
  160. WHEN ord.ordercanceled
  161. THEN 'Canceled'
  162. ELSE
  163. (SELECT CASE
  164. WHEN ord.po_ref=1
  165. THEN
  166. (SELECT CASE
  167. WHEN ord.approver_ref=1
  168. THEN '---'
  169. ELSE 'Approved'
  170. END)
  171. ELSE 'PO'
  172. END)
  173. END) AS "Status",
  174. (CASE
  175. WHEN ord.ordercanceled
  176. THEN 'Canceled'
  177. ELSE
  178. (CASE
  179. WHEN ord.po_ref=1
  180. THEN
  181. (CASE
  182. WHEN ord.approver_ref=1
  183. THEN '---'
  184. ELSE 'Approved'
  185. END)
  186. ELSE 'PO'
  187. END)
  188. END) AS "Status_OK"
  189. FROM orderstest ord;
  190. SELECT * FROM orders_view;
  191. DROP TABLE orderstest cascade;
  192. --
  193. -- Test cases to catch situations where rule rewriter fails to propagate
  194. -- hasSubLinks flag correctly. Per example from Kyle Bateman.
  195. --
  196. create temp table parts (
  197. partnum text,
  198. cost float8
  199. );
  200. create temp table shipped (
  201. ttype char(2),
  202. ordnum int4,
  203. partnum text,
  204. value float8
  205. );
  206. create temp view shipped_view as
  207. select * from shipped where ttype = 'wt';
  208. create rule shipped_view_insert as on insert to shipped_view do instead
  209. insert into shipped values('wt', new.ordnum, new.partnum, new.value);
  210. insert into parts (partnum, cost) values (1, 1234.56);
  211. insert into shipped_view (ordnum, partnum, value)
  212. values (0, 1, (select cost from parts where partnum = '1'));
  213. select * from shipped_view;
  214. create rule shipped_view_update as on update to shipped_view do instead
  215. update shipped set partnum = new.partnum, value = new.value
  216. where ttype = new.ttype and ordnum = new.ordnum;
  217. update shipped_view set value = 11
  218. from int4_tbl a join int4_tbl b
  219. on (a.f1 = (select f1 from int4_tbl c where c.f1=b.f1))
  220. where ordnum = a.f1;
  221. select * from shipped_view;
  222. select f1, ss1 as relabel from
  223. (select *, (select sum(f1) from int4_tbl b where f1 >= a.f1) as ss1
  224. from int4_tbl a) ss;
  225. --
  226. -- Test cases involving PARAM_EXEC parameters and min/max index optimizations.
  227. -- Per bug report from David Sanchez i Gregori.
  228. --
  229. select * from (
  230. select max(unique1) from tenk1 as a
  231. where exists (select 1 from tenk1 as b where b.thousand = a.unique2)
  232. ) ss;
  233. select * from (
  234. select min(unique1) from tenk1 as a
  235. where not exists (select 1 from tenk1 as b where b.unique2 = 10000)
  236. ) ss;
  237. --
  238. -- Test that an IN implemented using a UniquePath does unique-ification
  239. -- with the right semantics, as per bug #4113. (Unfortunately we have
  240. -- no simple way to ensure that this test case actually chooses that type
  241. -- of plan, but it does in releases 7.4-8.3. Note that an ordering difference
  242. -- here might mean that some other plan type is being used, rendering the test
  243. -- pointless.)
  244. --
  245. create temp table numeric_table (num_col numeric);
  246. insert into numeric_table values (1), (1.000000000000000000001), (2), (3);
  247. create temp table float_table (float_col float8);
  248. insert into float_table values (1), (2), (3);
  249. select * from float_table
  250. where float_col in (select num_col from numeric_table);
  251. select * from numeric_table
  252. where num_col in (select float_col from float_table);
  253. --
  254. -- Test case for bug #4290: bogus calculation of subplan param sets
  255. --
  256. create temp table ta (id int primary key, val int);
  257. insert into ta values(1,1);
  258. insert into ta values(2,2);
  259. create temp table tb (id int primary key, aval int);
  260. insert into tb values(1,1);
  261. insert into tb values(2,1);
  262. insert into tb values(3,2);
  263. insert into tb values(4,2);
  264. create temp table tc (id int primary key, aid int);
  265. insert into tc values(1,1);
  266. insert into tc values(2,2);
  267. select
  268. ( select min(tb.id) from tb
  269. where tb.aval = (select ta.val from ta where ta.id = tc.aid) ) as min_tb_id
  270. from tc;
  271. --
  272. -- Test case for 8.3 "failed to locate grouping columns" bug
  273. --
  274. create temp table t1 (f1 numeric(14,0), f2 varchar(30));
  275. select * from
  276. (select distinct f1, f2, (select f2 from t1 x where x.f1 = up.f1) as fs
  277. from t1 up) ss
  278. group by f1,f2,fs;
  279. --
  280. -- Test case for bug #5514 (mishandling of whole-row Vars in subselects)
  281. --
  282. create temp table table_a(id integer);
  283. insert into table_a values (42);
  284. create temp view view_a as select * from table_a;
  285. select view_a from view_a;
  286. select (select view_a) from view_a;
  287. select (select (select view_a)) from view_a;
  288. select (select (a.*)::text) from view_a a;
  289. --
  290. -- Check that whole-row Vars reading the result of a subselect don't include
  291. -- any junk columns therein
  292. --
  293. select q from (select max(f1) from int4_tbl group by f1 order by f1) q;
  294. with q as (select max(f1) from int4_tbl group by f1 order by f1)
  295. select q from q;
  296. --
  297. -- Test case for sublinks pulled up into joinaliasvars lists in an
  298. -- inherited update/delete query
  299. --
  300. begin; -- this shouldn't delete anything, but be safe
  301. delete from road
  302. where exists (
  303. select 1
  304. from
  305. int4_tbl cross join
  306. ( select f1, array(select q1 from int8_tbl) as arr
  307. from text_tbl ) ss
  308. where road.name = ss.f1 );
  309. rollback;
  310. --
  311. -- Test case for sublinks pushed down into subselects via join alias expansion
  312. --
  313. select
  314. (select sq1) as qq1
  315. from
  316. (select exists(select 1 from int4_tbl where f1 = q2) as sq1, 42 as dummy
  317. from int8_tbl) sq0
  318. join
  319. int4_tbl i4 on dummy = i4.f1;
  320. --
  321. -- Test case for subselect within UPDATE of INSERT...ON CONFLICT DO UPDATE
  322. --
  323. create temp table upsert(key int4 primary key, val text);
  324. insert into upsert values(1, 'val') on conflict (key) do update set val = 'not seen';
  325. insert into upsert values(1, 'val') on conflict (key) do update set val = 'seen with subselect ' || (select f1 from int4_tbl where f1 != 0 limit 1)::text;
  326. select * from upsert;
  327. with aa as (select 'int4_tbl' u from int4_tbl limit 1)
  328. insert into upsert values (1, 'x'), (999, 'y')
  329. on conflict (key) do update set val = (select u from aa)
  330. returning *;
  331. --
  332. -- Test case for cross-type partial matching in hashed subplan (bug #7597)
  333. --
  334. create temp table outer_7597 (f1 int4, f2 int4);
  335. insert into outer_7597 values (0, 0);
  336. insert into outer_7597 values (1, 0);
  337. insert into outer_7597 values (0, null);
  338. insert into outer_7597 values (1, null);
  339. create temp table inner_7597(c1 int8, c2 int8);
  340. insert into inner_7597 values(0, null);
  341. select * from outer_7597 where (f1, f2) not in (select * from inner_7597);
  342. --
  343. -- Similar test case using text that verifies that collation
  344. -- information is passed through by execTuplesEqual() in nodeSubplan.c
  345. -- (otherwise it would error in texteq())
  346. --
  347. create temp table outer_text (f1 text, f2 text);
  348. insert into outer_text values ('a', 'a');
  349. insert into outer_text values ('b', 'a');
  350. insert into outer_text values ('a', null);
  351. insert into outer_text values ('b', null);
  352. create temp table inner_text (c1 text, c2 text);
  353. insert into inner_text values ('a', null);
  354. insert into inner_text values ('123', '456');
  355. select * from outer_text where (f1, f2) not in (select * from inner_text);
  356. --
  357. -- Another test case for cross-type hashed subplans: comparison of
  358. -- inner-side values must be done with appropriate operator
  359. --
  360. explain (verbose, costs off)
  361. select 'foo'::text in (select 'bar'::name union all select 'bar'::name);
  362. select 'foo'::text in (select 'bar'::name union all select 'bar'::name);
  363. --
  364. -- Test that we don't try to hash nested records (bug #17363)
  365. -- (Hashing could be supported, but for now we don't)
  366. --
  367. explain (verbose, costs off)
  368. select row(row(row(1))) = any (select row(row(1)));
  369. select row(row(row(1))) = any (select row(row(1)));
  370. --
  371. -- Test case for premature memory release during hashing of subplan output
  372. --
  373. select '1'::text in (select '1'::name union all select '1'::name);
  374. --
  375. -- Test that we don't try to use a hashed subplan if the simplified
  376. -- testexpr isn't of the right shape
  377. --
  378. -- this fails by default, of course
  379. select * from int8_tbl where q1 in (select c1 from inner_text);
  380. begin;
  381. -- make an operator to allow it to succeed
  382. create function bogus_int8_text_eq(int8, text) returns boolean
  383. language sql as 'select $1::text = $2';
  384. create operator = (procedure=bogus_int8_text_eq, leftarg=int8, rightarg=text);
  385. explain (costs off)
  386. select * from int8_tbl where q1 in (select c1 from inner_text);
  387. select * from int8_tbl where q1 in (select c1 from inner_text);
  388. -- inlining of this function results in unusual number of hash clauses,
  389. -- which we can still cope with
  390. create or replace function bogus_int8_text_eq(int8, text) returns boolean
  391. language sql as 'select $1::text = $2 and $1::text = $2';
  392. explain (costs off)
  393. select * from int8_tbl where q1 in (select c1 from inner_text);
  394. select * from int8_tbl where q1 in (select c1 from inner_text);
  395. -- inlining of this function causes LHS and RHS to be switched,
  396. -- which we can't cope with, so hashing should be abandoned
  397. create or replace function bogus_int8_text_eq(int8, text) returns boolean
  398. language sql as 'select $2 = $1::text';
  399. explain (costs off)
  400. select * from int8_tbl where q1 in (select c1 from inner_text);
  401. select * from int8_tbl where q1 in (select c1 from inner_text);
  402. rollback; -- to get rid of the bogus operator
  403. --
  404. -- Test resolution of hashed vs non-hashed implementation of EXISTS subplan
  405. --
  406. explain (costs off)
  407. select count(*) from tenk1 t
  408. where (exists(select 1 from tenk1 k where k.unique1 = t.unique2) or ten < 0);
  409. select count(*) from tenk1 t
  410. where (exists(select 1 from tenk1 k where k.unique1 = t.unique2) or ten < 0);
  411. explain (costs off)
  412. select count(*) from tenk1 t
  413. where (exists(select 1 from tenk1 k where k.unique1 = t.unique2) or ten < 0)
  414. and thousand = 1;
  415. select count(*) from tenk1 t
  416. where (exists(select 1 from tenk1 k where k.unique1 = t.unique2) or ten < 0)
  417. and thousand = 1;
  418. -- It's possible for the same EXISTS to get resolved both ways
  419. create temp table exists_tbl (c1 int, c2 int, c3 int) partition by list (c1);
  420. create temp table exists_tbl_null partition of exists_tbl for values in (null);
  421. create temp table exists_tbl_def partition of exists_tbl default;
  422. insert into exists_tbl select x, x/2, x+1 from generate_series(0,10) x;
  423. analyze exists_tbl;
  424. explain (costs off)
  425. select * from exists_tbl t1
  426. where (exists(select 1 from exists_tbl t2 where t1.c1 = t2.c2) or c3 < 0);
  427. select * from exists_tbl t1
  428. where (exists(select 1 from exists_tbl t2 where t1.c1 = t2.c2) or c3 < 0);
  429. --
  430. -- Test case for planner bug with nested EXISTS handling
  431. --
  432. select a.thousand from tenk1 a, tenk1 b
  433. where a.thousand = b.thousand
  434. and exists ( select 1 from tenk1 c where b.hundred = c.hundred
  435. and not exists ( select 1 from tenk1 d
  436. where a.thousand = d.thousand ) );
  437. --
  438. -- Check that nested sub-selects are not pulled up if they contain volatiles
  439. --
  440. explain (verbose, costs off)
  441. select x, x from
  442. (select (select now()) as x from (values(1),(2)) v(y)) ss;
  443. explain (verbose, costs off)
  444. select x, x from
  445. (select (select random()) as x from (values(1),(2)) v(y)) ss;
  446. explain (verbose, costs off)
  447. select x, x from
  448. (select (select now() where y=y) as x from (values(1),(2)) v(y)) ss;
  449. explain (verbose, costs off)
  450. select x, x from
  451. (select (select random() where y=y) as x from (values(1),(2)) v(y)) ss;
  452. --
  453. -- Test rescan of a hashed subplan (the use of random() is to prevent the
  454. -- sub-select from being pulled up, which would result in not hashing)
  455. --
  456. explain (verbose, costs off)
  457. select sum(ss.tst::int) from
  458. onek o cross join lateral (
  459. select i.ten in (select f1 from int4_tbl where f1 <= o.hundred) as tst,
  460. random() as r
  461. from onek i where i.unique1 = o.unique1 ) ss
  462. where o.ten = 0;
  463. select sum(ss.tst::int) from
  464. onek o cross join lateral (
  465. select i.ten in (select f1 from int4_tbl where f1 <= o.hundred) as tst,
  466. random() as r
  467. from onek i where i.unique1 = o.unique1 ) ss
  468. where o.ten = 0;
  469. --
  470. -- Test rescan of a SetOp node
  471. --
  472. explain (costs off)
  473. select count(*) from
  474. onek o cross join lateral (
  475. select * from onek i1 where i1.unique1 = o.unique1
  476. except
  477. select * from onek i2 where i2.unique1 = o.unique2
  478. ) ss
  479. where o.ten = 1;
  480. select count(*) from
  481. onek o cross join lateral (
  482. select * from onek i1 where i1.unique1 = o.unique1
  483. except
  484. select * from onek i2 where i2.unique1 = o.unique2
  485. ) ss
  486. where o.ten = 1;
  487. --
  488. -- Test rescan of a RecursiveUnion node
  489. --
  490. explain (costs off)
  491. select sum(o.four), sum(ss.a) from
  492. onek o cross join lateral (
  493. with recursive x(a) as
  494. (select o.four as a
  495. union
  496. select a + 1 from x
  497. where a < 10)
  498. select * from x
  499. ) ss
  500. where o.ten = 1;
  501. select sum(o.four), sum(ss.a) from
  502. onek o cross join lateral (
  503. with recursive x(a) as
  504. (select o.four as a
  505. union
  506. select a + 1 from x
  507. where a < 10)
  508. select * from x
  509. ) ss
  510. where o.ten = 1;
  511. --
  512. -- Check we don't misoptimize a NOT IN where the subquery returns no rows.
  513. --
  514. create temp table notinouter (a int);
  515. create temp table notininner (b int not null);
  516. insert into notinouter values (null), (1);
  517. select * from notinouter where a not in (select b from notininner);
  518. --
  519. -- Check we behave sanely in corner case of empty SELECT list (bug #8648)
  520. --
  521. create temp table nocolumns();
  522. select exists(select * from nocolumns);
  523. --
  524. -- Check behavior with a SubPlan in VALUES (bug #14924)
  525. --
  526. select val.x
  527. from generate_series(1,10) as s(i),
  528. lateral (
  529. values ((select s.i + 1)), (s.i + 101)
  530. ) as val(x)
  531. where s.i < 10 and (select val.x) < 110;
  532. -- another variant of that (bug #16213)
  533. explain (verbose, costs off)
  534. select * from
  535. (values
  536. (3 not in (select * from (values (1), (2)) ss1)),
  537. (false)
  538. ) ss;
  539. select * from
  540. (values
  541. (3 not in (select * from (values (1), (2)) ss1)),
  542. (false)
  543. ) ss;
  544. --
  545. -- Check sane behavior with nested IN SubLinks
  546. --
  547. explain (verbose, costs off)
  548. select * from int4_tbl where
  549. (case when f1 in (select unique1 from tenk1 a) then f1 else null end) in
  550. (select ten from tenk1 b);
  551. select * from int4_tbl where
  552. (case when f1 in (select unique1 from tenk1 a) then f1 else null end) in
  553. (select ten from tenk1 b);
  554. --
  555. -- Check for incorrect optimization when IN subquery contains a SRF
  556. --
  557. explain (verbose, costs off)
  558. select * from int4_tbl o where (f1, f1) in
  559. (select f1, generate_series(1,50) / 10 g from int4_tbl i group by f1);
  560. select * from int4_tbl o where (f1, f1) in
  561. (select f1, generate_series(1,50) / 10 g from int4_tbl i group by f1);
  562. --
  563. -- check for over-optimization of whole-row Var referencing an Append plan
  564. --
  565. select (select q from
  566. (select 1,2,3 where f1 > 0
  567. union all
  568. select 4,5,6.0 where f1 <= 0
  569. ) q )
  570. from int4_tbl;
  571. --
  572. -- Check for sane handling of a lateral reference in a subquery's quals
  573. -- (most of the complication here is to prevent the test case from being
  574. -- flattened too much)
  575. --
  576. explain (verbose, costs off)
  577. select * from
  578. int4_tbl i4,
  579. lateral (
  580. select i4.f1 > 1 as b, 1 as id
  581. from (select random() order by 1) as t1
  582. union all
  583. select true as b, 2 as id
  584. ) as t2
  585. where b and f1 >= 0;
  586. select * from
  587. int4_tbl i4,
  588. lateral (
  589. select i4.f1 > 1 as b, 1 as id
  590. from (select random() order by 1) as t1
  591. union all
  592. select true as b, 2 as id
  593. ) as t2
  594. where b and f1 >= 0;
  595. --
  596. -- Check that volatile quals aren't pushed down past a DISTINCT:
  597. -- nextval() should not be called more than the nominal number of times
  598. --
  599. create temp sequence ts1;
  600. select * from
  601. (select distinct ten from tenk1) ss
  602. where ten < 10 + nextval('ts1')
  603. order by 1;
  604. select nextval('ts1');
  605. --
  606. -- Check that volatile quals aren't pushed down past a set-returning function;
  607. -- while a nonvolatile qual can be, if it doesn't reference the SRF.
  608. --
  609. create function tattle(x int, y int) returns bool
  610. volatile language plpgsql as $$
  611. begin
  612. raise notice 'x = %, y = %', x, y;
  613. return x > y;
  614. end$$;
  615. explain (verbose, costs off)
  616. select * from
  617. (select 9 as x, unnest(array[1,2,3,11,12,13]) as u) ss
  618. where tattle(x, 8);
  619. select * from
  620. (select 9 as x, unnest(array[1,2,3,11,12,13]) as u) ss
  621. where tattle(x, 8);
  622. -- if we pretend it's stable, we get different results:
  623. alter function tattle(x int, y int) stable;
  624. explain (verbose, costs off)
  625. select * from
  626. (select 9 as x, unnest(array[1,2,3,11,12,13]) as u) ss
  627. where tattle(x, 8);
  628. select * from
  629. (select 9 as x, unnest(array[1,2,3,11,12,13]) as u) ss
  630. where tattle(x, 8);
  631. -- although even a stable qual should not be pushed down if it references SRF
  632. explain (verbose, costs off)
  633. select * from
  634. (select 9 as x, unnest(array[1,2,3,11,12,13]) as u) ss
  635. where tattle(x, u);
  636. select * from
  637. (select 9 as x, unnest(array[1,2,3,11,12,13]) as u) ss
  638. where tattle(x, u);
  639. drop function tattle(x int, y int);
  640. --
  641. -- Test that LIMIT can be pushed to SORT through a subquery that just projects
  642. -- columns. We check for that having happened by looking to see if EXPLAIN
  643. -- ANALYZE shows that a top-N sort was used. We must suppress or filter away
  644. -- all the non-invariant parts of the EXPLAIN ANALYZE output.
  645. --
  646. create table sq_limit (pk int primary key, c1 int, c2 int);
  647. insert into sq_limit values
  648. (1, 1, 1),
  649. (2, 2, 2),
  650. (3, 3, 3),
  651. (4, 4, 4),
  652. (5, 1, 1),
  653. (6, 2, 2),
  654. (7, 3, 3),
  655. (8, 4, 4);
  656. create function explain_sq_limit() returns setof text language plpgsql as
  657. $$
  658. declare ln text;
  659. begin
  660. for ln in
  661. explain (analyze, summary off, timing off, costs off)
  662. select * from (select pk,c2 from sq_limit order by c1,pk) as x limit 3
  663. loop
  664. ln := regexp_replace(ln, 'Memory: \S*', 'Memory: xxx');
  665. return next ln;
  666. end loop;
  667. end;
  668. $$;
  669. select * from explain_sq_limit();
  670. select * from (select pk,c2 from sq_limit order by c1,pk) as x limit 3;
  671. drop function explain_sq_limit();
  672. drop table sq_limit;
  673. --
  674. -- Ensure that backward scan direction isn't propagated into
  675. -- expression subqueries (bug #15336)
  676. --
  677. begin;
  678. declare c1 scroll cursor for
  679. select * from generate_series(1,4) i
  680. where i <> all (values (2),(3));
  681. move forward all in c1;
  682. fetch backward all in c1;
  683. commit;
  684. --
  685. -- Tests for CTE inlining behavior
  686. --
  687. -- Basic subquery that can be inlined
  688. explain (verbose, costs off)
  689. with x as (select * from (select f1 from subselect_tbl) ss)
  690. select * from x where f1 = 1;
  691. -- Explicitly request materialization
  692. explain (verbose, costs off)
  693. with x as materialized (select * from (select f1 from subselect_tbl) ss)
  694. select * from x where f1 = 1;
  695. -- Stable functions are safe to inline
  696. explain (verbose, costs off)
  697. with x as (select * from (select f1, now() from subselect_tbl) ss)
  698. select * from x where f1 = 1;
  699. -- Volatile functions prevent inlining
  700. explain (verbose, costs off)
  701. with x as (select * from (select f1, random() from subselect_tbl) ss)
  702. select * from x where f1 = 1;
  703. -- SELECT FOR UPDATE cannot be inlined
  704. explain (verbose, costs off)
  705. with x as (select * from (select f1 from subselect_tbl for update) ss)
  706. select * from x where f1 = 1;
  707. -- Multiply-referenced CTEs are inlined only when requested
  708. explain (verbose, costs off)
  709. with x as (select * from (select f1, now() as n from subselect_tbl) ss)
  710. select * from x, x x2 where x.n = x2.n;
  711. explain (verbose, costs off)
  712. with x as not materialized (select * from (select f1, now() as n from subselect_tbl) ss)
  713. select * from x, x x2 where x.n = x2.n;
  714. -- Multiply-referenced CTEs can't be inlined if they contain outer self-refs
  715. explain (verbose, costs off)
  716. with recursive x(a) as
  717. ((values ('a'), ('b'))
  718. union all
  719. (with z as not materialized (select * from x)
  720. select z.a || z1.a as a from z cross join z as z1
  721. where length(z.a || z1.a) < 5))
  722. select * from x;
  723. with recursive x(a) as
  724. ((values ('a'), ('b'))
  725. union all
  726. (with z as not materialized (select * from x)
  727. select z.a || z1.a as a from z cross join z as z1
  728. where length(z.a || z1.a) < 5))
  729. select * from x;
  730. explain (verbose, costs off)
  731. with recursive x(a) as
  732. ((values ('a'), ('b'))
  733. union all
  734. (with z as not materialized (select * from x)
  735. select z.a || z.a as a from z
  736. where length(z.a || z.a) < 5))
  737. select * from x;
  738. with recursive x(a) as
  739. ((values ('a'), ('b'))
  740. union all
  741. (with z as not materialized (select * from x)
  742. select z.a || z.a as a from z
  743. where length(z.a || z.a) < 5))
  744. select * from x;
  745. -- Check handling of outer references
  746. explain (verbose, costs off)
  747. with x as (select * from int4_tbl)
  748. select * from (with y as (select * from x) select * from y) ss;
  749. explain (verbose, costs off)
  750. with x as materialized (select * from int4_tbl)
  751. select * from (with y as (select * from x) select * from y) ss;
  752. -- Ensure that we inline the currect CTE when there are
  753. -- multiple CTEs with the same name
  754. explain (verbose, costs off)
  755. with x as (select 1 as y)
  756. select * from (with x as (select 2 as y) select * from x) ss;
  757. -- Row marks are not pushed into CTEs
  758. explain (verbose, costs off)
  759. with x as (select * from subselect_tbl)
  760. select * from x for update;