Using Ranking Functions to Deduplicate Data

  • Don't get me wrong. This is a good example of "how to use RANK() and ROW_NUMBER() functions". My problem is why would I do this instead of using DISTINCT?

    There is already an article on "Ranking Functions" here...

    [/url]

    Also, I know that DISTINCT is not the most efficient way to "de-duplicate" (nice phrase) over large datasets. Now if we are saying using Ranking Function approach is faster on larger data sets or largely skewed data sets, i.e. each row is already distinct, then I have learnt something. Else all I have learnt is (yet) one more way to write (potentially confusing) code. Using DISTINCT on the example cited in the article would be obvious. That's important where I come from.

    So, if someone can please educate me as to when and why I would use the Ranking function method to get distinct records I would very much appreciate it.

  • Say for example, if you have type 2 updates and you just wanted to know that which records are the latest in your table, you could do so by using Ranking functions (partitioned over time stamp obviously). If you would have done a distinct on the same table, there is no way to be sure if the record that your distinct query is picking up is indeed the latest one.

    A very practical example for using ranking functions is the Database Reconciliation process.

  • Anyone actually check this code?

    I believe the RANK statement in the CTE is incorrect (see corrected version below) if the intent is to remove duplicates for ItemNumber only. At the very least, to return the dataset the author provides in the article:

    777 10.10

    888 13.13

    999 16.16

    Of course, I have to agree with others on this, for this particular example, GROUP with MIN would achieve the same result much more easily.

    with GetMissingItems(Rank, RowNumber, ItemNumber, UnitCost) as (

    select

    --RANK() over (order by ItemNumber, UnitCost) as Rank

    RANK() over (order by ItemNumber) as Rank

    , ROW_NUMBER() over (order by ItemNumber, UnitCost) as RowNumber

    , ItemNumber

    , UnitCost

    from MissingItems

    )

    select

    ItemNumber

    , UnitCost

    from GetMissingItems

    where Rank = RowNumber

    select

    ItemNumber

    , min(UnitCost) 'UnitCost'

    from #MissingItems

    group by ItemNumber

  • In most of the cases you need to retain the latest record from the duplicates. In that case matching rank=rownumber will not work.

    So using ROW_NUMBER() partition and ORDER BY col DESC is always a good approach.

  • Very nice article. Thanks for sharing. My two cents are that I would use the dense_rank() function to return the rank in tandem order. The rank() function tends to skip a rank depending on how many members belong to a group.

    declare @AlphaList table (AlphaKey char);

    insert into @AlphaList(AlphaKey) values ('A');

    insert into @AlphaList(AlphaKey) values ('A');

    insert into @AlphaList(AlphaKey) values ('B');

    insert into @AlphaList(AlphaKey) values ('B');

    insert into @AlphaList(AlphaKey) values ('C');

    insert into @AlphaList(AlphaKey) values ('D');

    insert into @AlphaList(AlphaKey) values ('D');

    insert into @AlphaList(AlphaKey) values ('E');

    select

    RANK() over (order by AlphaKey) as Rank

    , dense_RANK() over (order by AlphaKey) as [Rank by density]

    , ROW_NUMBER() over (order by AlphaKey) as RowNumber

    , AlphaKey

    from @AlphaList;

    RankRank by densityRowNumberAlphaKey

    111A

    112A

    323B

    324B

    535C

    646D

    647D

    858E

  • I'm still getting ranking functions into my head slowly. 😀

    Nice article about a very useful way to use them.

    Best regards,

    Andre Guerreiro Neto

    Database Analyst
    http://www.softplan.com.br
    MCITPx1/MCTSx2/MCSE/MCSA

  • I'm disappointed. I've been doing this for a while with ROW_NUMBER and PARTION and it works gr8 in all the situations I've come across.

    I can't figure out what advantage I can gain using the RANK function.

    I'm not sure there is an advantage, but I'll be happy if someone corrects me 🙂

  • I'm torn... it's a nicely written article but the premise is at least twice as complicated as it needs to be and 2 times as slow as conventional methods, IMHO. Don't take my word for it, though... test it yourself...

    --===========================================================================

    -- Create a multi-million row test table. This is not a measured

    -- part of the test.

    --===========================================================================

    --===== Conditionally drop the test table to make reruns easier

    IF OBJECT_ID('TempDB..#AlphaList','U') IS NOT NULL

    DROP TABLE #AlphaList

    ;

    --===== Create and populate a multi-million row test table on the fly

    SELECT TOP 5000000

    AlphaListID = IDENTITY(INT,1,1),

    AlphaKey = CHAR(ABS(CHECKSUM(NEWID()))%26+65) --A thru Z randomly

    INTO #AlphaList

    FROM Master.sys.All_Columns t1

    CROSS JOIN Master.sys.All_Columns t2

    ;

    --===== Create the expected indexes

    ALTER TABLE #AlphaList

    ADD PRIMARY KEY CLUSTERED (AlphaListID)

    ;

    CREATE NONCLUSTERED INDEX IX_#AlphaList_AlphaKey

    ON #AlphaList (AlphaKey)

    ;

    --===========================================================================

    -- Test 3 different methods with CPU and Duration measurements.

    --===========================================================================

    --===== "Clear the guns"

    PRINT REPLICATE('=',80);

    PRINT '========== Traditional RowNumber Method ==========';

    DBCC FREEPROCCACHE;

    DBCC DROPCLEANBUFFERS;

    SET STATISTICS TIME ON;

    --===== Test the code

    select AlphaKey

    from (

    select row_number() over(partition by AlphaKey order by AlphaKey) rownum,

    AlphaKey

    from #AlphaList

    ) al

    where rownum = 1

    order by AlphaKey

    ;

    SET STATISTICS TIME OFF;

    --===== "Clear the guns"

    PRINT REPLICATE('=',80);

    PRINT '========== Simple Distinct ==========';

    DBCC FREEPROCCACHE;

    DBCC DROPCLEANBUFFERS;

    SET STATISTICS TIME ON;

    --===== Test the code

    SELECT DISTINCT AlphaKey

    FROM #AlphaList

    ORDER BY AlphaKey

    ;

    SET STATISTICS TIME OFF;

    --===== "Clear the guns"

    PRINT REPLICATE('=',80);

    PRINT '========== New Rank Method from Article ==========';

    DBCC FREEPROCCACHE;

    DBCC DROPCLEANBUFFERS;

    SET STATISTICS TIME ON;

    --===== Test the code

    with AlphaRank(Rank, RowNumber, AlphaKey) as (

    select

    RANK() over (order by AlphaKey) as Rank

    , ROW_NUMBER() over (order by AlphaKey) as RowNumber

    , AlphaKey

    from #AlphaList

    )

    select AlphaKey

    from AlphaRank

    where Rank=RowNumber

    ;

    SET STATISTICS TIME OFF;

    Here are the results on my 8 year old desktop single p4 CPU running at 1.8Ghz with 1GB of ram on SQL Server 2005 Developer's Edition sp3.

    (5000000 row(s) affected)

    ================================================================================

    ========== Traditional RowNumber Method ==========

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    (26 row(s) affected)

    SQL Server Execution Times:

    CPU time = 2875 ms, elapsed time = 3005 ms.

    ================================================================================

    ========== Simple Distinct ==========

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    (26 row(s) affected)

    SQL Server Execution Times:

    CPU time = 2985 ms, elapsed time = 3043 ms.

    ================================================================================

    ========== New Rank Method from Article ==========

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    (26 row(s) affected)

    SQL Server Execution Times:

    CPU time = 7953 ms, elapsed time = 8037 ms.

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Hi,

    I think we can achieve the same without rank function.

    SELECT * FROM GetMissingItems WHERE RowNumber = 1



    Praveen D'sa
    MCITP - Database Administrator 2008
    http://sqlerrors.wordpress.com

  • PravB4u (7/29/2010)


    Hi,

    I think we can achieve the same without rank function.

    SELECT * FROM GetMissingItems WHERE RowNumber = 1

    Ummm.... Not without the "Partition By" part of the OVER clause for ROW_NUMBER in what appears to be a missing CTE from your code.

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 10 posts - 16 through 24 (of 24 total)

You must be logged in to reply to this topic. Login to reply