Skip to content

Commit 9a169bc

Browse files
authored
Initial commit of fk_index_generator script
1 parent 7870ad4 commit 9a169bc

File tree

1 file changed

+53
-0
lines changed

1 file changed

+53
-0
lines changed

fk_index_generator.sql

+53
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,53 @@
1+
/**************************************************************************
2+
FK Index Generator
3+
Author: Eric Cobb - http://www.sqlnuggets.com/
4+
Source: https://github.com/ericcobb/FK-Index-Generator
5+
Supported Versions: SQL Server 2008, SQL Server 2012, SQL Server 2014, SQL Server 2016, SQL Server 2017
6+
License:
7+
MIT License
8+
9+
Copyright (c) 2017 Eric Cobb
10+
11+
Permission is hereby granted, free of charge, to any person obtaining a copy
12+
of this software and associated documentation files (the "Software"), to deal
13+
in the Software without restriction, including without limitation the rights
14+
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
15+
copies of the Software, and to permit persons to whom the Software is
16+
furnished to do so, subject to the following conditions:
17+
18+
The above copyright notice and this permission notice shall be included in all
19+
copies or substantial portions of the Software.
20+
21+
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
22+
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
23+
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
24+
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
25+
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
26+
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
27+
SOFTWARE.
28+
***************************************************************************/
29+
30+
SELECT [ParentSchema], [ParentTable], [ParentColumn],
31+
[Script] = 'CREATE NONCLUSTERED INDEX [IX_FK_'+[ParentTable]+'_'+[ParentColumn]+'] ON ['+[ParentSchema]+'].['+[ParentTable]+'] (['+[ParentColumn]+']);'
32+
--Gets a list of all FK Constraints
33+
FROM (SELECT [ParentObjectID] = fk.parent_object_id
34+
,[ParentSchema] = SCHEMA_NAME (fk.[schema_id])
35+
,[ParentTable] = t.[name]
36+
,[parent_column_id] = fkc.parent_column_id
37+
,[ParentColumn] = COL_NAME(fk.parent_object_id , fkc.parent_column_id)
38+
FROM sys.foreign_keys fk
39+
INNER JOIN sys.foreign_key_columns fkc ON fkc.constraint_object_id = fk.[object_id]
40+
INNER JOIN sys.tables t ON t.object_id = fk.parent_object_id) c
41+
--Gets a list of the first key column of all nonclustered indexes
42+
LEFT JOIN (SELECT [TableObjectID] = t.[object_id]
43+
,[IndexName] = i.[name]
44+
,[TableColumnID] = ic.column_id
45+
FROM sys.indexes i
46+
INNER JOIN sys.index_columns ic ON ic.object_id = i.object_id and ic.index_id = i.index_id
47+
INNER JOIN sys.tables t ON t.object_id = i.object_id
48+
INNER JOIN sys.columns col ON ic.object_id = col.object_id and ic.column_id = col.column_id
49+
WHERE i.[type] IN (1,2)
50+
AND OBJECTPROPERTY(i.OBJECT_ID,'IsUserTable') = 1
51+
AND ic.key_ordinal = 1) i ON i.[TableObjectID] = c.[ParentObjectID] AND i.[TableColumnID] = c.parent_column_id
52+
WHERE i.[IndexName] IS NULL --If NULL, an index beginning with the specified key column does not exist.
53+
ORDER BY [ParentSchema], [ParentTable], [ParentColumn];

0 commit comments

Comments
 (0)