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


Exotic SQL: NULL Column Analysis


Exotic SQL: NULL Column Analysis

Author
Message
Leo Peysakhovich
Leo Peysakhovich
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1324 Visits: 371
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnist



Richard Nadeau
Richard Nadeau
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 6

Great article. I found that blew up when the table owner was not the dbo so I added a little bit of code and it worked beautifully. Thanks for sharing. Here is the modified version:

Use pubs

drop table pubs..tmp_count
go
Create table pubs..tmp_count
(dbnm varchar(50), owner varchar(255), tbl varchar(255), col varchar(255), nulls int, tot int)
go


----------------------------------------------------------------------------------
-- begin batch
----------------------------------------------------------------------------------
BEGIN
declare @sql Nvarchar(1000), @minid int, @maxid int,
@table_n varchar(255), @col varchar(255), @dbnm varchar(50), @ownernm varchar(50)
declare @tmp1 table (id
int identity(1,1), tbl varchar(255), col varchar(255), owner varchar(255))


set @dbnm = db_name()
truncate table pubs..tmp_count
insert into @tmp1(tbl,col,owner)
select so.name, sc.name, su.name from syscolumns sc
inner join sysobjects so on so.id = sc.id
inner join sysusers su on so.uid = su.uid
where so.name not like 'ERR_%' and so.type = 'U' and
sc.isnullable = 1
select @minid = 1, @maxid = max(id) from @tmp1
while (@minid <=@maxid)
begin
select @table_n = tbl,@col = col,@ownernm = owner from @tmp1
where id = @minid
select @sql = ' insert into pubs..tmp_count(dbnm, owner, tbl, col , nulls , tot)'
select @sql = @sql + ' select ''' + @dbnm + ''', ''' + @ownernm + ''', ''' + @table_n + ''', ''' +
@col + ''', (select count(*) from [' + @ownernm + '].[' + @table_n + '] where ['+ @col + '] is null) '
select @sql = @sql + ' , (select count(*) from [' + @ownernm + '].[' + @table_n +'])'

exec ( @sql )
set @minid = @minid + 1
end
END
-----------------------------------------------------------------------------------
-- end batch
-----------------------------------------------------------------------------------

select left(dbnm,10) as dbnm, left(owner,20) as owner, left(tbl,20) as tbl,
left(col,20) as col,tot, nulls, tot - nulls as NotNulls
from pubs..tmp_count order by NotNulls


russella0-96423
russella0-96423
SSC Veteran
SSC Veteran (200 reputation)SSC Veteran (200 reputation)SSC Veteran (200 reputation)SSC Veteran (200 reputation)SSC Veteran (200 reputation)SSC Veteran (200 reputation)SSC Veteran (200 reputation)SSC Veteran (200 reputation)

Group: General Forum Members
Points: 200 Visits: 255
Hi - This really helped me field a query from my boss ultra quick - I appreciate your hard work being shared.



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