Here’s a quick tip I know some of us has overlooked at some point. When doing SELECT … UNION SELECT, where do you put the the INTO OUTFILE clause? On the first SELECT, on the last or somewhere else? The manual has the answer here, to quote:
Only the last
SELECT
statement can useINTO OUTFILE
. (However, the entireUNION
result is written to the file.)
However, I still see queries going further lengths to the same effect. For example, putting the UNIONs into a subquery and then doing the SELECT INTO OUFILE from this. Using the employees.employees table:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 |
mysql [localhost] {msandbox} (employees) > EXPLAIN SELECT * INTO OUTFILE '/home/viiin/sandboxes/msb_5_1_58p/outfile.txt' -> FROM ( -> SELECT * FROM employees -> WHERE hire_date BETWEEN '1990-01-01' AND '1990-01-02' -> UNION ALL -> SELECT * FROM employees -> WHERE hire_date BETWEEN '1990-01-05' AND '1990-01-06' -> UNION ALL -> SELECT * FROM employees -> WHERE hire_date BETWEEN '1990-01-03' AND '1990-01-04' -> ) t; +----+--------------+--------------+-------+---------------+-----------+---------+------+------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+--------------+--------------+-------+---------------+-----------+---------+------+------+-------------+ | 1 | PRIMARY | <derived2> | ALL | NULL | NULL | NULL | NULL | 421 | | | 2 | DERIVED | employees | range | hire_date | hire_date | 3 | NULL | 119 | Using where | | 3 | UNION | employees | range | hire_date | hire_date | 3 | NULL | 123 | Using where | | 4 | UNION | employees | range | hire_date | hire_date | 3 | NULL | 179 | Using where | | NULL | UNION RESULT | | ALL | NULL | NULL | NULL | NULL | NULL | | +----+--------------+--------------+-------+---------------+-----------+---------+------+------+-------------+ 5 rows in set (0.00 sec) |
Compared to using UNION simply:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 |
mysql [localhost] {msandbox} (employees) > EXPLAIN SELECT * -> FROM employees -> WHERE hire_date BETWEEN '1990-01-01' AND '1990-01-02' -> UNION ALL -> SELECT * -> FROM employees -> WHERE hire_date BETWEEN '1990-01-05' AND '1990-01-06' -> UNION ALL -> SELECT * INTO OUTFILE '/home/viiin/sandboxes/msb_5_1_58p/outfile.txt' -> FROM employees -> WHERE hire_date BETWEEN '1990-01-03' AND '1990-01-04'; +----+--------------+--------------+-------+---------------+-----------+---------+------+------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+--------------+--------------+-------+---------------+-----------+---------+------+------+-------------+ | 1 | PRIMARY | employees | range | hire_date | hire_date | 3 | NULL | 119 | Using where | | 2 | UNION | employees | range | hire_date | hire_date | 3 | NULL | 123 | Using where | | 3 | UNION | employees | range | hire_date | hire_date | 3 | NULL | 179 | Using where | | NULL | UNION RESULT | | ALL | NULL | NULL | NULL | NULL | NULL | | +----+--------------+--------------+-------+---------------+-----------+---------+------+------+-------------+ 4 rows in set (0.00 sec) |
You will notice the second query without the additional derived <derived2>
table holding all the results from the UNION queries, making the latter more performant than the former. Of course you can stil break all this UNION queries down and SELECT them INTO OUTFILE separately, then concatenate the resulting files offline if you think the number of resulting rows would be to big to bear, otherwise SELECT .. UNION SELECT INTO OUTFILE should be convenient.
Lastly to demonstrate the purpose of this post.
1 2 3 4 5 6 7 8 9 10 11 12 |
mysql [localhost] {msandbox} (employees) > SELECT * -> FROM employees -> WHERE hire_date BETWEEN '1990-01-01' AND '1990-01-02' -> UNION ALL -> SELECT * -> FROM employees -> WHERE hire_date BETWEEN '1990-01-05' AND '1990-01-06' -> UNION ALL -> SELECT * INTO OUTFILE '/home/viiin/sandboxes/msb_5_1_58p/outfile.txt' -> FROM employees -> WHERE hire_date BETWEEN '1990-01-03' AND '1990-01-04'; Query OK, 421 rows affected (0.00 sec) |
Awewsome! Thank you Jervin.