You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
@@ -147,7 +148,7 @@ If an exception occurs in the user function when processing changes then the bat
147
148
148
149
If the function execution fails 5timesin a row for a given row then that row is completely ignored for all future changes. Because the rows in a batch are not deterministic, rows in a failed batch may end up in different batches in subsequent invocations. This means that not all rows in the failed batch will necessarily be ignored. If other rows in the batch were the ones causing the exception, the "good" rows may end up in a different batch that doesn't fail in future invocations.
149
150
150
-
You can run this query to see what rows have failed 5 times and are currently ignored, see [Leases table](#az_funcleases_) documentation for how to get the correct Leases table to query for your function.
151
+
You can run this query to see what rows have failed 5 times and are currently ignored, see [Leases table](./TriggerBinding.md#az_funcleases_) documentation for how to get the correct Leases table to query for your function.
151
152
152
153
```sql
153
154
SELECT * FROM [az_func].[Leases_<FunctionId>_<TableId>] WHERE _az_func_AttemptCount = 5
@@ -168,3 +169,101 @@ e.g.
168
169
```sql
169
170
UPDATE [Products].[az_func].[Leases_<FunctionId>_<TableId>] SET _az_func_AttemptCount = 0 WHERE ProductId = 123
170
171
```
172
+
173
+
#### Lease Tables clean up
174
+
175
+
Before clean up, please see [Leases table](./TriggerBinding.md#az_funcleases_) documentation for understanding how they are created and used.
176
+
177
+
Why clean up?
178
+
1. You renamed your function/class/method name, which causes a new lease table to be created and the old one to be obsolete.
179
+
2. You created a trigger function that you no longer need and wish to clean up its associated data.
180
+
3. You want to reset your environment.
181
+
The Azure SQL Trigger does not currently handle automatically cleaning up any leftover objects, and so we have provided the below scripts to help guide you through doing that.
182
+
183
+
- Delete all the lease tables that haven't been accessed in`@CleanupAgeDays` days:
184
+
185
+
```sql
186
+
-- Deletes all the lease tables that haven't been accessed in @CleanupAgeDays days (set below)
187
+
-- and removes them from the GlobalState table.
188
+
USE [<Insert DATABASE name here>]
189
+
GO
190
+
DECLARE @TableName NVARCHAR(MAX);
191
+
DECLARE @UserFunctionId char(16);
192
+
DECLARE @UserTableId int;
193
+
DECLARE @CleanupAgeDays int = <Insert desired cleanup age in days here>;
194
+
DECLARE LeaseTable_Cursor CURSOR FOR
195
+
196
+
SELECT 'az_func.Leases_'+UserFunctionId+'_'+convert(varchar(100),UserTableID) as TABLE_NAME, UserFunctionID, UserTableID
197
+
FROM az_func.GlobalState
198
+
WHERE DATEDIFF(day, LastAccessTime, GETDATE()) > @CleanupAgeDays
199
+
200
+
OPEN LeaseTable_Cursor;
201
+
202
+
FETCH NEXT FROM LeaseTable_Cursor INTO @TableName, @UserFunctionId, @UserTableId;
203
+
204
+
WHILE @@FETCH_STATUS = 0
205
+
BEGIN
206
+
PRINT N'Dropping table ' + @TableName;
207
+
EXEC ('DROP TABLE IF EXISTS ' + @TableName);
208
+
PRINT 'Removing row from GlobalState for UserFunctionID = ' + RTRIM(CAST(@UserFunctionId AS NVARCHAR(30))) + ' and UserTableID = ' + RTRIM(CAST(@UserTableId AS NVARCHAR(30)));
209
+
DELETE FROM az_func.GlobalState WHERE UserFunctionID = @UserFunctionId and UserTableID = @UserTableId
210
+
FETCH NEXT FROM LeaseTable_Cursor INTO @TableName, @UserFunctionId, @UserTableId;
211
+
END;
212
+
213
+
CLOSE LeaseTable_Cursor;
214
+
215
+
DEALLOCATE LeaseTable_Cursor;
216
+
```
217
+
218
+
- Clean up a specific lease table:
219
+
220
+
To find the name of the lease table associated with your function, look in the log output for a line such as this which is emitted when the trigger is started.
This log message is at the `Information` level, so make sure your log level is set correctly.
225
+
226
+
```sql
227
+
-- Deletes the specified lease table and removes it from GlobalState table.
228
+
USE [<Insert DATABASE name here>]
229
+
GO
230
+
DECLARE @TableName NVARCHAR(MAX) = <Insert lease table name here>; -- e.g. '[az_func].[Leases_84d975fca0f7441a_901578250]
231
+
DECLARE @UserFunctionId char(16) = <Insert function ID here>; -- e.g. '84d975fca0f7441a' the first section of the lease table name [Leases_84d975fca0f7441a_901578250].
232
+
DECLARE @UserTableId int = <Insert table ID here>; -- e.g. '901578250' the second section of the lease table name [Leases_84d975fca0f7441a_901578250].
233
+
PRINT N'Dropping table ' + @TableName;
234
+
EXEC ('DROP TABLE IF EXISTS ' + @TableName);
235
+
PRINT 'Removing row from GlobalState for UserFunctionID = ' + RTRIM(CAST(@UserFunctionId AS NVARCHAR(30))) + ' and UserTableID = ' + RTRIM(CAST(@UserTableId AS NVARCHAR(30)));
236
+
DELETE FROM az_func.GlobalState WHERE UserFunctionID = @UserFunctionId and UserTableID = @UserTableId
237
+
```
238
+
239
+
- Clear all trigger related data for a reset:
240
+
241
+
```sql
242
+
-- Deletes all the lease tables and clears them from the GlobalState table.
243
+
USE [<Insert DATABASE name here>]
244
+
GO
245
+
DECLARE @TableName NVARCHAR(MAX);
246
+
DECLARE @UserFunctionId char(16);
247
+
DECLARE @UserTableId int;
248
+
DECLARE LeaseTable_Cursor CURSOR FOR
249
+
250
+
SELECT 'az_func.Leases_'+UserFunctionId+'_'+convert(varchar(100),UserTableID) as TABLE_NAME, UserFunctionID, UserTableID
251
+
FROM az_func.GlobalState
252
+
253
+
OPEN LeaseTable_Cursor;
254
+
255
+
FETCH NEXT FROM LeaseTable_Cursor INTO @TableName, @UserFunctionId, @UserTableId;
256
+
257
+
WHILE @@FETCH_STATUS = 0
258
+
BEGIN
259
+
PRINT N'Dropping table ' + @TableName;
260
+
EXEC ('DROP TABLE IF EXISTS ' + @TableName);
261
+
PRINT 'Removing row from GlobalState for UserFunctionID = ' + RTRIM(CAST(@UserFunctionId AS NVARCHAR(30))) + ' and UserTableID = ' + RTRIM(CAST(@UserTableId AS NVARCHAR(30)));
262
+
DELETE FROM az_func.GlobalState WHERE UserFunctionID = @UserFunctionId and UserTableID = @UserTableId
263
+
FETCH NEXT FROM LeaseTable_Cursor INTO @TableName, @UserFunctionId, @UserTableId;
0 commit comments