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'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
EXECsp_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
EXECsp_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)