February 7, 2014 at 7:51 am
Hello all, greetings from a cold-winter Sweden.
I have a problem that i need help with, tried to seach the forum posts but got too many hits.
A customer has messed up while moving their databases.
After working for a week they found that data is missing in the database.
I have two backups, one from the old server and one from the new server today, they have been working in the new one for a week.
I need to compare these two databases and then update the new database with all data that is in the old one but not in the new database.
Join the data in the two databases so to say.
Both databases are from the same application so they use the same users, schema and so on.
Any ideas on how to do this in the best way?
February 7, 2014 at 8:19 am
stefan 97267 (2/7/2014)
Hello all, greetings from a cold-winter Sweden.I have a problem that i need help with, tried to seach the forum posts but got too many hits.
A customer has messed up while moving their databases.
After working for a week they found that data is missing in the database.
I have two backups, one from the old server and one from the new server today, they have been working in the new one for a week.
I need to compare these two databases and then update the new database with all data that is in the old one but not in the new database.
Join the data in the two databases so to say.
Both databases are from the same application so they use the same users, schema and so on.
Any ideas on how to do this in the best way?
restore the old database on the server with a differnet name, ie PRODUCTIONCopy
then you can compare tables between the two databases pretty easily: the INTERSECT and EXCEPT operators can help a lot with that:
--items in copy that don't exist in production
SELECT SpecificColumns FROM PRODUCTIONCopy.dbo.Invoices
EXCEPT
SELECT SpecificColumns FROM PRODUCTION.dbo.Invoices
--items in production that don't exist in the copy
SELECT SpecificColumns FROM PRODUCTION.dbo.Invoices
EXCEPT
SELECT SpecificColumns FROM PRODUCTIONCopy.dbo.Invoices
then you can insert or update from the two as needed
SELECT * FROM PRODUCTIONCopy.dbo.Invoices
Lowell
February 9, 2014 at 11:00 am
Perfect, thank you.
But (there always is one)
The database has many tables,if i want to compare and insert on the schema level not table by table, is that possible?
February 9, 2014 at 11:16 am
stefan 97267 (2/9/2014)
Perfect, thank you.But (there always is one)
The database has many tables,if i want to compare and insert on the schema level not table by table, is that possible?
No, it would need to be done table by table.
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
February 9, 2014 at 7:01 pm
Red-Gate has a product for comparing such data called "Data Compare". For things like this, it's worth the investment. Red-Gate also makes some other very useful tools. You can get many of the tools along with "Data Compare" or buy data compare separately. And, no... I'm not a Red-Gate employee. I just happen to like their tools.
http://www.red-gate.com/products/sql-development/sql-data-compare/
--Jeff Moden
Change is inevitable... Change for the better is not.
February 10, 2014 at 7:38 am
You can make a procedure obtain tables name for sys.objects like this
select a.id, a.name
from sysobjects a
where xtype = 'u'
Then build a cursor and compare each table, fill results in temp tables
February 10, 2014 at 8:12 am
If there are many tables use this script:
DECLARE @sql varchar(max),
@Database1 varchar(50),
@Database2 varchar(50),
@TableName varchar(50)
SET @Database1 = 'Production'
SET @Database2 = 'ProductionCopy'
DECLARE TableNameCursor CURSOR
FOR
select a.name
from sysobjects a
where xtype = 'u'
order by a.name;
OPEN TableNameCursor
FETCH NEXT
FROM TableNameCursor
INTO @TableName
WHILE @@FETCH_STATUS = 0
BEGIN
print '---' + @TableName
SET @sql = 'INSERT INTO #Go'+@TableName+'
SELECT * FROM '+ @Database1 +'..'+ @TableName+'
EXCEPT
SELECT * FROM '+ @Database2 +'..'+ @TableName
EXEC(@sql)
SET @sql = 'INSERT INTO #Back'+@TableName+'
SELECT * FROM '+ @Database2 +'..'+ @TableName+'
EXCEPT
SELECT * FROM '+ @Database1 +'..'+ @TableName
EXEC(@sql)
FETCH NEXT
FROM TableNameCursor
INTO @TableName
END;
CLOSE TableNameCursor;
DEALLOCATE TableNameCursor;
Then only you must to SELECT the temp tables for each table
I hope you have served
February 10, 2014 at 12:23 pm
Great answers, thank you all very much.
Will test and report back.
February 11, 2014 at 5:49 am
+1 for Redgate. They are really helpful and the products are really useful. i especially like the source code control plug in for mgm studio and the SQL compare for generating migration scripts
If they would only add an SSIS / SSRS documenter solution it would be perfect.
Aaron
February 11, 2014 at 7:43 am
aaron.reese (2/11/2014)
If they would only add an SSIS / SSRS documenter solution it would be perfect.Aaron
PragmaticWorks have a BIDocumenter product that may meet your needs. Disclaimer: I don't work for PragmaticWorks.
Regards
Lempster
February 12, 2014 at 12:33 pm
They do, and its OK but like the RedGate packages, its a bit expensive on its own and I have not been able to get buy-in where I am to invest in PW's other offerings.
March 13, 2016 at 6:26 pm
March 13, 2016 at 10:04 pm
davros30 (3/13/2016)
SQLC is another good tool that will meet your needs. RedGate is also a very good tool but it is expensive.
So how much is "very affordable"?
--Jeff Moden
Change is inevitable... Change for the better is not.
March 14, 2016 at 5:20 am
Jeff Moden (3/13/2016)
davros30 (3/13/2016)
SQLC is another good tool that will meet your needs. RedGate is also a very good tool but it is expensive.So how much is "very affordable"?
I haven't downloaded it or tested it yet, but $18 dollars is inexpensive in my book; I've spent that much on a decent dinner. I'll play with it and report what i think.
Lowell
March 15, 2016 at 10:37 am
Lowell (3/14/2016)
I haven't downloaded it or tested it yet, but $18 dollars is inexpensive in my book; I've spent that much on a decent dinner. ...
I've spent more than that on dinners that weren't that decent. :sick:
-----
[font="Arial"]Knowledge is of two kinds. We know a subject ourselves or we know where we can find information upon it. --Samuel Johnson[/font]
Viewing 15 posts - 1 through 15 (of 15 total)
You must be logged in to reply to this topic. Login to reply