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


Need help with dynamic sql query


Need help with dynamic sql query

Author
Message
Sean Lange
Sean Lange
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62135 Visits: 17954
jancas08 (2/27/2013)
Okay I will simplify my steps:


The TEST ddl is the data that has commands that specify changes to the tables.

My objective is to do those specified commands which can either be insert update or delete.

The TEST ddl has a column named COMMAND which will have insert update or delete.
The TEST ddl has a column named ERRORMESSAGE; this specifies which table to run the commands on.
So, my rules are:

O14* dictates use of FOURTEEN_ALL table
HH* dictates use of HH_ALL table
HL* dictates use of HH_LISTING table
ED* dicatates use of EDUCATION table

All that I am to do is run the commands and display what commands are being executed.


OK now I understand what you are after. Can you post some sample data for test so I have something to work with?

By my count you have 4 possible tables each with a possible 3 commands. That means you would need to have 12 queries similar to my first post.

How many rows are in the test table during a typical run?

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
jancas08
jancas08
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 31
Typically running about 5000 rows.

I will send sample data in 2mins.
jancas08
jancas08
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 31

INSERT INTO [janinetestdata].[dbo].[EDUCATION] VALUES(2,3,4,6,2,4398)

INSERT INTO [janinetestdata].[dbo].[EDUCATION] VALUES(2,3,7,5,3,4237)

INSERT INTO [janinetestdata].[dbo].[EDUCATION] VALUES(5,3,4,6,2,4385)

INSERT INTO [janinetestdata].[dbo].[EDUCATION] VALUES(2,6,9,3,5,467)



INSERT INTO [janinetestdata].[dbo].[HH_ALL] VALUES(76544 , 2 , 7 , 25227 , 5 , 6 , 7 , 5 )

INSERT INTO [janinetestdata].[dbo].[HH_ALL] VALUES(76557 , 2 , 7 , 5677 , 5 , 6 , 7 , 5 )

INSERT INTO [janinetestdata].[dbo].[HH_ALL] VALUES(76544 , 2 , 7 , 25227 , 5 , 6 , 7 , 5 )

INSERT INTO [janinetestdata].[dbo].[HH_ALL] VALUES(76557 , 2 , 7 , 5677 , 5 , 6 , 7 , 5 )



INSERT INTO [janinetestdata].[dbo].[HH_LISTING] VALUES('7' , 3 , 4 , 6 , 8 , 6 , 5 , 35067 )

INSERT INTO [janinetestdata].[dbo].[HH_LISTING] VALUES('7' , 3 , 1 , 6 , 8 , 6 , 3 , 71027 )


INSERT INTO [janinetestdata].[dbo].[HH_LISTING] VALUES('7' , 3 , 8 , 6 , 8 , 6 , 2 , 35087 )

INSERT INTO [janinetestdata].[dbo].[HH_LISTING] VALUES('7' , 3 , 4 , 6 , 8 , 6 , 1 , 64077 )


INSERT INTO [janinetestdata].[dbo].[FOURTEEN_ALL] VALUES(36177 , 71493 , 3 , '3' , 4 , 4 , 7 , 9 , 3 , 4 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , '5' , '5' , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5)
INSERT INTO [janinetestdata].[dbo].[FOURTEEN_ALL] VALUES(36177 , 71594 , 3 , '2' , 4 , 4 , 7 , 3 , 3 , 4 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , '5' , '5' , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5)


INSERT INTO [janinetestdata].[dbo].[FOURTEEN_ALL] VALUES(36174 , 77019 , 7 , '1' , 7 , 4 , 7 , 9 , 4 , 6 , 4 , 6 , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , '5' , '5' , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5)

INSERT INTO [janinetestdata].[dbo].[FOURTEEN_ALL] VALUES(36174 , 77019 , 7 , '1' , 7 , 4 , 7 , 9 , 4 , 6 , 4 , 6 , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , '5' , '5' , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5)







Sean Lange
Sean Lange
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62135 Visits: 17954
jancas08 (2/27/2013)
Typically running about 5000 rows.

I will send sample data in 2mins.


OK then this will greatly benefit from a set based approach instead of a cursor. Thanks for the sample data but we still need some rows for the TEST table because that is the driver for this whole process as I understand it?

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
jancas08
jancas08
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 31

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,15453
,78798
,4
,'ED_THREE'
,5
,9
, 'UPDATE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,13245
,5676
,4
,'ED_FOUR'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,3245
,9603
,4
,'ED_FOUR'
,5
,9
, 'DELETE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('HL ERROR'
,43543
,12324
,4
,'HL_FOUR'
,2
,4
, 'DELETE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('HL ERROR'
,15453
,78798
,4
,'HL_FIVE'
,5
,9
, 'UPDATE')



INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('HL ERROR'
,4566
,42178
,4
,'HL_THREE'
,5
,9
, 'DELETE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,15453
,78798
,4
,'ED_FIVE'
,5
,9
, 'DELETE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,34320
,56896
,21345
,'ED_FIVE'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,565433
,78798
,4
,'ED_FIVE'
,5
,9
, 'DELETE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('O14 ERROR'
,45O43
,23452
,4
,'Q1_5'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('O14 ERROR'
,1324
,23492
,4
,'Q1_7'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('O14 ERROR'
,34954
,56766
,4
,'Q1_5'
,5
,9
, 'DELETE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,45323
,67567
,4
,'ED_THREE'
,5
,9
, 'UPDATE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,42543
,78454
,4
,'ED_FOUR'
,5
,9
, 'DELETE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,32445
,58763
,4
,'ED_FOUR'
,5
,9
, 'DELETE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('HL ERROR'
,79985
,36743
,4
,'HL_FOUR'
,2
,4
, 'UPDATE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('HL ERROR'
,57972
,25654
,4
,'HL_FIVE'
,5
,9
, 'UPDATE')



INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('HL ERROR'
,65776
,23634
,4
,'HL_THREE'
,5
,9
, 'DELETE')


INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,67898
,14365
,4
,'ED_FIVE'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,46765
,56543
,25
,'ED_FIVE'
,5
,9
, 'DELETE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('ED ERROR'
,36545
,67567
,4
,'ED_FIVE'
,5
,9
, 'DELETE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('O14 ERROR'
,56546
,65456
,4
,'Q1_5'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('O14 ERROR'
,35657
,99674
,4
,'Q1_7'
,5
,9
, 'UPDATE')

INSERT INTO [janinetestdata].[dbo].[TEST]
([ERRORMESSAGE]
,[BATCH_NO]
,[zBarcode]
,[Incorrect_Value]
,[Columns_To_Fix]
,[Person_No]
,[Corrected_Value]
,[Command]
)
VALUES
('O14 ERROR'
,23455
,67563
,4
,'Q1_5'
,5
,9
, 'DELETE')


INSERT INTO [janinetestdata].[dbo].[HH_LISTING]([ERRORMESSAGE],Command,[Person_No]
,[HL_THREE]
,[HL_FOUR]
,[HL_FIVE]
,[HL_SIX]
,[HL_SEVEN]
,[HL_SEVENB]
,[zBarcode]) VALUES('HL', 'INSERT','1' , 3 , 4 , 6 , 8 , 6 , 8 , 15011 )

INSERT INTO [janinetestdata].[dbo].[HH_ALL]([ERRORMESSAGE],Command,[BATCH_NO]
,[Cluster]
,[HHNUM]
,[zBarcode]
,[District]
,[URBAN_RURAL]
,[Final_Result_Code]
,[Person_No])VALUES('HH', 'INSERT',36157 , 2 , 3 , 5678 , 5 , 6 , 8 , 1 )


INSERT INTO [janinetestdata].[dbo].[EDUCATION]([ERRORMESSAGE],Command,[ED_THREE]
,[ED_FOUR]
,[ED_FIVE]
,[ED_SIX]
,[Person_No]
,[zBarcode]) VALUES('ED', 'INSERT',2,3,7,5,3,4237)


INSERT INTO [janinetestdata].[dbo].[FOURTEEN_ALL]([ERRORMESSAGE],Command, [BATCH_NO]
,[zBarcode]
,[HHBarcode]
,[Person_No]
,[District]
,[URBAN_RURAL]
,[Cluster]
,[HHNUM]
,[Final_Result_Code]
,[Q1_5]
,[Q1_5_DKNS]
,[Q1_7]
,[Q1_8]
,[Q1_9]
,[Q1_9_2]
,[Q1_10a]
,[Q1_10b]
,[Q1_10c]
,[Q1_10_Total]
,[Q1_11]
,[Q1_12]
,[Q1_13]
,[Q1_14]
,[Q1_15]
,[Q1_15a]
,[Q1_16]
,[Q1_17]
,[Q1_18]
,[Q1_19]
,[Q1_20]
,[Q1_21]
,[Q1_22]
,[Q1_23]
,[Q1_24]
,[Q1_25]
,[Q1_26]
,[Q1_27]
,[Q1_28_MAIN]
,[Q1_28_OTHER]
,[Q1_28_PREVIOUS]
,[Q1_29_SEASONAL]
,[Q1_29_YEARROUND]
,[Q1_30_MAIN]
,[Q1_30_OTHER]
,[Q1_30_PREVIOUS]
,[Q1_31_MAIN]
,[Q1_31_OTHER]
,[Q1_31_PREVIOUS]
,[Q1_32_MAIN]
,[Q1_32_OTHER]
,[Q1_32_TOTAL]
,[Q1_33_MAIN]
,[Q1_33_OTHER]
,[Q1_33_TOTAL]
,[Q1_35]
,[Q1_37]
,[Q1_38]
,[Q1_39]
,[Q1_40]
,[Q1_41]
,[Q1_41_DKNS]
,[Q1_41a]
,[Q1_41b]
,[Q1_41b_DKNS]
,[Q1_42]
,[Q1_42_DKNS]
,[Q1_43]
,[Q1_44])

VALUES('O14', 'INSERT',36122 , 21593 , 3 , '1' , 4 , 4 , 7 , 9 , 3 , 4 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , '5' , '5' , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , '5' , '5' , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5 , 5)



jancas08
jancas08
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 31
Yes you are right. I had to generate some sample data. It took longer than I anticipated. But I have just posted it before this post.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62135 Visits: 17954
This should cover the Updates and Deletes. I don't understand how the insert logic is supposed to work.


declare @SQL varchar(max) = ''

--First is the updates
select @SQL = stuff ((
select
'Update dbo.' +
case ERRORMESSAGE
when 'ED ERROR' then 'Education'
when 'O14 ERROR' then 'FOURTEEN_ALL'
when 'HL ERROR' then 'HH_LISTING'
when 'HL ERROR' then 'HH_ALL'
end
+ ' set ' + Columns_To_Fix + ' = ''' + Corrected_Value
+ ''' where zBarcode = ' + cast(zBarcode as varchar(20))
+ ' and PERSON_NUMBER = ' + cast(Person_No as varchar(20)) + ';' as MyVal
from test
where Command = 'UPDATE'
for XML PATH(''), type
).value('.','varchar(max)'), 1, 0, '')

--Now we append the deletes
select @SQL = @SQL + stuff ((
select
'DELETE dbo.' +
case ERRORMESSAGE
when 'ED ERROR' then 'Education'
when 'O14 ERROR' then 'FOURTEEN_ALL'
when 'HL ERROR' then 'HH_LISTING'
when 'HL ERROR' then 'HH_ALL'
end
+ ' where zBarcode = ' + cast(zBarcode as varchar(20))
+ ' and PERSON_NUMBER = ' + cast(Person_No as varchar(20)) + ';' as MyVal
from test
where Command = 'UPDATE'
for XML PATH(''), type
).value('.','varchar(max)'), 1, 0, '')

select @SQL

--exec sp_execute @SQL



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
jancas08
jancas08
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 31
Thanks, I think I could to the inserts.

The same logic applies basically and insert the corresponding data that is necessary.

Thanks for your help
jancas08
jancas08
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 31
Quick question how do I print the statements being executed I used
print @sql
but it didnt output anything

Also could you explain that xml coding at the bottom.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62135 Visits: 17954
Sean Lange (2/27/2013)
This should cover the Updates and Deletes. I don't understand how the insert logic is supposed to work.


declare @SQL varchar(max) = ''

--First is the updates
select @SQL = stuff ((
select
'Update dbo.' +
case ERRORMESSAGE
when 'ED ERROR' then 'Education'
when 'O14 ERROR' then 'FOURTEEN_ALL'
when 'HL ERROR' then 'HH_LISTING'
when 'HL ERROR' then 'HH_ALL'
end
+ ' set ' + Columns_To_Fix + ' = ''' + Corrected_Value
+ ''' where zBarcode = ' + cast(zBarcode as varchar(20))
+ ' and PERSON_NUMBER = ' + cast(Person_No as varchar(20)) + ';' as MyVal
from test
where Command = 'UPDATE'
for XML PATH(''), type
).value('.','varchar(max)'), 1, 0, '')

--Now we append the deletes
select @SQL = @SQL + stuff ((
select
'DELETE dbo.' +
case ERRORMESSAGE
when 'ED ERROR' then 'Education'
when 'O14 ERROR' then 'FOURTEEN_ALL'
when 'HL ERROR' then 'HH_LISTING'
when 'HL ERROR' then 'HH_ALL'
end
+ ' where zBarcode = ' + cast(zBarcode as varchar(20))
+ ' and PERSON_NUMBER = ' + cast(Person_No as varchar(20)) + ';' as MyVal
from test
where Command = 'UPDATE'
for XML PATH(''), type
).value('.','varchar(max)'), 1, 0, '')

select @SQL

--exec sp_execute @SQL



So the insert logic is to insert a new row with only certain columns that are defined in the test table? So it will only insert a single column plus zBarcode and PERSON_NUMBER? Let me know if you can't figure it out and I can lend a hand.

I know I said it before but you really would gain a lot of benefit from normalization on your tables.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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