Home > Articles

This chapter is from the book

This chapter is from the book

Performing Multiple-Table Retrievals with UNION

If you want to create a result set that combines the results from several queries, you can do so by using a UNION statement. For the examples in this section, assume that you have three tables, t1, t2, and t3 that look like this:

mysql> SELECT * FROM t1;
+------+-------+
| i    | c     |
+------+-------+
|    1 | red   |
|    2 | blue  |
|    3 | green |
+------+-------+
mysql> SELECT * FROM t2;
+------+------+
| i    | c    |
+------+------+
|  -1 | tan   |
|   1 | red   |
+------+------+
mysql> SELECT * FROM t3;
+------------+------+
| d          | i  |
+------------+------+
| 1904-01-01 | 100 |
| 2004-01-01 | 200 |
| 2004-01-01 | 200 |
+------------+------+

Tables t1 and t2 have integer and character columns, and t3 has date and integer columns. To write a UNION statement that combines multiple retrievals, just write several SELECT statements and put the keyword UNION between them. For example, to select the integer column from each table, do this:

mysql> SELECT i FROM t1 UNION SELECT i FROM t2 UNION SELECT i FROM t3;
+------+
| i    |
+------+
|    1 |
|    2 |
|    3 |
|   -1 |
|  100 |
|  200 |
+------+

UNION has the following properties:

  • The names for the columns of the UNION result come from the names of the columns in the first SELECT. The second and subsequent SELECT statements in the UNION must select the same number of columns, but corresponding columns need not have the same names or data types. (Normally, you write UNION such that corresponding columns do have the same types, but MySQL performs type conversion as necessary if they do not.) Columns are matched by position rather than by name, which is why the following two statements return different results, even though they select the same values from the two tables:

  • mysql> SELECT i, c FROM t1 UNION SELECT i, d FROM t3;
    +------+------------+
    | i    | c          |
    +------+------------+
    |  1   | red        |
    |  2   | blue       |
    |  3   | green      |
    | 100  | 1904-01-01 |
    | 200  | 2004-01-01 |
    +------+------------+
    mysql> SELECT i, c FROM t1 UNION SELECT d, i FROM t3;
    +------------+-------+
    | i          | c     |
    +------------+-------+
    | 1          | red   |
    | 2          | blue  |
    | 3          | green |
    | 1904-01-01 | 100   |
    | 2004-01-01 | 200   |
    +------------+-------+

    In each statement, the data type for each column of the result is determined from the selected values. In the first statement, strings and dates are selected for the second column. The result is a string column. In the second statement, integers and dates are selected for the first column, strings and integers for the second column. In both cases, the result is a string column.

    Note: Before MySQL 4.1.1, the data type for each column of the UNION result is based only on the type of the column in the first SELECT, and values from corresponding column of the following SELECT statements are converted to that type. Each of the preceding two statements will return an integer first column, which results in type conversion of the dates to integers.

  • By default, UNION eliminates duplicate rows from the result set:

  • mysql> SELECT * FROM t1 UNION SELECT * FROM t2 UNION SELECT * FROM t3;
    +------------+-------+
    | i          | c     |
    +------------+-------+
    | 1          | red   |
    | 2          | blue  |
    | 3          | green |
    | -1         | tan   |
    | 1904-01-01 | 100   |
    | 2004-01-01 | 200   |
    +------------+-------+

    t1 and t2 both have a row containing values of 1 and 'red', but only one such row appears in the output. Also, t3 has two rows containing '2004-01-01'and 200, one of which has been eliminated.

    UNION DISTINCT is synonymous with UNION; both retain only distinct rows.

    If you want to preserve duplicates, change each UNION to UNION ALL:

    mysql-> SELECT * FROM t1 UNION ALL SELECT * FROM t2 
         UNION ALL SELECT * FROM t3;
    +------------+-------+
    | i          | c     |
    +------------+-------+
    | 1          | red   |
    | 2          | blue  |
    | 3          | green |
    | -1         | tan   |
    | 1          | red   |
    | 1904-01-01 | 100   |
    | 2004-01-01 | 200   |
    | 2004-01-01 | 200   |
    +------------+-------+

    If you mix UNION or UNION DISTINCT with UNION ALL, any distinct union operation takes precedence over any UNION ALL operations to its left.

  • To sort a UNION result as a whole, place each SELECT within parentheses and add an ORDER BY clause following the final closing parenthesis. However, because the UNION uses column names from the first SELECT, the ORDER BY should refer to those names, not the column names from the last SELECT:

  • mysql> (SELECT i, c FROM t1) UNION (SELECT i, d FROM t3)
        -> ORDER BY c;
    +------+------------+
    | i    | c          |
    +------+------------+
    | 100  | 1904-01-01 |
    | 200  | 2004-01-01 |
    |  2   | blue       |
    |  3   | green      |
    |  1   | red        |
    +------+------------+

    To sort the result from an individual SELECT statement within a UNION, place the ORDER BY within the appropriate parenthesized SELECT:

    mysql> (SELECT i, c FROM t1 ORDER BY i DESC)
        -> UNION (SELECT i, c FROM t2 ORDER BY i);
    +------+-------+
    | i    | c     |
    +------+-------+
    |    3 | green |
    |    2 | blue  |
    |    1 | red   |
    |   -1 | tan   |
    +------+-------+
  • LIMIT can be used in a UNION in a manner similar to that for ORDER BY. If added to the end of the statement, it applies to the UNION result as a whole:

  • mysql> (SELECT * FROM t1) UNION (SELECT * FROM t2) UNION (SELECT * FROM t3)
        -> LIMIT 1;
    +------+------+
    | i    | c  |
    +------+------+
    | 1    | red |
    +------+------+

    If enclosed within parentheses as part of an individual SELECT statement, it applies only to that SELECT:

    mysql> (SELECT * FROM t1 LIMIT 1)
        -> UNION (SELECT * FROM t2 LIMIT 1)
        -> UNION (SELECT * FROM t3 LIMIT 1);
    +------------+------+
    | i          | c    |
    +------------+------+
    | 1          | red  |
    | -1         | tan  |
    | 1904-01-01 | 100  |
    +------------+------+
  • In a UNION statement, you need not select from different tables. You can select results from different subsets of the same table, using different conditions for each SELECT. This can be useful as an alternative to running several different SELECT queries, because you get all the rows in a single result set, rather than as several result sets.

You can "simulate" UNION by selecting rows from each table into a temporary table and then selecting the contents of that table. If you make the table a TEMPORARY table, it will be dropped automatically when your session with the server terminates. For quicker performance, use a MEMORY table:

CREATE TEMPORARY TABLE tmp ENGINE = MEMORY SELECT ... FROM t1 WHERE ... ;
INSERT INTO tmp SELECT ... FROM t2 WHERE ... ;
INSERT INTO tmp SELECT ... FROM t3 WHERE ... ;
...
SELECT * FROM tmp ORDER BY ... ;

If you want to run a UNION-type query on MyISAM tables that have the same structure, you can set up a MERGE table and query that. One reason this is useful is that it is simpler to write a query on a MERGE table than the corresponding UNION statement. A query on the MERGE table is similar to a UNION that selects corresponding columns from the individual tables that make up the MERGE table. That is, SELECT on a MERGE table is like UNION ALL (duplicates are not removed), and SELECT DISTINCT is like UNION or UNION DISTINCT (duplicates are removed).

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020