• Erland Sommarskog (9/12/2013)


    Blimey? Must be some lingo local to Port Moresby.

    Any way, since I don't think that there was a post with CROSS JOIN for unpivotting, here is an example, taken from another thread. When looking at the query plans, the CROSS APPLY solution looks better, but I would need more data to test. I would like to point out, though, that the solution with CROSS JOIN has the distinct advantage of being fully portable across platforms. (Hm, not all engines may support the VALUES clause, but it's easliy replaced with SELECT UNION ALL.)

    Create Table #sample

    ( Name Varchar(100) PRIMARY KEY,

    Mark1 int,

    Mark2 int,

    Mark3 int)

    insert into #sample values ('Vignesh',100,59,95)

    insert into #sample values ('ram',23,45,33)

    insert into #sample values ('kumar',58,12,15)

    insert into #sample values ('umar',15,25,98)

    go

    SELECT s.Name, CASE n.n WHEN 1 THEN s.Mark1

    WHEN 2 THEN s.Mark2

    WHEN 3 THEN s.Mark3

    END AS Mark,

    CASE n.n WHEN 1 THEN 'Mark1'

    WHEN 2 THEN 'Mark2'

    WHEN 3 THEN 'Mark3'

    END AS MarkName

    FROM #sample s

    CROSS JOIN (VALUES (1), (2), (3)) AS n(n)

    ORDER BY s.Name, n.n

    go

    SELECT s.Name, M.Mark, M.name

    FROM #sample s

    CROSS APPLY (VALUES (1, s.Mark1, 'Mark1'), (2, s.Mark2, 'Mark2'), (3, s.Mark1, 'Mark3')) AS M(n, Mark, name)

    ORDER BY s.Name, M.n

    go

    DROP TABLE #sample

    Note that here I have added a column n to the CROSS APPLY table to make that query fully equivalent to the CROSS JOIN solution, but in the APPLY solution you don't need n if you don't care about order, whereas it's a driving column in the CROSS JOIN solution.

    As for UNPIVOT - I have never been able to learn it, the same with PIVOT.

    Thanks for posting this - it's interesting to see both together. I'll have a closer look (in a couple of weeks, after vacation).

    I've not been able to learn PIVOT and UNPIVOT either - a swift look at BOL is always necessary. Since they both look like quick-and-dirty implementations, I'll wait until MS rewrites them properly.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden