Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Validating all the columns in a record


Validating all the columns in a record

Author
Message
dasari_stupid-735994
dasari_stupid-735994
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
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.
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14931 Visits: 38917
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

muthukrishnan_1985
muthukrishnan_1985
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: 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...
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14931 Visits: 38917
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

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