SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Generating Test Data: Part 2 - Generating Sequential and Random Dates


Generating Test Data: Part 2 - Generating Sequential and Random Dates

Author
Message
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16438 Visits: 19554
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
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search