• Jeff Moden (10/21/2014)


    Eirikur Eiriksson (10/20/2014)


    Some code refactoring on the previous set based solution to fulfil all the requirements, several orders of magnitude faster than string manipulation although it has not been tested on very large set.

    😎

    Careful now. If you have another CategoryID that does meet the requirements, it won't show.

    Good point! To cater for identical Category definitions, the subquery output will not work. Here is an example of two identical categories, 3 and 13.

    😎

    USE tempdb;

    GO

    DECLARE @t TABLE (Id INT)

    INSERT INTO @t

    SELECT 101 UNION ALL

    SELECT 102 UNION ALL

    SELECT 103 UNION ALL

    SELECT 108;

    DECLARE @t2 TABLE (CategoryId INT, Id INT)

    INSERT INTO @t2

    SELECT 2, 50 UNION ALL

    SELECT 2, 51 UNION ALL

    SELECT 2, 52 UNION ALL

    SELECT 2, 59 UNION ALL

    SELECT 2, 60 UNION ALL

    SELECT 3, 101 UNION ALL

    SELECT 3, 102 UNION ALL

    SELECT 3, 103 UNION ALL

    SELECT 3, 108 UNION ALL

    SELECT 13, 101 UNION ALL

    SELECT 13, 102 UNION ALL

    SELECT 13, 103 UNION ALL

    SELECT 13, 108 UNION ALL

    SELECT 9, 108 UNION ALL

    SELECT 4, 108 UNION ALL

    SELECT 4, 109 UNION ALL

    SELECT 4, 120 UNION ALL

    SELECT 9, 125 UNION ALL

    SELECT 9, 166 UNION ALL

    SELECT 9, 169;

    ;WITH CATEGORY_CANDIDATES AS

    (

    SELECT DISTINCT

    T2.CategoryId

    FROM @t2 T2

    WHERE T2.Id IN (SELECT Id FROM @T)

    )

    ,BASE_SET AS

    (

    SELECT

    T2.CategoryId

    ,T2.Id

    ,COUNT(T2.Id) OVER

    (

    PARTITION BY T2.CategoryId

    ) AS T2_COUNT

    FROM @t2 T2

    INNER JOIN CATEGORY_CANDIDATES CC

    ON T2.CategoryId = CC.CategoryId

    )

    ,INCOMING_SET AS

    (

    SELECT

    T.Id

    ,COUNT(T.Id) OVER

    (

    PARTITION BY (SELECT NULL)

    ) AS T_COUNT

    FROM @t T

    )

    ,MATCHING_SET AS

    (

    SELECT

    BS.CategoryId

    ,COUNT(*) OVER

    (

    PARTITION BY BS.CategoryId

    ) AS T2M_COUNT

    ,T_COUNT

    ,T2_COUNT

    FROM INCOMING_SET INS

    INNER JOIN BASE_SET BS

    ON INS.Id = BS.Id

    )

    SELECT DISTINCT

    MS.CategoryId

    FROM MATCHING_SET MS

    WHERE MS.T_COUNT = MS.T2_COUNT

    AND MS.T_COUNT = MS.T2M_COUNT;

    Results

    CategoryId

    3

    13