Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

get set of random rows with distinct values Expand / Collapse
Author
Message
Posted Monday, June 17, 2013 4:58 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, October 13, 2014 2:20 AM
Points: 3, Visits: 15
I have an interesting little T-SQL problem that has me beaten.

I want to retrieve a small set of randomly selected rows from a table but also ensure that a particular column (AUTHORID) is unique (not duplicated) within that set.

SELECT TOP 6 WORKID, AUTHORID FROM dbo.LITERARYWORKS
ORDER BY CHECKSUM(NEWID())

works fine at getting a random selection, but of course does not prevent duplicates on AUTHORID. And I can't use DISTINCT without including WORKID and AUTHORID in the ORDER BY - and in any case the rows would always be unique if WORKID is included. I believe one way of achieving the effect of a 'DISTINCT' on a single column while returning other columns as well is by using GROUP BY, but I can't see how to use that in combination with ORDER BY.

Any ideas?

Jon
Post #1464080
Posted Monday, June 17, 2013 5:39 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 10:17 AM
Points: 12,927, Visits: 32,327
by introducing a row_number function that partitions by the two columns, you cna find unique rows; fromt here, it's just the same query you had before, but hitting a subquery isntead of the raw table:
SELECT
TOP 6
WORKID,
AUTHORID
FROM (SELECT
ROW_NUMBER() OVER(PARTITION BY WORKID, AUTHORID ORDER BY WORKID, AUTHORID) AS RW,
WORKID,
AUTHORID
FROM dbo.LITERARYWORKS) MyAlias
WHERE RW = 1--finds Uniqueness across WORKID, AUTHORID
ORDER BY
CHECKSUM(NEWID())



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1464095
Posted Monday, June 17, 2013 5:54 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, October 13, 2014 2:20 AM
Points: 3, Visits: 15
Works a treat - many thanks!

Post #1464099
Posted Monday, June 17, 2013 6:31 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:43 AM
Points: 6,869, Visits: 14,178
A randomly-selected work from a number of randomly-selected authors:
SELECT 
WORKID,
AUTHORID
FROM (
SELECT TOP 10
AUTHORID
FROM dbo.LITERARYWORKS
GROUP BY MASTNUM
ORDER BY NEWID()
) at
CROSS APPLY (
SELECT TOP 1
WORKID
FROM dbo.LITERARYWORKS
WHERE AUTHORID = at.AUTHORID
ORDER BY NEWID()
) MyAlias



“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
Post #1464112
Posted Tuesday, June 18, 2013 1:21 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, October 13, 2014 2:20 AM
Points: 3, Visits: 15
Many thanks. I actually prefer this for my purposes as it will always return the required number of items (provided that there is at least that number of authors with at least 1 work each) whereas the other approach above is arguably more random but can return less than the required number of items if more than 1 work for the same author is initially selected.
Post #1464479
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse