SQL Query (Inset-Update)

  • Hi ,

    I need help with my sql query :

    CREATE TABLE #Temp

    (

    ID INT IDENTITY(1,1),

    OrdId INT,

    ProjID INT,

    ProductID INT,

    Blocks Decimal(10,2),

    PAmount Decimal(10,2),

    PUnits Decimal(10,2)

    )

    INSERT INTO #Temp ( OrdID,ProjID,ProductID,Blocks,PAmount,PUnits)

    SELECT 2115,2137,377,10.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,350,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,345,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,389,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,450,13.00,3312.00,169.00

    UNION ALL

    SELECT 3115,2136,450,13.00,6312.00,835.00

    UNION ALL

    SELECT 3115,2136,457,03.00,6312.00,835.00

    UNION ALL

    SELECT 3115,4560,450,13.00,11312.00,135.00

    SELECT * FROM #Temp

    FOR every OrdID AND ProjID combination, I would LIKE TO ADD a line item WITH ProductID = 1 AND make the Blocks,PAmount,PUnits field VALUES 0

    EXAMPLE

    SELECT 2115,2137,377,10.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,350,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,345,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,389,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,450,13.00,3312.00,169.00

    UNION ALL

    SELECT 2115,2137,1,0.00,0.00,0.00

    UNION ALL

    SELECT 3115,2136,450,13.00,6312.00,835.00

    UNION ALL

    SELECT 3115,2136,457,03.00,6312.00,835.00

    UNION ALL

    SELECT 3115,2136,1,0.00,0.00,0.00

    UNION ALL

    SELECT 3115,4560,450,13.00,11312.00,135.00

    UNION ALL

    SELECT 3115,4560,1,0.00,0.00,0.00

    DROP TABLE #Temp

    I want to update PAmount,PUnits fields for every OrdID AND ProjID combination WHERE ProductID = 1 . Others belonging TO this combination WHERE ProductID <> 1 should be updated TO 0.

    SELECT 2115,2137,377,10.00,0.00,0.00

    UNION ALL

    SELECT 2115,2137,350,13.00,0.00,0.00

    UNION ALL

    SELECT 2115,2137,345,13.00,0.00,0.00

    UNION ALL

    SELECT 2115,2137,389,13.00,0.00,0.00

    UNION ALL

    SELECT 2115,2137,450,13.00,0.00,0.00

    UNION ALL

    SELECT 2115,2137,1,0.00,3312.00,169.00

    UNION ALL

    SELECT 3115,2136,450,13.00,0.00,0.00

    UNION ALL

    SELECT 3115,2136,457,03.00,0.00,0.00

    UNION ALL

    SELECT 3115,2136,1,0.00,6312.00,835.00

    UNION ALL

    SELECT 3115,4560,450,13.00,0.00,0.00

    UNION ALL

    SELECT 3115,4560,1,0.00,11312.00,135.00

    Please help .

    Thanks,

    PSB

  • Any help , please anyone ?

  • Do you mean like this?

    WITH ProductIDs AS

    (

    SELECT OrdID, ProjID, ProductID=1

    ,Blocks=MAX(Blocks), PAmount=MAX(Pamount), Punits=MAX(PUnits)

    FROM #Temp

    GROUP BY OrdID, ProjID

    HAVING MIN(ProductID) > 1

    UNION ALL

    SELECT OrdID, ProjID, ProductID, Blocks, PAmount, Punits

    FROM #Temp

    )

    MERGE #Temp t

    USING ProductIDs s

    ON s.OrdID = t.OrdID AND s.ProjID = t.ProjID AND s.ProductID = t.ProductID

    WHEN NOT MATCHED AND s.ProductID = 1

    THEN

    INSERT

    (

    OrdID, ProjID, ProductID, Blocks, Pamount, Punits

    )

    VALUES

    (

    s.OrdID, s.ProjID, s.ProductID, s.Blocks, s.Pamount, s.Punits

    )

    WHEN MATCHED AND t.ProductID <> 1

    THEN

    UPDATE

    SET Blocks = 0

    ,PAmount = 0

    ,Punits = 0;


    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

  • Thanks . Works perfectly.

  • PSB (2/16/2015)


    Thanks . Works perfectly.

    Just so you know and before someone else chides me on this point, you should read this link and decide if any of those cases applies to you:

    Use Caution with SQL Server's MERGE Statement[/url]

    I personally use it and haven't had any significant problems.


    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

  • The query performance is very poor . Any tips on improving performance ?

  • PSB (2/17/2015)


    The query performance is very poor . Any tips on improving performance ?

    I'm not particularly surprised. A few questions.

    1. How often does this query run?

    2. Would it be possible to introduce a flag column (indexed) containing a date when the process hit specific records, as a way to exclude those on a future run?

    3. How many rows are in the table?

    4. Have you tried breaking the MERGE into a standard "upsert" type of operation (that's an INSERT separate from UPDATE)?


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

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