Using an SQL SELECT statement from a non-existing table
SQL expert Rudy Limeback explains how to formulate a query using an SQL SELECT statement from a non-existing table.
I have a list of strings as follows (not in the table):
'aaaaa' 'bbbbb' 'ccccc'
In the table T1 I have a VARCHAR column x. The data under x are as follows:
'aaaaa' 'ccccc'
I want to formulate a query such that it will bring 'bbbbb' since 'bbbbb' is not in the table. At the same time I do not want the help of a second table to do the query. Please help!
Like it or not, the simplest way to solve this problem is with a table that will contain your list of strings to be tested against your table T1. The technique involves a LEFT OUTER JOIN, with an IS NULL test in the WHERE clause, to find those rows of the left table (your list of strings to be tested) that don't have a match in the right table (your table T1).
The wrinkle here is that you said you do not want the help of a second table, so the solution here is to achieve this without actually creating a table. We'll use an imaginary table.
There are two ways to do this. The first, which isn't actually Standard SQL, is to create the table "out of thin air" as it were.
SELECT dt.string FROM ( SELECT 'aaaaa' AS string UNION ALL SELECT 'bbbbb' UNION ALL SELECT 'ccccc' ) AS dt LEFT OUTER JOIN T1 ON T1.x = dt.string WHERE T1.x IS NULL
Here, "dt" is a table alias which stands for derived table, which is what we call a subquery used in the FROM clause.
In the subquery, we see several SELECT statements UNIONed together, but there is no FROM clause in them. Only some database systems support a SELECT statement which has no FROM clause (Microsoft SQL Server and MySQL do).
If your database system requires a FROM clause, then all you need to do is select the strings from any convenient table where it is easy to target a specific row. In Oracle, you have the built-in DUAL table which can be used, and probably was intended, for this purpose. It works in this context because it has only one row.
SELECT dt.string FROM ( SELECT 'aaaaa' AS string FROM dual UNION ALL SELECT 'bbbbb' FROM dual UNION ALL SELECT 'ccccc' FROM dual ) AS dt LEFT OUTER JOIN T1 ON T1.x = dt.string WHERE T1.x IS NULL
Note that it does not matter what columns the DUAL table actually has, because we are selecting a constant instead of a column from it. If you're not using Oracle but still need to use a FROM clause, you could instead use any table you wish, including the T1 table itself, provided that you retrieve only one row from it.
SELECT dt.string FROM ( SELECT 'aaaaa' AS string FROM T1 WHERE x = 'aaaaa' UNION ALL SELECT 'bbbbb' FROM T1 WHERE x = 'aaaaa' UNION ALL SELECT 'ccccc' FROM T1 WHERE x = 'aaaaa' ) AS dt LEFT OUTER JOIN T1 ON T1.x = dt.string WHERE T1.x IS NULL
Neat, eh?