Tuning UPDATE query

  • Hi Guys ,

    I am tuning an UPDATE query by adding an index

    UPDATE XYZ

    SET Count = Count + 1,

    LastOccured = GetDate()

    WHERE AppID = @AppID

    AND SubString(Message, 1, 50) = SubString(@Message, 1, 50)

    AND DateDiff(mi, CreatedDate, GETDATE()) < 60

    Since it is UPDATE statement that will change the table value I am worried if I run that script to compare before and after I apply Index , it will change the value . If it is SELECT statement I won’t worry ..

    I want to measure the performance by using :

    Set statistics IO on

    So I can analyse the Logical read

    Please kindly advise ..

    Thank you

  • WhiteLotus (6/2/2016)


    Hi Guys ,

    I am tuning an UPDATE query by adding an index

    UPDATE XYZ

    SET Count = Count + 1,

    LastOccured = GetDate()

    WHERE AppID = @AppID

    AND SubString(Message, 1, 50) = SubString(@Message, 1, 50)

    AND DateDiff(mi, CreatedDate, GETDATE()) < 60

    Since it is UPDATE statement that will change the table value I am worried if I run that script to compare before and after I apply Index , it will change the value . If it is SELECT statement I won’t worry ..

    I want to measure the performance by using :

    Set statistics IO on

    So I can analyse the Logical read

    Please kindly advise ..

    Thank you

    An index on anything other than [Appid] won't help much with this query as it stands - functions around columns in the WHERE clause almost always obstruct index usage. Try removing the functions, something like this:

    UPDATE XYZ SET

    [Count] = [Count] + 1,

    LastOccured = GETDATE()

    WHERE AppID = @AppID

    AND CreatedDate >= DATEADD(MINUTE,-90,GETDATE())

    AND [Message] LIKE LEFT(@Message, 50) + '%'

    An index on AppID, CreatedDate and INCLUDEing Message should do it.

    “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

Viewing 2 posts - 1 through 1 (of 1 total)

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