Home Forums Programming General compare the values in the column RE: compare the values in the column

  • Here is your test data in a readily consumable form, i.e. a CREATE TABLE statement and an INSERT statement. Supplying test data in this form will encourage people to assist you, and therefore tends to lead to a greater number of responses in a shorter time.

    CREATE TABLE #t (

    field1 varchar(20) NOT NULL,

    field2 char(1) NOT NULL

    )

    INSERT INTO #t(field1, field2)

    SELECT 'position1', 'b' UNION ALL

    SELECT 'position1', 'b' UNION ALL

    SELECT 'position2', 'a' UNION ALL

    SELECT 'position2', 'a' UNION ALL

    SELECT 'position3', 'a' UNION ALL

    SELECT 'position3', 'b'

    I'm not sure which version of SQL Server you are using, but the following queries should work on any version of SQL Server from 2000 or later. If the field2 column cannot possibly take any value other than 'a' or 'b', the query could be written as follows:

    SELECT T.field1, T.field2, CASE

    WHEN (AGG.CountA = AGG.CountAll) THEN 1

    WHEN (AGG.CountB = AGG.CountAll) THEN 2

    ELSE 3 END AS Flag

    FROM #t AS T INNER JOIN (

    SELECT field1,

    COUNT(1) AS CountAll,

    COUNT(CASE WHEN field2 = 'a' THEN 1 END) AS CountA,

    COUNT(CASE WHEN field2 = 'b' THEN 1 END) AS CountB

    FROM #t

    GROUP BY field1

    ) AGG ON (T.field1 = AGG.field1)

    This second version of the query will return NULL for the Flag column if there is any value of the field2 column in a group (grouped by field1) that is neither 'a' nor 'b'.

    SELECT T.field1, T.field2, CASE

    WHEN (AGG.CountA = AGG.CountAll) THEN 1

    WHEN (AGG.CountB = AGG.CountAll) THEN 2

    WHEN (AGG.CountA + AGG.CountB = AGG.CountAll) THEN 3

    ELSE NULL END AS Flag

    FROM #t AS T INNER JOIN (

    SELECT field1,

    COUNT(1) AS CountAll,

    COUNT(CASE WHEN field2 = 'a' THEN 1 END) AS CountA,

    COUNT(CASE WHEN field2 = 'b' THEN 1 END) AS CountB

    FROM #t

    GROUP BY field1

    ) AGG ON (T.field1 = AGG.field1)