• 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)