Performance tuning on insert query

  • Hi all,

    I have a validation table which gets updated through a insert statement. The fields in the select clause has a computed column and the t_validate table gets updated once matching policies and other conditions are satisfied.

    Now This query in previuos runs would complete in 5 mins. But now it is taking more than 2 hours and still query does not complete. For information, this step is taking longers hours as additional data has been added to table b (> 1 mil records).

    Please help to optimize this query. Thanks....

    Actual query:

    insert into t_validate (policy,form,date,premium)

    Select a.policy, a.form, a.date, sum(a.premium/b.premprcnt) as premium

    from b inner join a on

    b.policy = a.policy and

    b.form = a.form and

    b.date = a.date and

    b.location_date = a.location_date and

    b.location_pin = a.location_pin and

    b.state = a.state

    group by a.policy, a.form, a.date

  • Please post table definitions, index definitions and execution plan as per http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

    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
  • How long does the select part SELECT

    a.policy,

    a.form,

    a.date,

    SUM(a.premium/b.premprcnt) AS premium

    FROM b

    INNER JOIN a

    ON b.policy = a.policy

    AND b.form = a.form

    AND b.date = a.date

    AND b.location_date = a.location_date

    AND b.location_pin = a.location_pin

    AND b.state = a.state

    GROUP BY a.policy, a.form, a.date of the query take to run?

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    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

  • It takes more than 2 hours. I have let the query run completely. I cancelled the query once it crossed the 2 hour duration.

  • Can you post the things I asked for?

    Is this supposed to be an unrestricted select? No where clause?

    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
  • Gail may have already spotted the problem. If you're just running the SELECT and there's no filter on the data, it's doing a scan of all data across all the tables involved in the query. It's just going to take how long it takes. You might be able to speed up aspects of it such as the joins, with indexing, but overall... you might be in trouble.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • To get maximum performance you want a merge join between a and b and you want an index on a so you can use a stream aggregation for the group by.

    This can be achieved by using the following indexes:

    create nonclustered index IX_a on a

    (policy, form, date, location_date, location_pin, state)

    include (premium)

    create nonclustered index IX_b on b

    (policy, form, date, location_date, location_pin, state)

    include (premprcnt)

Viewing 7 posts - 1 through 6 (of 6 total)

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