SQL How to use CASE with a NOT EXISTS statement

  • I have quite a complex query in SQL where I am pulling a load of information from various tables and doing various joins. I want to pull a column which checks whether the particular tradeId is contained in 2 different tables. I'm getting stuck with how to do this properly though.

    The below code gives me all the TradeIds from the Trade table that are NOT in the TCM (which is just a combination of 2 tables). However I would like ALL the trades from the Trade table and then a column to indicate whether it is found in TCM or not.

    I know this would be done with a CASE WHEN query but I'm confused how to structure it so that it fits in the CASE WHEN.

    With subCA As

    (Select distinct OTPTradeId, ConfoAuditSenderRef from ConfirmationAudit where ConfoAuditSenderRef like 'HBEUM%'),

    TCM As

    (Select distinct OTPTradeID from subCA union ALL select TradeId from subCA inner join ConfirmationSent on (OTPTradeId = ConfoId

    AND ConfoAuditSenderRef like 'HBEUMN%'))

    select TradeId from Trade where NOT EXISTS (Select OtpTradeId from TCM where OtpTradeId = TradeId)

    and TradeDate = '17 jun 2013'

    Heres my attempt to fit it in a CASE WHEN statement but I get an error because the NOT EXISTS is not allowed without a WHERE I believe. But what I am after is something like this. If I use NOT IN it becomes painstakingly slow like 5 minutes plus and this is part of an larger query and I dont want it to take so long - if possible!

    With subCA As

    (Select distinct OTPTradeId, ConfoAuditSenderRef from ConfirmationAudit where ConfoAuditSenderRef like 'HBEUM%'),

    TCM As

    (Select distinct OTPTradeID from subCA union ALL select TradeId from subCA inner join ConfirmationSent on (OTPTradeId = ConfoId

    AND ConfoAuditSenderRef like 'HBEUMN%'))

    select TradeId,

    CASE WHEN

    (TradeId NOT EXISTS (Select OtpTradeId from TCM where OtpTradeId = TradeId) Then 'Y' Else 'N' End As 'TCM'

    from Trade

    WHERE TradeDate = '17 jun 2013'

  • Like this?

    With subCA As (

    Select distinct

    OTPTradeId,

    ConfoAuditSenderRef

    from ConfirmationAudit

    where ConfoAuditSenderRef like 'HBEUM%'

    ),

    TCM As (

    Select distinct

    OTPTradeID

    from subCA

    union ALL

    select TradeId

    from subCA

    inner join ConfirmationSent

    on (OTPTradeId = ConfoId

    AND ConfoAuditSenderRef like 'HBEUMN%')

    )

    SELECT

    t.TradeId,

    CASE WHEN x.OtpTradeId IS NULL THEN 'Y' Else 'N' End As 'TCM'

    FROM Trade t

    OUTER APPLY (SELECT TOP 1 OtpTradeId FROM TCM m WHERE m.OtpTradeId = t.TradeId) x

    WHERE t.TradeDate = '17 jun 2013'

    “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

  • Thanks for that - it pulls out what I need but the query time is 8mins (and counting!) I know its difficult to say as you cannot see the structure of the DB but where could it be going wrong? (I only have readonly access to the DB so cant view the execution plan sadly)

  • There's scope for improvement but without ddl/execution plan it's a long shot. Try this:

    SELECT

    t.TradeId,

    CASE WHEN x.OtpTradeId IS NULL THEN 'Y' Else 'N' End As 'TCM'

    FROM Trade t

    OUTER APPLY (

    SELECT TOP 1 ca.OTPTradeID, cs.TradeId

    FROM ConfirmationAudit ca

    LEFT JOIN ConfirmationSent cs

    ON ca.OTPTradeId = cs.ConfoId

    AND cs.ConfoAuditSenderRef LIKE 'HBEUMN%'

    WHERE ca.ConfoAuditSenderRef LIKE 'HBEUM%'

    AND (ca.OTPTradeID = t.TradeId OR cs.TradeId = t.TradeId)

    ) x

    WHERE t.TradeDate = '17 jun 2013'

    “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

  • I gave up on the first query - was 30 mins and counting! Massively appreciate your time Chris.

    Ive tried another way albeit a copout from the IF EXISTS method - it seems to look like it works but could you please check it as well. It only took 2 minutes.

    With TCM AS(

    select distinct OTPTradeId from confirmationaudit where confoauditsenderref like 'HBEUM0%'

    union

    select distinct tradeid from confirmationsent cs, confirmationaudit ca where cs.confoid = ca.otptradeid

    )

    select TradeId, OTPTradeId As 'TCM ID',

    case when OTPTradeId is NULL Then 'No' Else 'Yes' End as 'TCM'

    from Trade left join TCM on TradeID = OTPTradeId

    where tradedate = '17 Jun 2013'

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

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