-
Couldn't load subscription status.
- Fork 28.9k
[SPARK-18872][SQL][TESTS] New test cases for EXISTS subquery #16710
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Closed
Closed
Changes from all commits
Commits
Show all changes
2 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
123 changes: 123 additions & 0 deletions
123
sql/core/src/test/resources/sql-tests/inputs/subquery/exists-subquery/exists-basic.sql
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,123 @@ | ||
| -- Tests EXISTS subquery support. Tests basic form | ||
| -- of EXISTS subquery (both EXISTS and NOT EXISTS) | ||
|
|
||
| CREATE TEMPORARY VIEW EMP AS SELECT * FROM VALUES | ||
| (100, "emp 1", date "2005-01-01", 100.00D, 10), | ||
| (100, "emp 1", date "2005-01-01", 100.00D, 10), | ||
| (200, "emp 2", date "2003-01-01", 200.00D, 10), | ||
| (300, "emp 3", date "2002-01-01", 300.00D, 20), | ||
| (400, "emp 4", date "2005-01-01", 400.00D, 30), | ||
| (500, "emp 5", date "2001-01-01", 400.00D, NULL), | ||
| (600, "emp 6 - no dept", date "2001-01-01", 400.00D, 100), | ||
| (700, "emp 7", date "2010-01-01", 400.00D, 100), | ||
| (800, "emp 8", date "2016-01-01", 150.00D, 70) | ||
| AS EMP(id, emp_name, hiredate, salary, dept_id); | ||
|
|
||
| CREATE TEMPORARY VIEW DEPT AS SELECT * FROM VALUES | ||
| (10, "dept 1", "CA"), | ||
| (20, "dept 2", "NY"), | ||
| (30, "dept 3", "TX"), | ||
| (40, "dept 4 - unassigned", "OR"), | ||
| (50, "dept 5 - unassigned", "NJ"), | ||
| (70, "dept 7", "FL") | ||
| AS DEPT(dept_id, dept_name, state); | ||
|
|
||
| CREATE TEMPORARY VIEW BONUS AS SELECT * FROM VALUES | ||
| ("emp 1", 10.00D), | ||
| ("emp 1", 20.00D), | ||
| ("emp 2", 300.00D), | ||
| ("emp 2", 100.00D), | ||
| ("emp 3", 300.00D), | ||
| ("emp 4", 100.00D), | ||
| ("emp 5", 1000.00D), | ||
| ("emp 6 - no dept", 500.00D) | ||
| AS BONUS(emp_name, bonus_amt); | ||
|
|
||
| -- uncorrelated exist query | ||
| -- TC.01.01 | ||
| SELECT * | ||
| FROM emp | ||
| WHERE EXISTS (SELECT 1 | ||
| FROM dept | ||
| WHERE dept.dept_id > 10 | ||
| AND dept.dept_id < 30); | ||
|
|
||
| -- simple correlated predicate in exist subquery | ||
| -- TC.01.02 | ||
| SELECT * | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.dept_name | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id); | ||
|
|
||
| -- correlated outer isnull predicate | ||
| -- TC.01.03 | ||
| SELECT * | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.dept_name | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id | ||
| OR emp.dept_id IS NULL); | ||
|
|
||
| -- Simple correlation with a local predicate in outer query | ||
| -- TC.01.04 | ||
| SELECT * | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.dept_name | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id) | ||
| AND emp.id > 200; | ||
|
|
||
| -- Outer references (emp.id) should not be pruned from outer plan | ||
| -- TC.01.05 | ||
| SELECT emp.emp_name | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.state | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id) | ||
| AND emp.id > 200; | ||
|
|
||
| -- not exists with correlated predicate | ||
| -- TC.01.06 | ||
| SELECT * | ||
| FROM dept | ||
| WHERE NOT EXISTS (SELECT emp_name | ||
| FROM emp | ||
| WHERE emp.dept_id = dept.dept_id); | ||
|
|
||
| -- not exists with correlated predicate + local predicate | ||
| -- TC.01.07 | ||
| SELECT * | ||
| FROM dept | ||
| WHERE NOT EXISTS (SELECT emp_name | ||
| FROM emp | ||
| WHERE emp.dept_id = dept.dept_id | ||
| OR state = 'NJ'); | ||
|
|
||
| -- not exist both equal and greaterthan predicate | ||
| -- TC.01.08 | ||
| SELECT * | ||
| FROM bonus | ||
| WHERE NOT EXISTS (SELECT * | ||
| FROM emp | ||
| WHERE emp.emp_name = emp_name | ||
| AND bonus_amt > emp.salary); | ||
|
|
||
| -- select employees who have not received any bonus | ||
| -- TC 01.09 | ||
| SELECT emp.* | ||
| FROM emp | ||
| WHERE NOT EXISTS (SELECT NULL | ||
| FROM bonus | ||
| WHERE bonus.emp_name = emp.emp_name); | ||
|
|
||
| -- Nested exists | ||
| -- TC.01.10 | ||
| SELECT * | ||
| FROM bonus | ||
| WHERE EXISTS (SELECT emp_name | ||
| FROM emp | ||
| WHERE bonus.emp_name = emp.emp_name | ||
| AND EXISTS (SELECT state | ||
| FROM dept | ||
| WHERE dept.dept_id = emp.dept_id)); | ||
96 changes: 96 additions & 0 deletions
96
...ore/src/test/resources/sql-tests/inputs/subquery/exists-subquery/exists-within-and-or.sql
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,96 @@ | ||
| -- Tests EXISTS subquery support. Tests EXISTS | ||
| -- subquery within a AND or OR expression. | ||
|
|
||
| CREATE TEMPORARY VIEW EMP AS SELECT * FROM VALUES | ||
| (100, "emp 1", date "2005-01-01", 100.00D, 10), | ||
| (100, "emp 1", date "2005-01-01", 100.00D, 10), | ||
| (200, "emp 2", date "2003-01-01", 200.00D, 10), | ||
| (300, "emp 3", date "2002-01-01", 300.00D, 20), | ||
| (400, "emp 4", date "2005-01-01", 400.00D, 30), | ||
| (500, "emp 5", date "2001-01-01", 400.00D, NULL), | ||
| (600, "emp 6 - no dept", date "2001-01-01", 400.00D, 100), | ||
| (700, "emp 7", date "2010-01-01", 400.00D, 100), | ||
| (800, "emp 8", date "2016-01-01", 150.00D, 70) | ||
| AS EMP(id, emp_name, hiredate, salary, dept_id); | ||
|
|
||
| CREATE TEMPORARY VIEW DEPT AS SELECT * FROM VALUES | ||
| (10, "dept 1", "CA"), | ||
| (20, "dept 2", "NY"), | ||
| (30, "dept 3", "TX"), | ||
| (40, "dept 4 - unassigned", "OR"), | ||
| (50, "dept 5 - unassigned", "NJ"), | ||
| (70, "dept 7", "FL") | ||
| AS DEPT(dept_id, dept_name, state); | ||
|
|
||
| CREATE TEMPORARY VIEW BONUS AS SELECT * FROM VALUES | ||
| ("emp 1", 10.00D), | ||
| ("emp 1", 20.00D), | ||
| ("emp 2", 300.00D), | ||
| ("emp 2", 100.00D), | ||
| ("emp 3", 300.00D), | ||
| ("emp 4", 100.00D), | ||
| ("emp 5", 1000.00D), | ||
| ("emp 6 - no dept", 500.00D) | ||
| AS BONUS(emp_name, bonus_amt); | ||
|
|
||
|
|
||
| -- Or used in conjunction with exists - ExistenceJoin | ||
| -- TC.02.01 | ||
| SELECT emp.emp_name | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.state | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id) | ||
| OR emp.id > 200; | ||
|
|
||
| -- all records from emp including the null dept_id | ||
| -- TC.02.02 | ||
| SELECT * | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.dept_name | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id) | ||
| OR emp.dept_id IS NULL; | ||
|
|
||
| -- EXISTS subquery in both LHS and RHS of OR. | ||
| -- TC.02.03 | ||
| SELECT emp.emp_name | ||
| FROM emp | ||
| WHERE EXISTS (SELECT dept.state | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id | ||
| AND dept.dept_id = 20) | ||
| OR EXISTS (SELECT dept.state | ||
| FROM dept | ||
| WHERE emp.dept_id = dept.dept_id | ||
| AND dept.dept_id = 30); | ||
| ; | ||
|
|
||
| -- not exists and exists predicate within OR | ||
| -- TC.02.04 | ||
| SELECT * | ||
| FROM bonus | ||
| WHERE ( NOT EXISTS (SELECT * | ||
| FROM emp | ||
| WHERE emp.emp_name = emp_name | ||
| AND bonus_amt > emp.salary) | ||
| OR EXISTS (SELECT * | ||
| FROM emp | ||
| WHERE emp.emp_name = emp_name | ||
| OR bonus_amt < emp.salary) ); | ||
|
|
||
| -- not exists and in predicate within AND | ||
| -- TC.02.05 | ||
| SELECT * FROM bonus WHERE NOT EXISTS | ||
| ( | ||
| SELECT * | ||
| FROM emp | ||
| WHERE emp.emp_name = emp_name | ||
| AND bonus_amt > emp.salary) | ||
| AND | ||
| emp_name IN | ||
| ( | ||
| SELECT emp_name | ||
| FROM emp | ||
| WHERE bonus_amt < emp.salary); | ||
|
|
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Could you also add one more test case, which is very like
TC.01.08? This test case is used very often in the real world. BTW, you do not need to run DB2. We can know the results using our naked eyes. : )Uh oh!
There was an error while loading. Please reload this page.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@gatorsmile Thanks .. I have added the suggested test case and have updated the PR description.