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


Update in all table


Update in all table

Author
Message
kapil_kk
kapil_kk
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3095 Visits: 2766
I have written an update statement which is updating some fields like this--

update L
set L.UpdateBy = E.UserID,
L.CreatedByID = E.UserID
from EmployeeProfile E
inner join LocationMaster L on E.EmployeeID=L.UpdateBy

As it will only updating in LocationMaster table.
I want to update all the tables that has columns(UpdateBy,CreatedByID).
Is it possible?

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Lowell
Lowell
One Orange Chip
One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)

Group: General Forum Members
Points: 28323 Visits: 39955
you could build the queries you want to execute for all tables meeting your criteria.

if the table has a value in the UpdateBy column, are you trying to set the CreatedByID tot eh same value?
what is the purpose of joining to the Employee table if the data is already in the target table anyway? if the data is blank in LocationMaster, your update will leave those rows null still.

Anyway, as far as building the query goes,
my example below below builds the same SQL statement you demoed for every table that has both a UpdateBy column and a CreatedByID column.
is that what you want?
it's a little wierd to want to blindly update like that...since the data is already there!




SELECT
'
update L
set L.UpdateBy = E.UserID,
L.CreatedByID = E.UserID
from EmployeeProfile E
inner join ' + OBJECT_NAME(T1.object_id) + ' L on E.EmployeeID=L.UpdateBy
' AS cmd
FROM sys.columns T1
INNER JOIN sys.columns T2
ON T1.object_id = T2.object_id
WHERE T1.name = 'UpdateBy'
AND T2.name = 'CreatedByID'




edit
is this what you are really trying to do?

update LocationMaster
set UpdateBy = CreatedByID
WHERE CreatedByID IS NOT NULL
--AND UpdateBy IS NULL --?? only where it's currently blank/null?



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!

EamonSQL
EamonSQL
SSC Veteran
SSC Veteran (208 reputation)SSC Veteran (208 reputation)SSC Veteran (208 reputation)SSC Veteran (208 reputation)SSC Veteran (208 reputation)SSC Veteran (208 reputation)SSC Veteran (208 reputation)SSC Veteran (208 reputation)

Group: General Forum Members
Points: 208 Visits: 181
the MERGE statement might help you there but I would create separate update statements and run as a single transaction. Also use nested if statements so that if one update fails everything gets rolled back.

make sense?

Eamon
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