Skip to content

Commit 53247fe

Browse files
committed
[SPARK-18872] New test cases for EXISTS subquery
1 parent 8f3f73a commit 53247fe

File tree

4 files changed

+568
-0
lines changed

4 files changed

+568
-0
lines changed
Lines changed: 115 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,115 @@
1+
-- Tests EXISTS subquery support. Tests basic form
2+
-- of EXISTS subquery (both EXISTS and NOT EXISTS)
3+
4+
CREATE TEMPORARY VIEW EMP AS SELECT * FROM VALUES
5+
(100, "emp 1", date "2005-01-01", 100.00D, 10),
6+
(100, "emp 1", date "2005-01-01", 100.00D, 10),
7+
(200, "emp 2", date "2003-01-01", 200.00D, 10),
8+
(300, "emp 3", date "2002-01-01", 300.00D, 20),
9+
(400, "emp 4", date "2005-01-01", 400.00D, 30),
10+
(500, "emp 5", date "2001-01-01", 400.00D, NULL),
11+
(600, "emp 6 - no dept", date "2001-01-01", 400.00D, 100),
12+
(700, "emp 7", date "2010-01-01", 400.00D, 100),
13+
(800, "emp 8", date "2016-01-01", 150.00D, 70)
14+
AS EMP(id, emp_name, hiredate, salary, dept_id);
15+
16+
CREATE TEMPORARY VIEW DEPT AS SELECT * FROM VALUES
17+
(10, "dept 1", "CA"),
18+
(20, "dept 2", "NY"),
19+
(30, "dept 3", "TX"),
20+
(40, "dept 4 - unassigned", "OR"),
21+
(50, "dept 5 - unassigned", "NJ"),
22+
(70, "dept 7", "FL")
23+
AS DEPT(dept_id, dept_name, state);
24+
25+
CREATE TEMPORARY VIEW BONUS AS SELECT * FROM VALUES
26+
("emp 1", 10.00D),
27+
("emp 1", 20.00D),
28+
("emp 2", 300.00D),
29+
("emp 2", 100.00D),
30+
("emp 3", 300.00D),
31+
("emp 4", 100.00D),
32+
("emp 5", 1000.00D),
33+
("emp 6 - no dept", 500.00D)
34+
AS BONUS(emp_name, bonus_amt);
35+
36+
-- uncorrelated exist query
37+
-- TC.01.01
38+
SELECT *
39+
FROM emp
40+
WHERE EXISTS (SELECT 1
41+
FROM dept
42+
WHERE dept.dept_id > 10
43+
AND dept.dept_id < 30);
44+
45+
-- simple correlated predicate in exist subquery
46+
-- TC.01.02
47+
SELECT *
48+
FROM emp
49+
WHERE EXISTS (SELECT dept.dept_name
50+
FROM dept
51+
WHERE emp.dept_id = dept.dept_id);
52+
53+
-- correlated outer isnull predicate
54+
-- TC.01.03
55+
SELECT *
56+
FROM emp
57+
WHERE EXISTS (SELECT dept.dept_name
58+
FROM dept
59+
WHERE emp.dept_id = dept.dept_id
60+
OR emp.dept_id IS NULL);
61+
62+
-- Simple correlation with a local predicate in outer query
63+
-- TC.01.04
64+
SELECT *
65+
FROM emp
66+
WHERE EXISTS (SELECT dept.dept_name
67+
FROM dept
68+
WHERE emp.dept_id = dept.dept_id)
69+
AND emp.id > 200;
70+
71+
-- Outer references (emp.id) should not be pruned from outer plan
72+
-- TC.01.05
73+
SELECT emp.emp_name
74+
FROM emp
75+
WHERE EXISTS (SELECT dept.state
76+
FROM dept
77+
WHERE emp.dept_id = dept.dept_id)
78+
AND emp.id > 200;
79+
80+
-- not exists with correlated predicate
81+
-- TC.01.06
82+
SELECT *
83+
FROM dept
84+
WHERE NOT EXISTS (SELECT emp_name
85+
FROM emp
86+
WHERE emp.dept_id = dept.dept_id);
87+
88+
-- not exists with correlated predicate + local predicate
89+
-- TC.01.07
90+
SELECT *
91+
FROM dept
92+
WHERE NOT EXISTS (SELECT emp_name
93+
FROM emp
94+
WHERE emp.dept_id = dept.dept_id
95+
OR state = 'NJ');
96+
97+
-- not exist both equal and greaterthan predicate
98+
-- TC.01.08
99+
SELECT *
100+
FROM bonus
101+
WHERE NOT EXISTS (SELECT *
102+
FROM emp
103+
WHERE emp.emp_name = emp_name
104+
AND bonus_amt > emp.salary);
105+
106+
-- Nested exists
107+
-- TC.01.09
108+
SELECT *
109+
FROM bonus
110+
WHERE EXISTS (SELECT emp_name
111+
FROM emp
112+
WHERE bonus.emp_name = emp.emp_name
113+
AND EXISTS (SELECT state
114+
FROM dept
115+
WHERE dept.dept_id = emp.dept_id));
Lines changed: 96 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
1+
-- Tests EXISTS subquery support. Tests EXISTS
2+
-- subquery within a AND or OR expression.
3+
4+
CREATE TEMPORARY VIEW EMP AS SELECT * FROM VALUES
5+
(100, "emp 1", date "2005-01-01", 100.00D, 10),
6+
(100, "emp 1", date "2005-01-01", 100.00D, 10),
7+
(200, "emp 2", date "2003-01-01", 200.00D, 10),
8+
(300, "emp 3", date "2002-01-01", 300.00D, 20),
9+
(400, "emp 4", date "2005-01-01", 400.00D, 30),
10+
(500, "emp 5", date "2001-01-01", 400.00D, NULL),
11+
(600, "emp 6 - no dept", date "2001-01-01", 400.00D, 100),
12+
(700, "emp 7", date "2010-01-01", 400.00D, 100),
13+
(800, "emp 8", date "2016-01-01", 150.00D, 70)
14+
AS EMP(id, emp_name, hiredate, salary, dept_id);
15+
16+
CREATE TEMPORARY VIEW DEPT AS SELECT * FROM VALUES
17+
(10, "dept 1", "CA"),
18+
(20, "dept 2", "NY"),
19+
(30, "dept 3", "TX"),
20+
(40, "dept 4 - unassigned", "OR"),
21+
(50, "dept 5 - unassigned", "NJ"),
22+
(70, "dept 7", "FL")
23+
AS DEPT(dept_id, dept_name, state);
24+
25+
CREATE TEMPORARY VIEW BONUS AS SELECT * FROM VALUES
26+
("emp 1", 10.00D),
27+
("emp 1", 20.00D),
28+
("emp 2", 300.00D),
29+
("emp 2", 100.00D),
30+
("emp 3", 300.00D),
31+
("emp 4", 100.00D),
32+
("emp 5", 1000.00D),
33+
("emp 6 - no dept", 500.00D)
34+
AS BONUS(emp_name, bonus_amt);
35+
36+
37+
-- Or used in conjunction with exists - ExistenceJoin
38+
-- TC.02.01
39+
SELECT emp.emp_name
40+
FROM emp
41+
WHERE EXISTS (SELECT dept.state
42+
FROM dept
43+
WHERE emp.dept_id = dept.dept_id)
44+
OR emp.id > 200;
45+
46+
-- all records from emp including the null dept_id
47+
-- TC.02.02
48+
SELECT *
49+
FROM emp
50+
WHERE EXISTS (SELECT dept.dept_name
51+
FROM dept
52+
WHERE emp.dept_id = dept.dept_id)
53+
OR emp.dept_id IS NULL;
54+
55+
-- EXISTS subquery in both LHS and RHS of OR.
56+
-- TC.02.03
57+
SELECT emp.emp_name
58+
FROM emp
59+
WHERE EXISTS (SELECT dept.state
60+
FROM dept
61+
WHERE emp.dept_id = dept.dept_id
62+
AND dept.dept_id = 20)
63+
OR EXISTS (SELECT dept.state
64+
FROM dept
65+
WHERE emp.dept_id = dept.dept_id
66+
AND dept.dept_id = 30);
67+
;
68+
69+
-- not exists and exists predicate within OR
70+
-- TC.02.04
71+
SELECT *
72+
FROM bonus
73+
WHERE ( NOT EXISTS (SELECT *
74+
FROM emp
75+
WHERE emp.emp_name = emp_name
76+
AND bonus_amt > emp.salary)
77+
OR EXISTS (SELECT *
78+
FROM emp
79+
WHERE emp.emp_name = emp_name
80+
OR bonus_amt < emp.salary) );
81+
82+
-- not exists and in predicate within AND
83+
-- TC.02.05
84+
SELECT * FROM bonus WHERE NOT EXISTS
85+
(
86+
SELECT *
87+
FROM emp
88+
WHERE emp.emp_name = emp_name
89+
AND bonus_amt > emp.salary)
90+
AND
91+
emp_name IN
92+
(
93+
SELECT emp_name
94+
FROM emp
95+
WHERE bonus_amt < emp.salary);
96+

0 commit comments

Comments
 (0)