Count NULL columns

  • Hi All,

    I am working on the below requirement.

    use css

    go

    create table test

    (

    eno int,

    t1 int null,

    t2 int null,

    t3 int null,

    t4 int null

    )

    insert into test values (7,null,null,null,null)

    insert into test values (1,null,null,null,null)

    insert into test values (2,2,null,null,null)

    insert into test values (3,1,7,null,null)

    insert into test values (4,1,7,4,2)

    insert into test values (5,null,null,4,2)

    insert into test values (6,null,null,null,2)

    insert into test values (7,null,null,null,null)

    select eno, cnt from

    (

    select eno, case when t1 is null then 1 else 0 end + case when t2 is null then 1 else 0 end + case when t3 is null then 1 else 0 end + case when t4 is null then 1 else 0 end as cnt

    from test

    )x

    where cnt > 2

    output:

    14

    23

    63

    74

    But my actual requirement is to test 119 columns. do I need to hard code all 119 column in the sql query?

    We can use Dynamic SQL to achieve this, again the problem is the table contains 250 columns.

    is there any trick available to achieve this? Inputs are welcome!

    karthik

  • SELECT t.eno, d.NullCount

    FROM test t

    CROSS APPLY (

    SELECT NullCount = 4 - COUNT(col) FROM (VALUES (t1), (t2), (t3), (t4)) d (col)

    ) d

    WHERE d.NullCount > 2

    “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

  • VALUES (t1), (t2), (t3), (t4))

    I have 119 columns in the actual table. Do I need to use all those names in VALUES clause?

    karthik

  • karthik M (2/7/2014)


    VALUES (t1), (t2), (t3), (t4))

    I have 119 columns in the actual table. Do I need to use all those names in VALUES clause?

    You could use dynamic SQL, but tbh it won't take more than a few moments to copy'n'paste them in.

    “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

  • Many of us prefer to generate such code from the table itself, something like below. Uncomment the EXEC(@sql) when ready to actually run the code:

    USE css

    DECLARE @nonrepeated_cols nvarchar(max)

    DECLARE @repeated_cols nvarchar(max)

    DECLARE @sql nvarchar(max)

    SELECT @nonrepeated_cols = (

    SELECT ', ' + c.name

    FROM sys.columns c

    WHERE

    c.object_id = OBJECT_ID('test') AND

    c.name NOT LIKE 't%'

    FOR XML PATH('')

    )

    SELECT @repeated_cols = (

    SELECT ' + CASE WHEN [' + c.name + '] IS NULL THEN 1 ELSE 0 END'

    FROM sys.columns c

    WHERE

    c.object_id = OBJECT_ID('test') AND

    c.name LIKE 't%'

    FOR XML PATH('')

    )

    SELECT @nonrepeated_cols, @repeated_cols

    SELECT @sql = '

    Select ' + SUBSTRING(@nonrepeated_cols, 3, 2000000000) + ',

    ' + SUBSTRING(@repeated_cols, 4, 2000000000) + ' AS null_count

    from test

    where ' + SUBSTRING(@repeated_cols, 4, 2000000000) + ' >= 2'

    SELECT @sql

    --EXEC(@sql)

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

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

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