Update a table by compare values in two rows from a second table

  • Couldn't think of a more specific subject for my query so apologies in advance.

    Would really appreciate help with this.

    I have the following two tables. I need to write an Update statement to update Table2.Price with the Table2.Price. The condition here is that Table2.CreatedDate the Table1.Date rows.

    E.g the first row in Table2 the CreatedDate is greater than Table1.Date so the Table2.Price would be 1500.

    E.g row 4 in Table1 the CreatedDate is Greater than row 3 in Table1.Date and less than row 2 in Table1.Date so the price would be 1000

    Table1

    LinkIDPriceDate

    116615002012-11-15 00:00:00

    116613002012-10-01 00:00:00

    116610002012-05-15 00:00:00

    202020002012-09-09 00:00:00

    202017502012-07-01 00:00:00

    Table2

    LinkIDPriceCreatedDate

    1166NULL2012-12-01 00:00:00

    1166NULL2012-10-05 00:00:00

    1166NULL2012-10-01 00:00:00

    1166 02012-08-02 00:00:00

    2020NULL2012-10-09 00:00:00

    2020NULL2012-07-02 00:00:00

    Following is how the updated Table2 should look like.

    Table2

    LinkIDPriceCreatedDate

    116615002012-12-01 00:00:00

    116613002012-10-05 00:00:00

    116613002012-10-01 00:00:00

    116610002012-08-02 00:00:00

    202020002012-10-09 00:00:00

    202017502012-07-02 00:00:00

    Thanks everyone in advance.

  • Probably the reason no one has volunteered to help after 6 days is that you didn't provide your sample data in readily consumable form.

    I'm feeling charitable today so I will do that for you.

    DECLARE @Table1 TABLE

    (LinkID INT, Price MONEY, Date DATETIME)

    INSERT INTO @Table1

    SELECT 1166,1500,'2012-11-15 00:00:00'

    UNION ALL SELECT 1166,1300,'2012-10-01 00:00:00'

    UNION ALL SELECT 1166,1000,'2012-05-15 00:00:00'

    UNION ALL SELECT 2020,2000,'2012-09-09 00:00:00'

    UNION ALL SELECT 2020,1750,'2012-07-01 00:00:00'

    DECLARE @Table2 TABLE

    (LinkID INT, Price MONEY, CreatedDate DATETIME)

    INSERT INTO @Table2

    SELECT 1166,NULL,'2012-12-01 00:00:00'

    UNION ALL SELECT 1166,NULL,'2012-10-05 00:00:00'

    UNION ALL SELECT 1166,NULL,'2012-10-01 00:00:00'

    UNION ALL SELECT 1166,0,'2012-08-02 00:00:00'

    UNION ALL SELECT 2020,NULL,'2012-10-09 00:00:00'

    UNION ALL SELECT 2020,NULL,'2012-07-02 00:00:00'

    UPDATE a

    SET Price = (

    SELECT TOP 1 Price

    FROM @Table1 b

    WHERE a.LinkID = b.LinkID AND Date < CreatedDate

    ORDER BY Date DESC)

    FROM @Table2 a

    SELECT *

    FROM @Table2

    You can Google "SQL correlated subquery" if you need to understand how this works.


    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