mssql_script

SQL 維護Script

SQL Server Script

PowerShell+SMO

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
$server = "ServerName"
$srcDB = "DBName"
$dump = "path folder"

# Stop on any error
$ErrorActionPreference = "stop"

[void] [System.Reflection.Assembly]::LoadWithPartialName('Microsoft.SqlServer.SMO')
[void] [System.Reflection.Assembly]::LoadWithPartialName('Microsoft.SQlServer.SMOExtended')
$xfer = [Microsoft.SqlServer.Management.SMO.Transfer] ([Microsoft.SqlServer.Management.SMO.Server] $server).Databases[$srcDB]

# Set export options.
$opts = New-Object Microsoft.SqlServer.Management.SMO.ScriptingOptions
$opts.Filename = $dump
$opts.ToFileOnly = $true
$opts.AllowSystemObjects = $false
$opts.Statistics = $false
$opts.ScriptDataCompression = $true
$opts.DRIAll = $true

##table / index
$opts.ClusteredIndexes = $true
$opts.NonClusteredIndexes = $true
$opts.Indexes = $true

##trigger
$opts.Triggers = $true

##grant
$opts.Permissions = $true
$opts.PrimaryObject = $true

$xfer.options = $opts
$xfer.ScriptTransfer()

查SMO可用的參數

1
2
3
#PowerShell環境執行
$options = New-DbaScriptingOption
$options | Get-Member

DBATools/Script

DBATools

1
2
3
4
5
6
7
1.官網: https://dbatools.io/
2.戴入方式 :
Import-Module f:\tools\dbatools.library
Import-Module f:\tools\dbatools

Set-DbatoolsConfig -FullName sql.connection.trustcert -Value $true -Register
Set-DbatoolsConfig -FullName sql.connection.encrypt -Value $false -Register

Server Role

1
Export-DbaServerRole -SqlInstance "ServerName" -ExcludeFixedRole -Path d:\tmp\5 -Append

DB Role

1
Export-DbaDbRole -SqlInstance "ServerName" -Database DB1 -ExcludeFixedRole -IncludeRoleMember -Path d:\tmp\

User&Grant

1
Export-DbaUser -SqlInstance "ServerName" -Database DB1 -Path d:\tmp\5 #-Append

Table

1
Get-DbaDbTable -SqlInstance "ServerName" -Database DB1 | Export-DbaScript -FilePath "d:\tmp\db_tables.sql" -Append

View

1
Get-DbaDbView -SqlInstance "ServerName" -Database DB1 -ExcludeSystemView | Export-DbaScript -FilePath "d:\tmp\db_view.sql"  -Append

StoredProcedures

1
Get-DbaDbStoredProcedure  -SqlInstance "ServerName" -Database DB1  -ExcludeSystemSp | Export-DbaScript -FilePath "d:\tmp\db_sp.sql" -Append

Triggers

1
Get-DbaDbObjectTrigger -SqlInstance "ServerName" -Database DB1 | Export-DbaScript -FilePath "d:\tmp\db_trigger.sql" -Append

Function

1
2
3
4
5
6
with functions(routine_name) as 
(SELECT ROUTINE_NAME FROM information_schema.routines WHERE routine_type = 'FUNCTION')
select
OBJECT_DEFINITION(OBJECT_ID(routine_name)) AS [Object Definition]
from
functions

Index

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
SELECT ' CREATE ' +
CASE
WHEN I.is_unique = 1 THEN ' UNIQUE '
ELSE ''
END +
I.type_desc COLLATE DATABASE_DEFAULT + ' INDEX ' +
'[' + I.name+ ']' + ' ON ' +
SCHEMA_NAME(T.schema_id) + '.' + T.name + ' ( ' +
KeyColumns + ' ) ' +
ISNULL(' INCLUDE (' + IncludedColumns + ' ) ', '') +
ISNULL(' WHERE ' + I.filter_definition, '') + ' WITH ( ' +
CASE
WHEN I.is_padded = 1 THEN ' PAD_INDEX = ON '
ELSE ' PAD_INDEX = OFF '
END + ',' +
'FILLFACTOR = ' + CONVERT(
CHAR(5),
CASE
WHEN I.fill_factor = 0 THEN 100
ELSE I.fill_factor
END
) + ',' +
-- default value
'SORT_IN_TEMPDB = OFF ' + ',' +
CASE
WHEN I.ignore_dup_key = 1 THEN ' IGNORE_DUP_KEY = ON '
ELSE ' IGNORE_DUP_KEY = OFF '
END + ',' +
CASE
WHEN ST.no_recompute = 0 THEN ' STATISTICS_NORECOMPUTE = OFF '
ELSE ' STATISTICS_NORECOMPUTE = ON '
END + ',' +
' ONLINE = OFF ' + ',' +
CASE
WHEN I.allow_row_locks = 1 THEN ' ALLOW_ROW_LOCKS = ON '
ELSE ' ALLOW_ROW_LOCKS = OFF '
END + ',' +
CASE
WHEN I.allow_page_locks = 1 THEN ' ALLOW_PAGE_LOCKS = ON '
ELSE ' ALLOW_PAGE_LOCKS = OFF '
END + ' ) ON [' +
DS.name + ' ] ' + CHAR(13) + CHAR(10) + ' GO' [CreateIndexScript]
FROM sys.indexes I
JOIN sys.tables T
ON T.object_id = I.object_id
JOIN sys.sysindexes SI
ON I.object_id = SI.id
AND I.index_id = SI.indid
JOIN (
SELECT *
FROM (
SELECT IC2.object_id,
IC2.index_id,
STUFF(
(
SELECT ' , ' + C.name + CASE
WHEN MAX(CONVERT(INT, IC1.is_descending_key))
= 1 THEN
' DESC '
ELSE
' ASC '
END
FROM sys.index_columns IC1
JOIN sys.columns C
ON C.object_id = IC1.object_id
AND C.column_id = IC1.column_id
AND IC1.is_included_column =
0
WHERE IC1.object_id = IC2.object_id
AND IC1.index_id = IC2.index_id
GROUP BY
IC1.object_id,
C.name,
index_id
ORDER BY
MAX(IC1.key_ordinal)
FOR XML PATH('')
),
1,
2,
''
) KeyColumns
FROM sys.index_columns IC2
--WHERE IC2.Object_id = object_id('Person.Address') --Comment for all tables
GROUP BY
IC2.object_id,
IC2.index_id
) tmp3
)tmp4
ON I.object_id = tmp4.object_id
AND I.Index_id = tmp4.index_id
JOIN sys.stats ST
ON ST.object_id = I.object_id
AND ST.stats_id = I.index_id
JOIN sys.data_spaces DS
ON I.data_space_id = DS.data_space_id
JOIN sys.filegroups FG
ON I.data_space_id = FG.data_space_id
LEFT JOIN (
SELECT *
FROM (
SELECT IC2.object_id,
IC2.index_id,
STUFF(
(
SELECT ' , ' + C.name
FROM sys.index_columns IC1
JOIN sys.columns C
ON C.object_id = IC1.object_id
AND C.column_id = IC1.column_id
AND IC1.is_included_column =
1
WHERE IC1.object_id = IC2.object_id
AND IC1.index_id = IC2.index_id
GROUP BY
IC1.object_id,
C.name,
index_id
FOR XML PATH('')
),
1,
2,
''
) IncludedColumns
FROM sys.index_columns IC2
--WHERE IC2.Object_id = object_id('Person.Address') --Comment for all tables
GROUP BY
IC2.object_id,
IC2.index_id
) tmp1
WHERE IncludedColumns IS NOT NULL
) tmp2
ON tmp2.object_id = I.object_id
AND tmp2.index_id = I.index_id
WHERE I.is_primary_key = 0
AND I.is_unique_constraint = 0
--AND I.Object_id = object_id('Person.Address') --Comment for all tables
--AND I.name = 'IX_Address_PostalCode' --comment for all indexes

Agent Job

1
Get-DbaAgentJob -SqlInstance "ServerName" | Export-DbaScript -FilePath "d:\tmp\AgentJob.sql" -Append