-
Notifications
You must be signed in to change notification settings - Fork 2
/
sqlserver2022-tsql-stats-auto_drop.sql
131 lines (72 loc) · 2.95 KB
/
sqlserver2022-tsql-stats-auto_drop.sql
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
/*
SQL Server 2022
- STATS - AUTO_DROP
https://www.kursysql.pl
*/
USE AdventureWorks2019
-- Statistics for Sales.CreditCard table
/*
Index statistics (created automatically)
*/
SELECT * FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
CREATE INDEX IX_CreditCard_ExpMonth ON Sales.CreditCard (ExpMonth)
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
-- ExpMonth tinyint -> int
-- !!! Msg 5074, Level 16, State 1, Line 28
-- The index 'IX_CreditCard_ExpMonth' is dependent on column 'ExpMonth'.
-- !!! Msg 4922, Level 16, State 9, Line 28
-- ALTER TABLE ALTER COLUMN ExpMonth failed because one or more objects access this column.
ALTER TABLE Sales.CreditCard
ALTER COLUMN ExpMonth int
DROP INDEX IX_CreditCard_ExpMonth ON Sales.CreditCard
ALTER TABLE Sales.CreditCard
ALTER COLUMN ExpMonth int
-- Cleanup
ALTER TABLE Sales.CreditCard ALTER COLUMN ExpMonth tinyint
/*
Column statistics (created automatically)
*/
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
SELECT * FROM Sales.CreditCard WHERE ExpMonth = '10'
-- auto_drop = 1
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
ALTER TABLE Sales.CreditCard
ALTER COLUMN ExpMonth int
-- Cleanup
ALTER TABLE Sales.CreditCard ALTER COLUMN ExpMonth tinyint
/*
Column statistics (created by user)
*/
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
CREATE STATISTICS stat_Sales_CreditCard
ON Sales.CreditCard (ExpMonth)
-- ExpMonth tinyint -> int
-- !!! Msg 5074, Level 16, State 1, Line 89
-- The statistics 'stat_Sales_CreditCard' is dependent on column 'ExpMonth'.
-- !!! Msg 4922, Level 16, State 9, Line 89
-- ALTER TABLE ALTER COLUMN ExpMonth failed because one or more objects access this column.
ALTER TABLE Sales.CreditCard
ALTER COLUMN ExpMonth int
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
-- SQL Server 2022
UPDATE STATISTICS Sales.CreditCard stat_Sales_CreditCard WITH AUTO_DROP = ON
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
ALTER TABLE Sales.CreditCard
ALTER COLUMN ExpMonth int
ALTER TABLE Sales.CreditCard ALTER COLUMN ExpMonth tinyint
-- SQL Server 2022
CREATE STATISTICS stat_Sales_CreditCard
ON Sales.CreditCard (ExpMonth) WITH AUTO_DROP = ON
SELECT object_id, name, stats_id, auto_created, user_created, auto_drop FROM sys.stats
WHERE object_id = object_id('Sales.CreditCard')
-- Cleanup
ALTER TABLE Sales.CreditCard ALTER COLUMN ExpMonth tinyint
DROP STATISTICS Sales.CreditCard.stat_Sales_CreditCard