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


dense_rank


dense_rank

Author
Message
JohnNash
JohnNash
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 93
Team,

Using of Dense_rank() and row_number will leads to any performance issue? if yes can please suggest other alternative


John
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42139 Visits: 19829
The most accurate response I can give you is: It depends.
Both functions won't cause performance issues on their own, but could be used in an inefficient way and produce performance problems.
The question is, how are you trying to use them? are they part of a performance problem you're experiencing?
If it's for new development, just test and test again.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
ChrisM@home
ChrisM@home
SSCertifiable
SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)

Group: General Forum Members
Points: 5234 Visits: 10607
Both functions will result in a sort unless a) the data coming into the operator is sorted same as the order by of the function and b) the query processor can determine that this is the case. As Luis said "it depends". Run your queries and check the plans.


Low-hanging fruit picker and defender of the moggies





For better assistance in answering your questions, please read this.




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
Alan.B
Alan.B
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13452 Visits: 8002
Dwain Camps wrote this great article about this recently which was consistent with my experience using windows functions: The Performance of the T-SQL Window Functions. I suggest giving it a read.

RANK(), DENSE_RANK(), ROW_NUMBER() and NTILE() are examples of Ranking Functions. They seem to perform pretty well.

ROW_NUMBER() is extra special because, when used without any sorting, it is wicked fast. It's not common to use RANK() or DENSE_RANK() without a specific order (why would you) but a it's common to use ROW_NUMBER without any ORDER by for situations where you need a surrogate key or just need a sequence of numbers for any reason without any gaps.

Below is a quick test I put together to demonstrate how ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) is faster than identity for this type of task. ROW_NUMBER() with no sorting will outperform a loop, cursor, or any other iterative method for counting in T-SQL.


-- temp tables for testing
IF OBJECT_ID('tempdb..#sampledata') IS NOT NULL DROP TABLE #sampledata;
IF OBJECT_ID('tempdb..#targetTable1') IS NOT NULL DROP TABLE #targetTable1;
IF OBJECT_ID('tempdb..#targetTable2') IS NOT NULL DROP TABLE #targetTable2;
CREATE TABLE #sampledata(value varchar(36) not null);
CREATE TABLE #targetTable1(s_id int identity, value varchar(36)); --with identity
CREATE TABLE #targetTable2(s_id int, value varchar(36)); --using row_number()

-- get random sample data
INSERT #sampledata(value)
SELECT TOP(1000000) newid()
FROM sys.all_columns a
CROSS JOIN sys.all_columns b;

-- the performance test
SET NOCOUNT ON;

DBCC DROPCLEANBUFFERS WITH NO_INFOMSGS
DBCC FREEPROCCACHE WITH NO_INFOMSGS

PRINT 'using identity:'
SET STATISTICS TIME ON;
INSERT #targetTable1(value)
SELECT value FROM #sampledata;
SET STATISTICS TIME OFF;

DBCC DROPCLEANBUFFERS WITH NO_INFOMSGS
DBCC FREEPROCCACHE WITH NO_INFOMSGS

PRINT CHAR(13)+CHAR(13)
PRINT 'using ROW_NUMBER() OVER (ORDER BY (SELECT NULL))'
SET STATISTICS TIME ON;
INSERT #targetTable2(s_id,value)
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)), value
FROM #sampledata
SET STATISTICS TIME OFF;
GO



Any thoughts, comments, questions are welcome.


Edit: Typos

-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
JohnNash
JohnNash
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 93
Thanks for your quick replies, nice article shared by Alan.B, yes obsolutely it depends, now we are developing a new database just wanted to check going forward (if data increases) will be a performance problem. Thanks for your views.

Regards
John
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17909 Visits: 6431
I think I said in the article that ROW_NUMBER() and the other ranking functions are all good performing options over trying to code the same thing yourself a different way.

I do want to emphasize that what Luis and Chris said are equally important considerations. Indexing on the table may impact the performance you get out of ROW_NUMBER (improving it assuming your PARTITION/ORDER BY condition matches the CLUSTERED INDEX).

And like anything that is good, they could be misused to make them very, very bad.

Edit: Oh yes and Alan, thanks for the plug.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
GilaMonster
GilaMonster
SSC Guru
SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)

Group: General Forum Members
Points: 225667 Visits: 46321
JohnNash (2/12/2014)
just wanted to check going forward (if data increases) will be a performance problem.


Honestly, there's no way to answer that question. Depends on too many factors.

Write the code, test on representative data volumes, if performance is inadequate adjust the code.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


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