Question on MERGE statement

  • I have a table:

    declare tableName table

    (

    uniqueid int identity(1,1),

    id int,

    starttime datetime2(0),

    endtime datetime2(0),

    parameter int

    )

    A stored procedure has new set of values for a given id. Sometimes the startime and endtime are the same, in which case I update the value of parameter. Sometimes I add a new time range (insert statement), and sometimes I delete a time range (delete statement).

    I had a question on merge, with insert, delete and update and I got that resolved. However I have a different question regarding performance of the merge statement.

    If my target table has hundreds of millions of records and I want to delete/update/insert a handful of records, will SQL server scan the entire target table? I can't have:

    merge ( select * from tableName where id = 10 ) as target

    using ...

    and I can't have:

    merge tableName as target

    using [my query] as source on

    source.id = target.id and

    source.starttime = target.startime and

    source.endtime = target.endtime

    where target.id = 10

    ...

    This means I cannot filter the set of rows in the target table to a handful of records where id = 10.

    Is there a way around this?

  • N_Muller (2/10/2015)


    I have a table:

    declare tableName table

    (

    uniqueid int identity(1,1),

    id int,

    starttime datetime2(0),

    endtime datetime2(0),

    parameter int

    )

    A stored procedure has new set of values for a given id. Sometimes the startime and endtime are the same, in which case I update the value of parameter. Sometimes I add a new time range (insert statement), and sometimes I delete a time range (delete statement).

    I had a question on merge, with insert, delete and update and I got that resolved. However I have a different question regarding performance of the merge statement.

    If my target table has hundreds of millions of records and I want to delete/update/insert a handful of records, will SQL server scan the entire target table? I can't have:

    merge ( select * from tableName where id = 10 ) as target

    using ...

    and I can't have:

    merge tableName as target

    using [my query] as source on

    source.id = target.id and

    source.starttime = target.startime and

    source.endtime = target.endtime

    where target.id = 10

    ...

    This means I cannot filter the set of rows in the target table to a handful of records where id = 10.

    Is there a way around this?

    You can filter the target table to only the rows where id = 10.

    WITH MyTarget AS

    (

    SELECT *

    FROM TargetTable

    WHERE id = 10

    )

    MERGE MyTarget t

    USING whatever s

    ON s.x = t.x

    ... etc

    Whether this helps the performance or not depends on whether id is indexed.

    Using a CTE to filter the target is a good idea anyway whenever you use the DELETE clause of MERGE because of this:

    A Hazard of Using the SQL Merge Statement [/url]


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

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

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