SQL SERVER – UNION ALL and ORDER BY – How to Order Table Separately While Using UNION ALL

I often see developers trying following syntax while using ORDER BY.

SELECT Columns
FROM TABLE1
ORDER BY Columns
UNION ALL
SELECT Columns
FROM TABLE2
ORDER BY Columns

However the above query will return following error.

Msg 156, Level 15, State 1, Line 5
Incorrect syntax near the keyword ‘ORDER’.

It is not possible to use two different ORDER BY in the UNION statement. UNION returns single resultsetand as per the Logical Query Processing Phases.

However, if your requirement is such that you want your top and bottom query of the UNION resultset independently sorted but in the same resultset you can add an additional static column and order by that column. Let us re-create the same scenario.

First create two tables and populated with sample data.

USE tempdb
GO
-- Create table
CREATE TABLE t1 (ID INT, Col1 VARCHAR(100));
CREATE TABLE t2 (ID INT, Col1 VARCHAR(100));
GO
-- Sample Data Build
INSERT INTO t1 (ID, Col1)
SELECT 1, 'Col1-t1'
UNION ALL
SELECT 2, 'Col2-t1'
UNION ALL
SELECT 3, 'Col3-t1';
INSERT INTO t2 (ID, Col1)
SELECT 3, 'Col1-t2'
UNION ALL
SELECT 2, 'Col2-t2'
UNION ALL
SELECT 1, 'Col3-t2';
GO

If we SELECT the data from both the table using UNION ALL .

-- SELECT without ORDER BY
SELECT ID, Col1
FROM t1
UNION ALL
SELECT ID, Col1
FROM t2
GO

We will get the data in following order.

However, our requirement is to get data in following order.

If we need data ordered by Column1 we can ORDER the resultset ordered by Column1.

-- SELECT with ORDER BY
SELECT ID, Col1
FROM t1
UNION ALL
SELECT ID, Col1
FROM t2
ORDER BY ID
GO

Now to get the data in independently sorted in UNION ALL let us add additional column OrderKey and use ORDER BY  on that column. I think the description does not do proper justice let us see the example here.

-- SELECT with ORDER BY - with ORDER KEY
SELECT ID, Col1, 'id1' OrderKey
FROM t1
UNION ALL
SELECT ID, Col1, 'id2' OrderKey
FROM t2
ORDER BY OrderKey, ID
GO

The above query will give the desired result.

Now do not forget to clean up the database by running the following script.

-- Clean up
DROP TABLE t1;
DROP TABLE t2;
GO

Here is the complete script used in this example.

USE tempdb
GO
-- Create table
CREATE TABLE t1 (ID INT, Col1 VARCHAR(100));
CREATE TABLE t2 (ID INT, Col1 VARCHAR(100));
GO
-- Sample Data Build
INSERT INTO t1 (ID, Col1)
SELECT 1, 'Col1-t1'
UNION ALL
SELECT 2, 'Col2-t1'
UNION ALL
SELECT 3, 'Col3-t1';
INSERT INTO t2 (ID, Col1)
SELECT 3, 'Col1-t2'
UNION ALL
SELECT 2, 'Col2-t2'
UNION ALL
SELECT 1, 'Col3-t2';
GO
-- SELECT without ORDER BY
SELECT ID, Col1
FROM t1
UNION ALL
SELECT ID, Col1
FROM t2
GO
-- SELECT with ORDER BY
SELECT ID, Col1
FROM t1
UNION ALL
SELECT ID, Col1
FROM t2
ORDER BY ID
GO
-- SELECT with ORDER BY - with ORDER KEY
SELECT ID, Col1, 'id1' OrderKey
FROM t1
UNION ALL
SELECT ID, Col1, 'id2' OrderKey
FROM t2
ORDER BY OrderKey, ID
GO
-- Clean up
DROP TABLE t1;
DROP TABLE t2;
GO

I am sure there are many more ways to achieve this, what method would you use if you have to face the similar situation?

Click to Download Scripts

Reference: Pinal Dave (http://blog.sqlauthority.com)

 

About these ads

21 thoughts on “SQL SERVER – UNION ALL and ORDER BY – How to Order Table Separately While Using UNION ALL

  1. It seems like the title is wrong, you are not ordering the tables separately (which to me implies that a different order by clause is used for different tables), you are just “clustering” the rows from the same table together.

  2. If you want different order for both query then you can do it like this,

    select * from (SELECT top 100 percent ID, Col1 FROM t1 order by id) a
    UNION all
    select * from (SELECT top 100 percent ID, Col1 FROM t2 order by id desc) b

    ID Col1
    1 Col1-t1
    2 Col2-t1
    3 Col3-t1
    3 Col1-t2
    2 Col2-t2
    1 Col3-t2

  3. In this case, I would use CTE

    because in this last SQL Statement, it’s giving one additional column as an output. If you want to keep the same output, use CTE instead.

    Thanks,

  4. select * from
    (SELECT id,col1 FROM
    (SELECT ID, Col1 FROM t1
    order by ID) t11

    UNION ALL

    SELECT id,col1 FROM
    (SELECT ID, Col1 FROM t2
    order by Col1) t22)final
    order by id

    if seperate ordering of each sql is required plus overall.If overall is not required then remove final.

  5. Pingback: SQL SERVER – UNION ALL and UNION are Different Operation | SQL Server Journey with SQL Authority

  6. Hi Pinal,
    I have one query as follows :
    I have tables as Source (few columns A B C D ) ,Intermediate (one column identity ) and
    destination (few columns B C D with inserted identity from Intermediate )

    Now I want to insert records in Intermediate table with querying against A B C D column with few other collumns from different tables .
    then get that identity and insert into Destitnation table with col B C D and other few columns and identity which is from Intermediate table.

    I am doing it into SSIS package with merge statement like :
    MERGE
    INTO Intermediate table
    USING (select A, B, C, D ,Col1,Col2 FROM Source Inner join with table 1 ) T
    ON 1= 0
    WHEN NOT matched then
    INSERT DEFAULT VALUES
    Output inserted.Identity ,T.A,T.B,T.Col1,T.col2
    ;
    And this output I am using to do some tranformation and then inserting into other table.

    So could you tell tell me that is it good approach or any other process to do it ?
    I am having almost more than 5 milion records.

    Thanks in advance.
    waiting for your reply.

    Thanks,
    Amol

  7. alter procedure GetArticuloXCBarrasEnCentroComercial @CBarras nvarchar(20)
    as
    Select * From
    (

    (select Articulo, NombreArticulo, CodigoBarrasArt, Cod_Familia , Cod_SubFamilia, ImagenArt
    from factunet.dbo.Articulo Where CodigoBarrasArt = @CBarras)

    union

    (select Articulo, NombreArticulo, CodigoBarrasArt, Cod_Familia , Cod_SubFamilia , ImagenArt
    from factumerida.dbo.Articulo Where CodigoBarrasArt = @CBarras)

    union

    (select Articulo COLLATE Modern_Spanish_CI_AS, NombreArticulo COLLATE Modern_Spanish_CI_AS, CodigoBarrasArt COLLATE Modern_Spanish_CI_AS, Cod_Familia COLLATE Modern_Spanish_CI_AS, Cod_SubFamilia COLLATE Modern_Spanish_CI_AS, ImagenArt COLLATE Modern_Spanish_CI_AS
    from factupol.dbo.Articulo Where CodigoBarrasArt = @CBarras)

    )
    AS T
    ORDER BY T.NombreArticulo DESC

  8. wouldn’t it be much easier to just create an additional column in the select statement and sort by that first?:
    SELECT a.Name, a.Address FROM
    (
    SELECT Name, Address, ’1′ as Sorter FROM Employees Where
    UNION
    SELECT Name, Address, ’2′ as Sorter FROM Customers Where
    ) AS a
    ORDER BY a.Sorter, a.Name

    This will allow you to sort your list by name, keeping customers and employees separated.

  9. its okey but i want out put something like this
    1 -from t1
    1-from t2
    2-from t1
    2-from t2
    3-from t1
    3-from t2

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s