How can I find the first column having NULL values in a table

  • Hi Friends,

    I have a file reader function that will read the file and load the data into a temp table. This function is designed to read 100 columns, but in some cases I will have only 30 columns data so that the remaining columns will be having value as <unknown>.

    Later this table will be called through another SP/Function (for some functionality), so if I can get to know the depth (the first column in the table which is having this <unknown> value, then I can pass that position (depth) to my SP so that I donโ€™t have to execute my SP/Function for these columns where there is no data at all.

    So is there any way to know the first column of table which has the NULL or (in my case <Unknown>) value?

    Thanks & Regards,
    MC

  • This may help.

    DECLARE @T TABLE

    (Col1 INT, Col2 INT, Col3 INT, Col4 INT

    ,Col5 INT, Col6 INT, Col7 INT, Col8 INT

    ,Col9 INT, Col10 INT, Col11 INT, Col12 INT)

    INSERT INTO @T (Col1, Col2, Col3, Col4)

    SELECT 1, 2, 3, 4

    UNION ALL SELECT 5, 6, 7, 8

    SELECT * FROM @T

    SELECT TOP 1 n

    FROM (SELECT TOP 1 * FROM @T) a

    CROSS APPLY (

    VALUES (1, Col1), (2, Col2)

    ,(3, Col3), (4, Col4)

    ,(5, Col5), (6, Col6)

    ,(7, Col7), (8, Col8)

    ,(9, Col9), (10, Col10)

    ,(11, Col11), (12, Col12)) b(n, Col)

    WHERE Col IS NULL

    ORDER BY n

    The number returned is the first column containing a NULL in the first row of the table.

    This is basically an UNPIVOT that is using the technique described here: http://www.sqlservercentral.com/articles/CROSS+APPLY+VALUES+UNPIVOT/91234/

    Somewhere in that article I believe it warns you that you need to CAST each column to the same (compatible) type if there are differences.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Thanks dwain.c,

    I'm getting the answer with that code. I'm just trying to see if I can rewrite this some way so that I don't have to hard code my 90+ columns ( agreed it is one time activity but still )

    Thanks & Regards,
    MC

  • only4mithunc (9/30/2012)


    Thanks dwain.c,

    I'm getting the answer with that code. I'm just trying to see if I can rewrite this some way so that I don't have to hard code my 90+ columns ( agreed it is one time activity but still )

    I don't see any way around hardcoding the 90+ columns. Sorry.

    I wouldn't like that any more than you. ๐Ÿ™‚


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Try this little script I wrote to get the column names of a table in comma-delimited form. Code can be changed to do other formats. Check the Messages tab on the results after run for the text version. This has come in handy SOOOOOOO many times.

    USE <dbname>

    GO

    -- Simple column listing with brackets

    DECLARE @tablename varchar(100)

    DECLARE @colline varchar(4000)

    SET @tablename = '<TableName>'-- set to the table name you are interested in

    SET @colline = ''-- leave blank

    SELECT @colline=@colline + COLUMN_NAME + ',' FROM information_schema.columns

    WHERE TABLE_NAME = @tablename

    ORDER BY ORDINAL_POSITION

    SELECT SUBSTRING(@colline,1,len(@colline)-1)

    PRINT SUBSTRING(@colline,1,len(@colline)-1)

  • In this case ;-), I think a simple CASE will do exactly the same thing:

    SELECT TOP 1

    CASE WHEN Col1 IS NULL THEN 1 WHEN Col2 IS NULL THEN 2 WHEN Col3 IS NULL THEN 3 WHEN Col4 IS NULL THEN 4

    WHEN Col5 IS NULL THEN 5 WHEN Col6 IS NULL THEN 6 WHEN Col7 IS NULL THEN 7 WHEN Col8 IS NULL THEN 8

    WHEN Col9 IS NULL THEN 9 WHEN Col10 IS NULL THEN 10 WHEN Col11 IS NULL THEN 11 WHEN Col12 IS NULL THEN 12 END

    FROM @T

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

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

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