• boriskey (12/16/2012)


    Jeff, thanks for the great articles (part 1 and part 2 and look forward to part3).

    Is there a way to pick a random value (like a color) from a subquery? here is what I tried but getting the same value on every run:

    SELECT TOP (100)

    ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as ID,--Sequential number from 1 to ..

    (SELECT top 1 color FROM ( VALUES (0,'Red'),(1,'Green'),(2,'Yellow') ) colors(id,color) ORDER BY NEWID()) as RandomColor,

    FROM sys.all_columns ac1

    CROSS JOIN sys.all_columns ac2

    but if I run this piece alone, I am getting different colors:

    SELECT top 1 color FROM ( VALUES (0,'Red'),(1,'Green'),(2,'Yellow') ) colors(id,color) ORDER BY NEWID()

    You have to make two changes to your subquery to make this work:

    1. Correlate it to the outer query, or it will run once per query rather than once per row

    2. Make it do something early on, or it will still get "optimized leftwards" (what the hell am I talking about? Is there a proper term for this?)

    What you are looking for in the constant scan operator at the rightmost end of the subquery branch is 'Number of Executions = 1000' and 'Actual number of Rows' = 3000.

    Something like this:

    SELECT TOP 1000 ID = ROW_NUMBER() OVER (ORDER BY (SELECT NULL)),

    x.*

    FROM sys.all_columns ac1

    OUTER APPLY (

    SELECT TOP 1

    RandomColor = color,

    IDi = ac1.object_id + ac1.column_id + ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

    FROM (VALUES (0,'Red'),(1,'Green'),(2,'Yellow')) colors (id,color)

    ORDER BY NEWID()

    ) x

    If you remove IDi from the outer SELECT, the whole optimiser spoof collapses ๐Ÿ˜‰

    โ€œ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