Window function to expand row into multiple rows?

  • 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?

  • 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!

  • 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]);

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • 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. 🙂

  • 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


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply