SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Count NULL columns


Count NULL columns

Author
Message
karthik M
karthik M
SSCertifiable
SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)

Group: General Forum Members
Points: 6735 Visits: 2586
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:

1 4
2 3
6 3
7 4


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
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40870 Visits: 20000
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
Exploring Recursive CTEs by Example Dwain Camps
karthik M
karthik M
SSCertifiable
SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)SSCertifiable (6.7K reputation)

Group: General Forum Members
Points: 6735 Visits: 2586
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
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40870 Visits: 20000
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
Exploring Recursive CTEs by Example Dwain Camps
ScottPletcher
ScottPletcher
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19373 Visits: 7410
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) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search