• Jeff Moden (3/20/2013)


    Shanmuga Raj (3/20/2013)


    Thanks.. its working !

    can you let me know why you have used

    HAVING COUNT(*) = 4

    That's to make it so that only those product_ids that have all 4 distinct product condition pairs are returned.

    So far, there are some good answers to this problem, especially Chris' most recent post. My question is, what are you going to do when the conditions change where you might need to meet fewer or more than 4 pairs of conditions? Is this a one off or something where the conditions need to be passed by a GUI or passed by something else?

    Thanks for picking this up, Jeff.

    There's a solution to more than 4 pairs of conditions - depending on how the conditions are raised, as you suggest. Here it is;

    ;WITH IncludedAgentProducts AS (

    SELECT DISTINCT *

    FROM (VALUES

    (1,'1'),

    (2,'3'),

    (3,'2'),

    (4,'1')

    ) d (agent_id, product_code)

    )

    SELECT Product_ID

    FROM (

    SELECT f.Product_ID, f.agent_id, f.product_code

    FROM #fact_sales f

    INNER JOIN IncludedAgentProducts d

    ON d.agent_id = f.agent_id

    AND d.product_code = f.product_code

    GROUP BY f.Product_ID, f.agent_id, f.product_code

    ) d

    GROUP BY Product_ID

    HAVING COUNT(*) = (SELECT COUNT(*) FROM IncludedAgentProducts)

    “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