Better logic than cursor

  • Hi All,

    I have two tables Tab1 and Tab2.For each row in Tab1, the table Tab2 contains multiple rows.Important columns in both tables are C0,C1 and C2. So i have to update the C1 and C2 columns in Tab1 with count(C1) and max(C2) for each C0.

    assume C0="Temp" and Tab2 has 10 rows for Temp.So Tab1 should be updated with C1 as 10 and C2 asmax(C2) in Tab2.

    so i wrote a cursor as below.It takes 1 min for two rows in Tab1.Any better solution ?

    declare T1_cursor CURSOR for

    select distinct C0 from Tab1

    OPEN T1_cursor

    FETCH NEXT FROM T1_cursor

    INTO @C0

    WHILE @@FETCH_STATUS = 0

    BEGIN

    select @recordCount=count(*)+1,@maxTime=max(maxtime) from Tab2

    where C0=@C0

    update T1 set RecordCount=@recordCount , Maxtime=@maxTime where C0=@C0

    FETCH NEXT FROM T1_cursor

    INTO @C0

    END -- End of cursor

    CLOSE T1_cursor

    DEALLOCATE T1_cursor

  • Actually, yes. Don't use a cursor. Oh, wait, you would like some actual code here wouldn't you?

    Okay, we can that once you post the DDL (CREATE TABLE statements) for the tables, some sample data (as INSERT INTO statements) for each of the tables, the expected results based on the sample data provided (usually best provided as another table and series of insert statements to make testing/comparisons easier).

    Need help with this, read the first article I have referenced below in my signature block. It will help you with everything you need to do to get the best possible answers quickly.

  • Compassionate (3/2/2013)


    Hi All,

    I have two tables Tab1 and Tab2.For each row in Tab1, the table Tab2 contains multiple rows.Important columns in both tables are C0,C1 and C2. So i have to update the C1 and C2 columns in Tab1 with count(C1) and max(C2) for each C0.

    assume C0="Temp" and Tab2 has 10 rows for Temp.So Tab1 should be updated with C1 as 10 and C2 asmax(C2) in Tab2.

    so i wrote a cursor as below.It takes 1 min for two rows in Tab1.Any better solution ?

    declare T1_cursor CURSOR for

    select distinct C0 from Tab1

    OPEN T1_cursor

    FETCH NEXT FROM T1_cursor

    INTO @C0

    WHILE @@FETCH_STATUS = 0

    BEGIN

    select @recordCount=count(*)+1,@maxTime=max(maxtime) from Tab2

    where C0=@C0

    update T1 set RecordCount=@recordCount , Maxtime=@maxTime where C0=@C0

    FETCH NEXT FROM T1_cursor

    INTO @C0

    END -- End of cursor

    CLOSE T1_cursor

    DEALLOCATE T1_cursor

    I'm really concerned for your system because even a cursor isn't normally as slow as that. There's something really funky going on if it's only doing 2 rows a minute. Perhaps it's just some really big tables that have no indexes. If that's true, even the following set based code may be slower than desired.

    And, no... haven't tested it because you didn't post any readily consumable data to test with. Follow the link Lynn pointed to. You'll get much quicker responses and even tested coded answers if you follow the suggestions at that article.

    UPDATE t1

    SET RecordCount = preagg.RecordCount,

    MaxTime = preagg.MaxTime

    FROM dbo.Tab1 t1

    JOIN (

    SELECT CO, RecordCount = COUNT(*)+1, MaxTime = MAX(MaxTime)

    FROM dbo.Tab2

    GROUP BY CO

    ) preagg

    ON preagg.CO = t1.CO

    ;

    --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 3 posts - 1 through 2 (of 2 total)

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