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


Dynamic Sql Update error


Dynamic Sql Update error

Author
Message
raym
raym
SSC-Enthusiastic
SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)SSC-Enthusiastic (119 reputation)

Group: General Forum Members
Points: 119 Visits: 307
The solution you gave me worked when I embeded the getdate() in single quotes in my string. problem now is when I want to use the dynamically created columns to run updates I get conversion errors. When I hard code it works ..Where am going wrong ? I have attached sample data and the script that I''m using to generate my table...

I have this table which I create dynamically. What I want to do is to
run an update on the table using the columns I have generated.


--==== If I run it this way it works because I copy the column names and hard code them
UPDATE EDW_STAGE..tbComm_3Months_Ago
SET Missed_Instalment = ((Jul08AMT + Jun08AMT + May08AMT /
(3 * ISNULL(CONVERT(DECIMAL(18,3),EvenInstalment),0))))


--- Tried this .............out of desperation and it gives me this error.
/**
Msg 8114, Level 16, State 5, Line 25
Error converting data type varchar to numeric.
**/

DECLARE @Col1 VARCHAR(10),@Col2 VARCHAR(10),@Col3 VARCHAR(10)

SET @Col1 = (SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME = 'tbComm_3Months_Ago'
AND ORDINAL_POSITION =(6))

SET @Col2 = (SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME = 'tbComm_3Months_Ago'
AND ORDINAL_POSITION =(7))

SET @Col3 = (SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME = 'tbComm_3Months_Ago'
AND ORDINAL_POSITION =(8))

--SELECT @Col1,@Col2,@Col3


--?????????????????? gives me an error
UPDATE EDW_STAGE..tbComm_3Months_Ago
SET Missed_Instalment = ((ISNULL(CONVERT(DECIMAL(18,3),@Col1),0) +
ISNULL(CONVERT(DECIMAL(18,3),@Col2),0) +
ISNULL(CONVERT(DECIMAL(18,3),@Col3),0)/
(3 * ISNULL(CONVERT(DECIMAL(18,3),EvenInstalment),0))))


Msg 8114, Level 16, State 5, Line 25
Error converting data type varchar to numeric.



Attachments
Scripts.zip (4 views, 4.00 KB)
Lynn Pettis
Lynn Pettis
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26691 Visits: 38142
This is what you are probably trying to do:


declare @SQLUpdateCmd varchar(max);
set @SQLUpdateCmd = 'UPDATE EDW_STAGE..tbComm_3Months_Ago SET ' +
'Missed_Instalment = ((ISNULL(CONVERT(DECIMAL(18,3),' + @Col1 + '),0) + ' +
'ISNULL(CONVERT(DECIMAL(18,3),' + @Col2 + '),0) + ' +
'ISNULL(CONVERT(DECIMAL(18,3),' + @Col3 + '),0)/ ' +
'(3 * ISNULL(CONVERT(DECIMAL(18,3),EvenInstalment),0))));'
exec (@SQLUpdateCmd);



Please NOTE, you will get a divide by zero error if EvenInstalment is null!

Edit: Or if it is zero.

Cool

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Christopher Stobbs
Christopher Stobbs
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1662 Visits: 2232
Hi raym,

Just got you internal message now.

I would also go with Lynn's answer on this one.

Sorry for the delay :-)

----------------------------------------------
Try to learn something about everything and everything about something. - Thomas Henry Huxley

w00t
Posting Best Practices
Numbers / Tally Tables

SQL-4-Life
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