Using While Loop with UNION clause

  • Hi, Anyone can help?

    How can I show the output of this loop in one recordset?

    Another words, I want UNION the output in a single recordset. Please help. Thanks

    DECLARE @cn AS int

    set @cn = 0

    while @cn < 10

    begin

    select rank ()over (order by budperc desc) as rank, * from table1

    where id =@cn+1

    set @cn = @cn+1

    end

  • This returns a single recordset ... and might be what you are looking for

    took this example from BOL

    USE AdventureWorks;

    GO

    SELECT

    RANK() OVER(ORDER BY SalesYTD DESC) AS 'Rank'

    ,s.SalesYTD,s.salespersonid

    FROM Sales.SalesPerson s

    WHERE s.salespersonid < 280

    Notice there is no looping - hope this helps

    If everything seems to be going well, you have obviously overlooked something.

    Ron

    Please help us, help you -before posting a question please read[/url]
    Before posting a performance problem please read[/url]

  • With the info given, there's no need for a loop.

    SELECT RANK() OVER(PARTITION BY ID ORDER BY BudPerc DESC) AS Rank, *

    FROM Table1

    WHERE ID BETWEEN 1 AND 10

    The PARTITION BY will do the trick so far as restarting the RANK for each ID.

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

  • It works now. As you said the trick was in Partition BY clause to restart the ranking.. Awesome!! Thanx a lot..

  • You bet. Thanks a bunch for the feedback. 🙂

    --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 5 posts - 1 through 4 (of 4 total)

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