Commit 81b1f8fb authored by dwentzel's avatar dwentzel

adding Compare folder

parent b65c515f
IF OBJECT_ID('DBA_CompareDBData') IS NOT NULL
DROP PROCEDURE DBA_CompareDBData
GO
/*
quick notes:
compares "data" from a given set of "model data" tables...defined below
looks for row discrepancies by table key
issues:
exec DBA_CompareDBData 'MaxAppDB','Alleg'
*/
CREATE PROCEDURE DBA_CompareDBData
(
@NetNewDB SYSNAME
, @PortedDB SYSNAME
)
AS
BEGIN
SET NOCOUNT ON
DECLARE @SQL NVARCHAR(4000)
CREATE TABLE #TableDataToCompare
(SchemaName varchar(200)
,TableName varchar(200)
,KeyCols varchar(200)
,NetNewRowCnts int
,PortedRowCnts int
)
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('dbo','tblData','ID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('dbo','tblProperties','ID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('dbo','tblTemplates','ID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','AppFunction','AppFunctionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','AppFunctionGroup','AppFunctionGroupID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','AppFunctionXAppFunction','AppFunctionXAppFunctionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','AppFunctionXAppFunctionGroup','AppFunctionXAppFunctionGroupID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','AppUser','AppUserID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','CodeDefinition','CodeDefinitionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','CodeDisplay','CodeDefinitionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ContactType','ContactTypeID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','JournalType','JournalTypeID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','LicenseRole','LicenseRoleID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','NextId','ID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','PayrollCalculation','PayrollCalculationID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','Person','PersonID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','SecurityEntity','SecurityEntityID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','SecurityEntityXAppFunction','SecurityEntityXAppFunctionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','StateProvince','StateProvinceID')
--INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','SystemSetting','SystemSettingID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','UIEntityListConfiguration','UIEntityListConfigurationID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','UIListDetail','UIListDetailID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','UIListHeader','UIListHeaderID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','UIListHeaderXAppFunction','UIListHeaderXAppFunctionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','UnitOfMeasure','UnitOfMeasureID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','WitholdingStatusType','WitholdingStatusTypeID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ObjectField','ObjectFieldID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ObjectFieldXField','ObjectFieldXFieldID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ObjectParameter','ObjectParameterID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ObjectXObject','ObjectXObjectID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ObjectXObjectField','ObjectXObjectFieldID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ReportDefinitionXReportDefinition','ReportDefinitionXReportDefinitionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ReportObjectField','ReportObjectFieldID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ReportParameterDefinition','ReportParameterDefinitionID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ReportParameterDefinitionXObjectField','ReportParameterDefinitionXObjectFieldID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ReportParameterXParameter','ReportParameterXParameterID')
INSERT INTO #TableDataToCompare (Schemaname, TableName,KeyCols) VALUES ('MXW','ReportDefinition','ReportDefinitionID')
--compare rowcounts
declare @SchemaName varchar(2000), @TableName varchar(2000), @exec_str varchar(max), @keyCols varchar(2000), @SQL_str varchar(max)
declare cnts cursor for
select SchemaName, TableName FROM #TableDataToCompare
open cnts
fetch next from cnts into @SchemaName, @TableName
while @@fetch_status = 0
begin
select @exec_str = 'UPDATE #TableDataToCompare SET NetNewRowCnts = (SELECT count(*) FROM ' + @NetNewDB + '.' + @SchemaName + '.' + @TableName + ') WHERE SchemaName = ''' + @SchemaName + ''' AND TableName = ''' + @TableName + ''''
--select @exec_str
exec (@exec_str)
select @exec_str = 'UPDATE #TableDataToCompare SET PortedRowCnts = (SELECT count(*) FROM ' + @PortedDB + '.' + @SchemaName + '.' + @TableName + ') WHERE SchemaName = ''' + @SchemaName + ''' AND TableName = ''' + @TableName + ''''
--select @exec_str
exec (@exec_str)
fetch next from cnts into @SchemaName, @TableName
end
close cnts
deallocate cnts
if exists (select * from #TableDataToCompare where NetNewRowCnts <> PortedRowCnts)
BEGIN
PRINT 'RowCount differences for Master data'
select * from #TableDataToCompare where NetNewRowCnts <> PortedRowCnts
END
ELSE
BEGIN
PRINT 'Rowcounts match for Master data'
END
PRINT 'Checking row level data differences...'
DECLARE @bin_list VARCHAR(max)
--Data-level differences
declare datadiff cursor for
select SchemaName, TableName, KeyCols FROM #TableDataToCompare
open datadiff
fetch next from datadiff into @SchemaName, @TableName, @KeyCols
while @@fetch_status = 0
begin
select @bin_list = ''
SELECT @bin_list = COALESCE(@bin_list,'') + c.Name + ','
from sys.columns c
join sys.objects o
on c.object_id = o.object_id
where o.name = @TableName
and o.type = 'U'
and o.schema_id = schema_id (@SchemaName)
and c.name not in ('CreatedBy','CreatedDate','ModifiedBy','ModifiedDate')
SELECT @bin_list = left(@bin_list,len(@bin_list) - 1)
--SELECT 'Data Differences for ' + @TableName
SELECT @SQL_str = '
(select sum(binary_checksum(' + @bin_list +')) [CheckSum] , ' + @KeyCols +
' from ' + @NetNewDB + '.' + @SchemaName + '.' + @TableName +
' group by ' + @KeyCols +
' except ' +
'select sum(binary_checksum(' + @bin_list +')) [CheckSum] , ' + @KeyCols +
' from ' + @PortedDB + '.' + @SchemaName + '.' + @TableName +
' group by ' + @KeyCols +
')' +
'UNION ALL ' +
'(' +
'select sum(binary_checksum(' + @bin_list +')) [CheckSum] , ' + @KeyCols +
' from ' + @PortedDB + '.' + @SchemaName + '.' + @TableName +
' group by ' + @KeyCols +
' except ' +
'select sum(binary_checksum(' + @bin_list +')) [CheckSum] , ' + @KeyCols +
' from ' + @NetNewDB + '.' + @SchemaName + '.' + @TableName +
' group by ' + @KeyCols +
')'
SELECT @exec_str = 'if exists (' + @SQL_str +')
begin
PRINT ''Data Differences for ' + @TableName + ''''
+ ' PRINT ''Use the following query to determine data difference'' PRINT ''' + @SQL_str + ''''
+ @SQL_str + '
end
'
--PRINT @exec_str
EXEC( @exec_str)
fetch next from datadiff into @SchemaName, @TableName, @KeyCols
end
close datadiff
deallocate datadiff
drop table #TableDataToCompare
END
\ No newline at end of file
IF OBJECT_ID('DBA_CompareDBSchemas') IS NOT NULL
DROP PROCEDURE DBA_CompareDBSchemas
GO
/*
quick notes:
can be run in any database on the given server/instance
capture the output to a text file for examination later.
run as part of a continuous build loop...tests a ported db against a net new
we dont report on schema differences for objects ending like <name>_xxxxx , we assume
these are bug fixes for a customer where xxxxx is the bug number.
issues:
exec DBA_CompareDBSchemas 'Alleg','MaxDemoDB_ANNA'
*/
CREATE PROCEDURE DBA_CompareDBSchemas
(
@NetNewDB SYSNAME
, @PortedDB SYSNAME
)
AS
BEGIN
SET NOCOUNT ON
DECLARE @SQL NVARCHAR(4000)
SELECT 'Looking for Missing Schema Items between net new and ported'
SELECT @SQL = N'
(
SELECT name , ''Missing Object From ' + @NetNewDB + ''' Description ,type_desc as object_type from ' + @PortedDB + '.sys.objects WHERE type in (''FN'',''IF'',''F'',''U''/*,''UQ''*/,''D'',''P'',''PK'',''V'',''TR'',''TF'') and name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
EXCEPT
SELECT name , ''Missing Object From ' + @NetNewDB + ''' Description ,type_desc as object_type from ' + @NetNewDB + '.sys.objects WHERE type in (''FN'',''IF'',''F'',''U''/*,''UQ''*/,''D'',''P'',''PK'',''V'',''TR'',''TF'') and name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
)
UNION ALL
(
SELECT name , ''Missing Object From ' + @PortedDB+ ''' Description ,type_desc as object_type from ' + @NetNewDB + '.sys.objects WHERE type in (''FN'',''IF'',''F'',''U''/*,''UQ''*/,''D'',''P'',''PK'',''V'',''TR'',''TF'') and name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
EXCEPT
SELECT name , ''Missing Object From ' + @PortedDB + ''' Description ,type_desc as object_type from ' + @PortedDB + '.sys.objects WHERE type in (''FN'',''IF'',''F'',''U''/*,''UQ''*/,''D'',''P'',''PK'',''V'',''TR'',''TF'') and name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
)
'
--SELECT @SQL
EXEC sp_executesql @SQL
SELECT 'Looking for Missing columns between net new and ported'
SELECT @SQL = N'
(
SELECT o.name as objectname,c.name as colname, ''Missing Column From ' + @NetNewDB + ''' from ' + @PortedDB + '.sys.columns c join ' + @PortedDB + '.sys.objects o on c.object_id = o.object_id and o.type = ''U'' and o.name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
EXCEPT
SELECT o.name as objectname,c.name as colname,''Missing Column From ' + @NetNewDB + ''' from ' + @NetNewDB + '.sys.columns c join ' + @NetNewDB + '.sys.objects o on c.object_id = o.object_id and o.type = ''U'' and o.name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
)
UNION ALL
(
SELECT o.name as objectname,c.name as colname, ''Missing Column From ' + @PortedDB+ ''' from ' + @NetNewDB + '.sys.columns c join ' + @NetNewDB + '.sys.objects o on c.object_id = o.object_id and o.type = ''U'' and o.name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
EXCEPT
SELECT o.name as objectname,c.name as colname,''Missing Column From ' + @PortedDB + ''' from ' + @PortedDB + '.sys.columns c join ' + @PortedDB + '.sys.objects o on c.object_id = o.object_id and o.type = ''U'' and o.name not like ''%_[0-9][0-9][0-9][0-9][0-9]''
)
'
--SELECT @SQL
EXEC sp_executesql @SQL
SELECT 'Looking for Index Discrepancies:'
SELECT @SQL = N'
(
select obj.name as TableName
,ind.name as IndexName
,ind.type_desc as Clustering
,col.name as ColName
,keys.keyno as ColPosition
,''Missing From DB: ' + @PortedDB + ''' AS Descr
from ' + @NetNewDB + '.sys.objects obj
join ' + @NetNewDB + '.sys.indexes ind on obj.object_id = ind.object_id
join ' + @NetNewDB + '.sys.columns col on obj.object_id = col.object_id
join ' + @NetNewDB + '.sys.sysindexkeys keys on (keys.id = col.object_id AND keys.colid = col.column_id) AND (ind.object_id = keys.id AND ind.index_id = keys.indid)
EXCEPT
select obj.name as TableName
,ind.name as IndexName
,ind.type_desc as Clustering
,col.name as ColName
,keys.keyno as ColPosition
,''Missing From DB: ' + @PortedDB + ''' AS Descr
from ' + @PortedDB + '.sys.objects obj
join ' + @PortedDB + '.sys.indexes ind on obj.object_id = ind.object_id
join ' + @PortedDB + '.sys.columns col on obj.object_id = col.object_id
join ' + @PortedDB + '.sys.sysindexkeys keys on (keys.id = col.object_id AND keys.colid = col.column_id) AND (ind.object_id = keys.id AND ind.index_id = keys.indid)
)
UNION ALL
(
select obj.name as TableName
,ind.name as IndexName
,ind.type_desc as Clustering
,col.name as ColName
,keys.keyno as ColPosition
,''Missing From DB: ' + @NetNewDB + ''' AS Descr
from ' + @PortedDB + '.sys.objects obj
join ' + @PortedDB + '.sys.indexes ind on obj.object_id = ind.object_id
join ' + @PortedDB + '.sys.columns col on obj.object_id = col.object_id
join ' + @PortedDB + '.sys.sysindexkeys keys on (keys.id = col.object_id AND keys.colid = col.column_id) AND (ind.object_id = keys.id AND ind.index_id = keys.indid)
EXCEPT
select obj.name as TableName
,ind.name as IndexName
,ind.type_desc as Clustering
,col.name as ColName
,keys.keyno as ColPosition
,''Missing From DB: ' + @NetNewDB + ''' AS Descr
from ' + @NetNewDB + '.sys.objects obj
join ' + @NetNewDB + '.sys.indexes ind on obj.object_id = ind.object_id
join ' + @NetNewDB + '.sys.columns col on obj.object_id = col.object_id
join ' + @NetNewDB + '.sys.sysindexkeys keys on (keys.id = col.object_id AND keys.colid = col.column_id) AND (ind.object_id = keys.id AND ind.index_id = keys.indid)
)
ORDER BY TableName, IndexName, ColPosition'
EXEC sp_executesql @SQL
END
\ No newline at end of file
'GenerateDiscrepancyReport.vbs
'compares two databases for differences (net new vs ported)
Const ForReading = 1, ForWriting = 2, ForAppending = 8
quote = """"
set oFso = CreateObject("Scripting.FileSystemObject")
'if we don't pass the params from the command line then lets prompt the user for the variables
'read arguments
Dim iArg, args
Set args = Wscript.Arguments
If args.count = 0 Then
'if we don't pass the params from the command line then lets prompt the user for the variables
msgbox "Arguments not found on the command line...will prompt for values."
server_instancename = inputbox("Enter Server and (if necessary) instance name for the SQL Server","Maxwell DB Installer","dwentzellp\procontractormx")
user_name = inputbox("sa (or equivalent) account. Leave blank to use NT authentication","Maxwell DB Installer","sa")
pwd = inputbox ("sa or equivalent password. Leave blank to use NT authentication","Maxwell DB Installer","Password01")
Logs_folder = inputbox("Folder for output logs (check this folder after the port completes for any errors","Maxwell DB Installer","c:\scripts\logs")
netnew_db = inputbox("Enter first db name to compare (netnew).","Maxwell DB Installer","demo")
ported_db = inputbox("Enter first db name to compare (ported).","Maxwell DB Installer","maxdemodb")
elseIf args.count > 1 Then
if args.count <> 6 then
msgbox "Wrong number of args passed in. Usage: cscript setup.vbs [server_instancename] [db_name] [user_name] [Logs_folder] [Language] [Version]"
wscript.quit 1
end if
'parse out the args
For iArg = 0 To args.count -1
server_instancename = args(0)
user_name = args(1)
pwd = args(2)
Logs_folder = args(3)
netnew_db = args(4)
ported_db = args(5)
Next
end if
'additional env setup
'get the path to the script file
sPath = WScript.ScriptFullName
sPath = Left(sPath,Len(sPath)-Len(WScript.Scriptname))
GeneratePath (Logs_Folder)
DiscrepLogFile = Logs_folder & "\discrepancies_between_" & netnew_db & "_and_" & ported_db & ".log"
if (oFSO.FileExists(DiscrepLogFile)) Then
oFSO.DeleteFile DiscrepLogFile,TRUE
End if
'run the process
Call SetEnvVar
Call SchemaCompare
Call DataCompare
'garbage collection
set oFSO = nothing
Public Sub SetEnvVar
'for CIT, set an env variable so we can automate looking at the error logs further
set shell = CreateObject("wscript.shell")
set sysEnv = shell.Environment("SYSTEM")
sysEnv("DiscrepLogFile") = DiscrepLogFile
End Sub
Public Function DetermineAuthentication
'determines whether we should use integrated or sql auth when connecting with OSQL
If user_name = "" and pwd = "" then
DetermineAuthentication = "NT"
Else
DetermineAuthentication = "SQL"
End if
End Function
Public Function GeneratePath(FolderPath)
GeneratePath = False
If Not oFso.FolderExists(FolderPath) Then
If GeneratePath(oFso.GetParentFolderName(FolderPath)) Then
GeneratePath = True
Call oFso.CreateFolder(FolderPath)
End If
Else
GeneratePath = True
End If
End Function
Public Sub OSQLforProcedure (CmdString,LgFile,dbcontext)
'calls osql for a stored procedure
'logs output using >> (appends to existing LgFile
strQuery = quote & CmdString & quote
If DetermineAuthentication() = "SQL" Then
strCommand = "cmd /C " & quote & quote & sPath & "osql" & quote & " -S" & quote & server_instancename & quote & " -n -w300 -d" & quote & dbcontext & quote & " -U" & quote & user_name & quote & " -P" & quote & pwd & quote & " -Q" & strQuery & " >>" & quote & LgFile & quote & quote
else
strCommand = "cmd /C " & quote & quote & sPath & "osql" & quote & " -S" & quote & server_instancename & quote & " -n -w300 -d" & quote & dbcontext & quote & " -E" & " -Q" & strQuery & " >>" & quote & LgFile & quote & quote
end if
Set shell = WScript.CreateObject ("WSCript.shell")
shell.run strCommand,,TRUE
set Shell = Nothing
End Sub
Public Sub SchemaCompare
'run the osql cmd and output to logs folder.
strQuery = "EXEC DBA_CompareDBSchemas '" & netnew_db & "','" & ported_db & "'"
Call OSQLforProcedure (strQuery,DiscrepLogFile,netnew_db)
End Sub
Public Sub DataCompare
'run the osql cmd and output to logs folder.
strQuery = "EXEC DBA_CompareDBData '" & netnew_db & "','" & ported_db & "'"
Call OSQLforProcedure (strQuery,DiscrepLogFile,netnew_db)
End Sub
......@@ -5,4 +5,8 @@ DBA-in-a-Box : this is a process I've been using since SQL 6.5 that will quickl
hygiene processes when I don't have a dedicated DBA available to me.
MyOldCITProcess : This is an example continuous integration process that I used years ago to automate database
build testing. http://www.davewentzel.com/content/doing-database-cit-tfs
\ No newline at end of file
build testing. http://www.davewentzel.com/content/doing-database-cit-tfs
Compare : various scripts that aid in comparing db schemas and seed/master/system/lookup table data
between two databases. This is part of any good database build/deploy/CIT system.
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment