Converting "not in" to "not exists"

  • /* I'm trying to change "not in" to "not exists" and I don't have the syntax quite right. The first statement updates multiple rows

    while the second statement updates 0 rows. This is for SQL Server. */

    update VehicleWorld set EstimatedDeletedDate=1

    where Vehicle_ID not in (select Vehicle_ID from CFS_Production..CORE_VehicleAdSearch ads)

    update VehicleWorld set EstimatedDeletedDate=1

    where not exists

    (select 1 from VehicleWorld car, CFS_Production..CORE_VehicleAdSearch ads

    where car.Vehicle_ID = ads.Vehicle_ID)

  • i prefer to use aliases for my updates, because the format for SQL makes it easy to include a SELECT statement very easily, which lets me do a quick Sanity Check by running the SELECT portion with the identical criteria.

    how does this work for you?

    UPDATE MyTarget

    SET MyTarget.EstimatedDeletedDate = 1

    --highlight and execute starting at the SELECT

    --SELECT MyTarget.EstimatedDeletedDate,*

    FROM VehicleWorld MyTarget

    WHERE NOT EXISTS

    (SELECT 1 FROM VCFS_Production..CORE_VehicleAdSearch ads

    WHERE MyTarget.Vehicle_ID = ads.Vehicle_ID)

    AND MyTarget.EstimatedDeletedDate <> 1

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • aiki4ever-796329 (6/27/2013)


    /* I'm trying to change "not in" to "not exists" and I don't have the syntax quite right. The first statement updates multiple rows

    while the second statement updates 0 rows. This is for SQL Server. */

    update VehicleWorld set EstimatedDeletedDate=1

    where Vehicle_ID not in (select Vehicle_ID from CFS_Production..CORE_VehicleAdSearch ads)

    update VehicleWorld set EstimatedDeletedDate=1

    where not exists

    (select 1 from VehicleWorld car, CFS_Production..CORE_VehicleAdSearch ads

    where car.Vehicle_ID = ads.Vehicle_ID)

    One important point here is that you're selecting from VehicleWorld in the subquery and then joining your table you check to it. This means that it won't join to the outer VehicleWorld table, so your update won't work. The one below should do the update because the subquery is correlated to the outer table.

    update VehicleWorld

    set EstimatedDeletedDate = 1

    where not exists (select 1

    from CFS_Production..CORE_VehicleAdSearch ads

    where VehicleWorld.Vehicle_ID = ads.Vehicle_ID);

    All that being said, I completely agree with Lowell...the syntax that allows you to select before firing an update is a good safety measure to make sure you aren't surprised by firing the update.

  • I see my problem. I had two tables in my subquery instead of one. That syntax is certainly confusing. Thank you gentlemen for your kind assistance. I'm quite glad that there are people in the world who understand SQL better than I do and who are willing to spread their knowledge. 🙂

Viewing 4 posts - 1 through 3 (of 3 total)

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