March 3, 2009 at 12:56 pm
Hi,
I am trying to create a script that will compare the indexes in two different databases.
I am trying to write a query that will show me indexes that exist in either one db or the other OR that differ in terms of name or column list.
I know how to find indexes that exist in both dbs or that exist in one and not the other. So I could do a union but I am certain there must be a way to write this query (that I am unaware of) so that I only need to make one pass through the data.
I am on SS2005 and both dbs are on the same machine. I believe anyone should be able to run this since it is using system views.
Here is what I have (that is not returning the differences only):
SELECT A.table_name, B.table_name, A.index_name, B.index_name, A.index_cols, B.index_cols
FROM
(
SELECT obj.name as table_name,
idx.name AS index_name,
dbo.fun_index_collist(idx.object_id, idx.index_id) AS index_cols
FROM [DB1].sys.indexes idx JOIN [DB1].sys.objects obj
ON idx.object_id =obj.object_id
) as A
FULL OUTER JOIN
(
SELECT obj.name as table_name,
idx.name AS index_name,
dbo.fun_index_collist(idx.object_id, idx.index_id) AS index_cols
FROM [DB2].sys.indexes idx JOIN [DB2].sys.objects obj
ON idx.object_id =obj.object_id
) as B
ON A.table_name = B.table_name
WHERE
A.table_name is null or B.table_name is null or
(A.table_name is not null or B.table_name is not null and
(
(A.index_name <> B.index_name) or
(A.index_cols <> B.index_cols)
)
)
Thanks for helping! I will continue banging my head against the proverbial wall.
March 4, 2009 at 7:29 am
I'm not sure if this does what you want exactly but you could use the EXCEPT operator.
Something like this (I couldn't complete test it because I don't have dbo.fun_index_collist), but I think it does what you want otherwise) :
(
SELECT obj.name as table_name,
idx.name AS index_name,
dbo.fun_index_collist(idx.object_id, idx.index_id) AS index_cols
FROM [DB1].sys.indexes idx JOIN [DB1].sys.objects obj
ON idx.object_id =obj.object_id
)
EXCEPT
(
SELECT obj.name as table_name,
idx.name AS index_name,
dbo.fun_index_collist(idx.object_id, idx.index_id) AS index_cols
FROM [DB2].sys.indexes idx JOIN [DB2].sys.objects obj
ON idx.object_id =obj.object_id
)
UNION
(
SELECT obj.name as table_name,
idx.name AS index_name,
dbo.fun_index_collist(idx.object_id, idx.index_id) AS index_cols
FROM [DB2].sys.indexes idx JOIN [DB2].sys.objects obj
ON idx.object_id =obj.object_id
)
EXCEPT
(
SELECT obj.name as table_name,
idx.name AS index_name,
dbo.fun_index_collist(idx.object_id, idx.index_id) AS index_cols
FROM [DB1].sys.indexes idx JOIN [DB1].sys.objects obj
ON idx.object_id =obj.object_id
)
You could also use one of the database compariason products out there, like RedGate SQLCompare or APEXSQLDiff.
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
March 12, 2009 at 9:57 am
Jack,
Thank you for your response. Sorry for the delay (got pulled onto something else for a couple of days). I am using your solution. It works just as I need.
Viewing 3 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy