February 12, 2016 at 9:32 am
I have a requirement to expand a row in an Orders table into two rows based on columns of EnteredBy and PerformedBy.
For example:
CREATE TABLE dbo.Orders
(
[OrderId] INT IDENTITY(1,1) PRIMARY KEY NOT NULL
,[OrderDate] DATETIME2(2) NOT NULL
,[CustomerName] VARCHAR(50) NOT NULL
,[SalesAmount] DECIMAL(9,2) NOT NULL
,[EnteredBy] VARCHAR(25) NOT NULL
,[PerformedBy] VARCHAR(25) NOT NULL
)
One way to expand this is to stack the results using UNION ALL.
SELECT
[OrderId] AS [OrderNumber]
,[EnteredBy] AS [User]
FROM dbo.Orders
UNION ALL
SELECT
[OrderId] AS [OrderNumber]
,[PerformedBy] AS [User]
FROM dbo.Orders
Unfortunately this reads the base table twice, so I'm wondering if there isn't a clever way to do this in a single read pass using a window function?
February 12, 2016 at 9:39 am
No need to use window functions. A simple CROSS APPLY will do the trick.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders CROSS APPLY (SELECT [User]=EnteredBy
UNION ALL
SELECT [User]=PerformedBy
) x([User])
Cheers!
February 12, 2016 at 10:00 am
Jacob Wilkins (2/12/2016)
No need to use window functions. A simple CROSS APPLY will do the trick.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders CROSS APPLY (SELECT [User]=EnteredBy
UNION ALL
SELECT [User]=PerformedBy
) x([User])
Cheers!
Or the short version available since 2008.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders
CROSS APPLY (VALUES( EnteredBy),
(PerformedBy)) x([User]);
February 12, 2016 at 10:04 am
Luis Cazares (2/12/2016)
Jacob Wilkins (2/12/2016)
No need to use window functions. A simple CROSS APPLY will do the trick.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders CROSS APPLY (SELECT [User]=EnteredBy
UNION ALL
SELECT [User]=PerformedBy
) x([User])
Cheers!
Or the short version available since 2008.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders
CROSS APPLY (VALUES( EnteredBy),
(PerformedBy)) x([User]);
Heh, good point. Went on autopilot using the old stuff; one day I won't have to worry about 2005...one day. 🙂
February 12, 2016 at 6:13 pm
Jacob Wilkins (2/12/2016)
Luis Cazares (2/12/2016)
Jacob Wilkins (2/12/2016)
No need to use window functions. A simple CROSS APPLY will do the trick.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders CROSS APPLY (SELECT [User]=EnteredBy
UNION ALL
SELECT [User]=PerformedBy
) x([User])
Cheers!
Or the short version available since 2008.
SELECT [OrderNumber]=OrderID,
[User]=x.[User]
FROM dbo.Orders
CROSS APPLY (VALUES( EnteredBy),
(PerformedBy)) x([User]);
Heh, good point. Went on autopilot using the old stuff; one day I won't have to worry about 2005...one day. 🙂
I know it's just me but I like the "old stuff". It's just as fast as the new stuff, as well. Guess it's a matter of what you cut your teeth on.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply