UNION Operation (Microsoft Access SQL)
Last modified: March 09, 2015
Applies to: Access 2013 | Office 2013
In this article
Syntax
Remarks
Example
Creates a union query, which combines the results of two or more independent queries or tables.
You can merge the results of two or more queries, tables, and SELECT statements, in any combination, in a single UNION operation. The following example merges an existing table named New Accounts and a SELECT statement:
TABLE [New Accounts] UNION ALL SELECT * FROM Customers WHERE OrderAmount > 1000;
By default, no duplicate records are returned when you use a UNION operation; however, you can include the ALL predicate to ensure that all records are returned. This also makes the query run faster.
All queries in a UNION operation must request the same number of fields; however, the fields do not have to be of the same size or data type.
Use aliases only in the first SELECT statement because they are ignored in any others. In the ORDER BY clause, refer to fields by what they are called in the first SELECT statement.
This example retrieves the names and cities of all suppliers and customers in Brazil.
This example calls the EnumFields procedure, which you can find in the SELECT statement example.
Sub UnionX()
Dim dbs As Database, rst As Recordset
' Modify this line to include the path to Northwind
' on your computer.
Set dbs = OpenDatabase("Northwind.mdb")
' Retrieve the names and cities of all suppliers
' and customers in Brazil.
Set rst = dbs.OpenRecordset("SELECT CompanyName," _
& " City FROM Suppliers" _
& " WHERE Country = 'Brazil' UNION" _
& " SELECT CompanyName, City FROM Customers" _
& " WHERE Country = 'Brazil';")
' Populate the Recordset.
rst.MoveLast
' Call EnumFields to print the contents of the
' Recordset. Pass the Recordset object and desired
' field width.
EnumFields rst, 12
dbs.Close
End Sub
Note