Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

order by inside union (selects) Expand / Collapse
Author
Message
Posted Friday, October 10, 2003 4:48 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, June 23, 2008 4:40 PM
Points: 18, Visits: 2
I have a series of select statements that are unioned togther. 1 of them I would like to be able to sort in addition to the sorting of the whole final table. I get a syntax error that prevent me from doing this. Can anyone provide some insight or mods to the example code? thx

--------------
select a,b,c
from d
where x = 1
union
(select a,b,c
from d
where x = 2
order by b)
order by c

So in this example, the second select statement would be ordered by b, then the whole results would be ordered by c.

But alas - syntax error prevents this.
thx for any comments.







Post #17183
Posted Friday, October 10, 2003 5:08 PM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Thursday, February 03, 2005 3:17 PM
Points: 504, Visits: 1
You might be able to get around this if you use TOP 100 PERCENT on your subquery that you want to order by.

 
use pubs
go

SELECT title, 'titles' WHEREFROM FROM titles
UNION
SELECT title, 'author' WHEREFROM FROM (SELECT TOP 5 au_fname title FROM authors ORDER BY au_fname DESC) A
ORDER BY title


Gary Johnson
Microsoft Natural Language Group
DBA, Sr. DB Engineer





Gary Johnson
Microsoft Natural Language Group
DBA, Sr. DB Engineer

This posting is provided "AS IS" with no warranties, and confers no rights. The opinions expressed in this post are my own and may not reflect that of my employer.
Post #82970
Posted Friday, October 10, 2003 5:59 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Wednesday, September 23, 2009 9:40 AM
Points: 940, Visits: 54
The result set from a UNION is not guaranteed to be in any order, so, even if you could order the selects that are unioned, the order of the results would not be meaningful. That's why your statement produces an error. Perhaps something like this will work:

SELECT a,b,c
FROM (
SELECT a, b, c, 1 s
FROM d
WHERE x = 1
UNION
SELECT a, b, c, 2
FROM d
WHERE x = 2) a
ORDER BY c, s, b


--Jonathan




--Jonathan
Post #82971
Posted Sunday, October 12, 2003 10:42 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Friday, February 11, 2005 5:29 AM
Points: 28, Visits: 1
Try out this.
Select '2' 'orderfield', field1, Field2 from table1
union
Select '1' 'orderfield', field3, Field4 from table2
order by orderfield, <field> you want to order by

You could think of re-writing your query on these lines by introducing dummy order by fields that would contain constants. It is not possible to order sub result sets in a Union.





Post #82972
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse