Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Validating all the columns in a record Expand / Collapse
Author
Message
Posted Thursday, January 15, 2009 12:02 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, November 15, 2010 3:36 AM
Points: 5, Visits: 78
Hi,

Please find our requirement below,

We have a staging table with the following structure
Tgt_stg:
---------
col1 varchar(100),
col2 varchar(100),
col3 varchar(100)

We have target table with the following desc

Tgt_tab:
---------
col1 Numeric(10),
col2 datetime,
col3 varchar(20)


We have a requirement to validate the values in stage table for all the records against the target table(i.e)
isnumeric(Row1.col1),isdate(Row1.col2),len (Row1.col3)<=20
isnumeric(Row2.col1),isdate(Row2.col2),len (Row2.col3)<=20
isnumeric(Row3.col1),isdate(Row3.col2),len (Row3.col3)<=20
isnumeric(Row4.col1),isdate(Row4.col2),len (Row4.col3)<=20
.
.
.
.

The records that failed to confirm the validation should redirected to a error table by concatenating all the error messages.

We are planning to write a SP for the same.As we are new SQL server,It could be helpful if you give the complete code.

Thanks.
Post #637463
Posted Thursday, January 15, 2009 12:24 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:03 PM
Points: 12,963, Visits: 32,512
wouldn't you simply identify the offending rows like this?

SELECT *
FROM YOUR STAGINGTABLE
WHERE isnumeric(col1) = 0
OR isdate(col2) = 0
OR len (Row1.col3)> 20


Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #637484
Posted Thursday, January 15, 2009 11:30 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, January 28, 2013 11:36 PM
Points: 1, Visits: 26
Hi,

Thanks for reply.

The problem here we need to pass the table name dynamically.It means that the procedure should able to validate all the columns what ever the table we are passing.
For this purpose we are using 'INFORMATION_SCHEMA.COLUMNS' to get the metadata details for a table.We stuck up there.
We need a procedure for which the stage,target table names should be an argument.

Hope i cleared the requirement.

Thanks in advance.

Regards,
Muthu...
Post #637757
Posted Friday, January 16, 2009 6:54 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:03 PM
Points: 12,963, Visits: 32,512
ok this nippet, based on using some FOR XML statements goves a SQL statement you could execute that looks like this:
SELECT * FROM MYSTAGE WHERE 1 = 2   
OR ISNUMERIC(COUNTYTBLKEY) = 0
OR ISNUMERIC(INDEXTBLKEY) = 0
OR LEN(STATE) > 2
OR LEN(DESCRIP) > 30
OR LEN(CODE) > 3
OR ISNUMERIC(STATETBLKEY) = 0
OR ISNUMERIC(REGIONTBLKEY) = 0
OR ISNUMERIC(EDREGIONTBLKEY) = 0
OR ISNUMERIC(SPECDISTTBLKEY) = 0

this might get you started:
DECLARE @STAGINGTABLE VARCHAR(125),
        
@TESTAGAINST  VARCHAR(125)
SELECT @STAGINGTABLE ='MYSTAGE' ,
    
@TESTAGAINST  ='TBCOUNTY'
SELECT
  DISTINCT
REPLACE(REPLACE('SELECT * FROM '
                  
+ @STAGINGTABLE
                  
+ ' WHERE 1 = 2 '
                  
+ STUFF(
                          (
                          
SELECT
                            
' OR  '
                            
+ CASE
                                
WHEN B.DATA_TYPE IN('varchar','nvarchar','char','nchar')
                                
THEN ' LEN('+ B.COLUMN_NAME + ') > '+ CONVERT(VARCHAR,CHARACTER_MAXIMUM_LENGTH) + ' '
                                
WHEN DATA_TYPE IN('datetime')
                                
THEN ' ISDATE(' + B.COLUMN_NAME + ') = 0 '
                                
WHEN DATA_TYPE IN('int','bigint','money','float','decimal','numeric')
                                
THEN ' ISNUMERIC('+ B.COLUMN_NAME + ') = 0 '
                              
END
                           FROM
information_schema.columns B
                          
WHERE A.TABLE_NAME = B.TABLE_NAME
                            
FOR XML PATH(''))
                           ,
                          
1, 2, ' OR  ') ,'>','>'
                  
),'OR  R   ',' OR   ') AS SQLSTATEMENT
FROM information_schema.columns A
WHERE TABLE_NAME = @TESTAGAINST








Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #638002
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse