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 ««1234»»»

Returning the Top X row for each group Expand / Collapse
Author
Message
Posted Monday, December 6, 2010 9:05 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Saturday, May 24, 2014 7:58 PM
Points: 219, Visits: 824
Dave,

I liked this article, thanks!

One more thing: this optimization relies on the assumptions that only a small percentage are winners. It might be interesting to research which query is faster if everyone is a winner, and what percentage of winners is the tipping point when both queries run for the same time.

What do you think?
Post #1030679
Posted Monday, December 6, 2010 9:13 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 11:43 AM
Points: 168, Visits: 119
Thanks, Dave!! My bad - I didn't read it carefully enough!
Post #1030683
Posted Monday, December 6, 2010 9:27 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, September 9, 2014 2:06 AM
Points: 1,768, Visits: 8,318
@Alex , Thanks glad you liked it.
The same thought had occurred to me but there complication would be that it would not entirely reproducible due to random data.

Maybe a follow up with published data is in order then after thats all proved decided and measured , i could break it all by adding another included column of dummy data :)

@rockvilleaustin , No worries






Clear Sky SQL
My Blog
Kent user group
Post #1030695
Posted Monday, December 6, 2010 2:00 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Wednesday, September 24, 2014 4:19 PM
Points: 436, Visits: 2,286
...what about a tie?

INSERT INTO #Runners SELECT  9,10,20




Cursors are useful if you don't know SQL
Post #1030829
Posted Monday, December 6, 2010 2:08 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, September 18, 2014 4:34 PM
Points: 188, Visits: 1,557
Thanks for the article Dave. It is a well explained example and easy to follow.

Cheers,


Nicole Bowman

Nothing is forever.
Post #1030833
Posted Monday, December 6, 2010 2:19 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 13, 2014 8:06 AM
Points: 36, Visits: 43
Thanks much for the info. I tried both versions on production data and found the row_number to be much faster, which took a second to run compared to 14 seconds to run using cross apply.

Account table has 121,000 records and call has 651,000 records. Due to account type clause there are only 8,000 acount and 98,000 call records affected. I wonder why the results are so different, acctid is primary key and index does exist on callactid.

14 seconds
select acctservareaid, acctid, acctname, acctstorenumber, callconfirmation, callaccttypeid, work_order
from account with (nolock)
cross apply (
select top 1 calltime, callconfirmation, callaccttypeid, callcokeagent + callpo work_order
from call with (nolock)
where callacctid = acctid
and callaccttypeid = 'c'
order by calltime desc) as call
where accttypeid = 'c'

1 second
with cteCall
as
(
select acctservareaid, acctid, acctname, acctstorenumber, calltime, callconfirmation, callaccttypeid, callcokeagent + callpo work_order
,row_number() over (partition by AcctID order by CallTime desc ) as RowN
from call with (nolock)
inner join account with (nolock) on callacctid = acctid
and callaccttypeid = 'c'
and accttypeid = 'c'
)
Select * from cteCall
where RowN <=1
order by AcctID, CallTime Desc
Post #1030841
Posted Monday, December 6, 2010 6:36 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 6:54 AM
Points: 35,267, Visits: 31,760
Idea Deadbeat (12/6/2010)
Not directly related to article - but - an alternative to spt_values:

create table #Number (number int);
with N4000 as (select 0 as Number union all select Number+1 from N4000 where Number <4000
)insert into #number select * from N4000 option (MAXRECURSION 4000);
create index ix_N on #Number (Number);


I know you're only building it once but I'd never use the hidden RBAR of a recursive CTE to build an on-the-fly Tally Table for no other reason than someone may copy the code to do something larger and really end up with a performance problem.

I'd also use a clustered index on the table with a FILLFACTOR = 100 just in case someone wants to use the code on a server where the default FILLFACTOR has been changed to something other than 0 (100).

Here's what I mean... the following code includes several different methods including the original recursive CTE. Yeah... I even threw in a WHILE loop because it's a big surprise for a lot of folks when compared to a recursive CTE: (Didn't include index builds because they're all the same)

--===== Drop Tables ===========================================================================
DROP TABLE #Number, #Number1, #Number2, #Tally, #Tally1;
SET NOCOUNT ON;
DBCC FREEPROCCACHE;
WAITFOR DELAY '00:00:05'; --Let the system "settle" for several seconds
GO
--===== Recursive CTE w/Predefined Table (original)
create table #Number (number int);
with N4000 as (select 1 as Number union all select Number+1 from N4000 where Number <4000
)insert into #number select * from N4000 option (MAXRECURSION 4000);
GO
--===== Recursive CTE w/SELECT/INTO
with N4000 as (select ISNULL(1,0) as Number union all select Number+1 from N4000 where Number <4000
)select * INTO #Number1 from N4000 option (MAXRECURSION 4000);
GO
--===== WHILE Loop
CREATE TABLE #Number2 (Number INT NOT NULL);
DECLARE @Counter INT;
SELECT @Counter = 1;
BEGIN TRANSACTION;
WHILE @Counter <= 4000
BEGIN
INSERT INTO #Number2
(Number)
SELECT @Counter;
set @Counter = @Counter + 1;
END;
COMMIT;
GO
--===== Cross Join
SELECT TOP 4000
N = IDENTITY(INT,1,1)
INTO #Tally
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
;
GO
--===== Modified Itzek Method
WITH
E1(N) AS ( --=== Create Ten 1's
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 --10
),
E2(N) AS (SELECT 1 FROM E1 a, E1 b), --100
E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10,000
cteTally(N) AS (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT N)) FROM E4)
SELECT N = ISNULL(N,0)
INTO #Tally1
FROM cteTally
WHERE N <= 4000
;


And, here are the results from SQL Profiler. Even the WHILE loop beat the recursive CTE!



--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems


  Post Attachments 
Everything Beats Recursive CTEs.GIF (252 views, 9.28 KB)
Post #1030958
Posted Tuesday, December 7, 2010 2:35 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, September 9, 2014 2:06 AM
Points: 1,768, Visits: 8,318
swoveland21 (12/6/2010)
Account table has 121,000 records and call has 651,000 records. Due to account type clause there are only 8,000 acount and 98,000 call records affected. I wonder why the results are so different, acctid is primary key and index does exist on callactid.


Without seeing the plan its hard to say for definite , but as you require a large portion of the data (651K / 121 K = 20% roughly assuming that each account has 1 call ) , then the single scan through the call table is more efficient that the seeks to find the first call. In my example we were required to find a tiny portion on the data 1mill / 100 = 0.01% .





Clear Sky SQL
My Blog
Kent user group
Post #1031088
Posted Thursday, December 9, 2010 2:52 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, May 29, 2012 3:11 AM
Points: 1, Visits: 82
Ok , so how could you achieve this in SQL Server 2000? Again, just need the top x from each group ordered by the ID field.

Thanks
Post #1032344
Posted Thursday, December 9, 2010 5:33 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, September 9, 2014 2:06 AM
Points: 1,768, Visits: 8,318
Tim Widdup (12/9/2010)
Ok , so how could you achieve this in SQL Server 2000? Again, just need the top x from each group ordered by the ID field.

Thanks


You will have to loop or cursor through the data. A "quirky update" may be possible, cant remember if possible in 2000 , sorry.




Clear Sky SQL
My Blog
Kent user group
Post #1032385
« Prev Topic | Next Topic »

Add to briefcase ««1234»»»

Permissions Expand / Collapse