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
Copy file name to clipboardExpand all lines: README.md
+72Lines changed: 72 additions & 0 deletions
Display the source diff
Display the rich diff
Original file line number
Diff line number
Diff line change
@@ -529,6 +529,78 @@ WITH (DATA_COMPRESSION = PAGE);
529
529
530
530
You can add indexes, partitioning, and other optimizations based on your specific requirements. See the [Quick Start](#quick-start) section for complete table examples.
531
531
532
+
## Log Management and Archival
533
+
534
+
As your application generates logs over time, the log table will grow continuously. It's important to implement a log retention strategy to manage storage costs and maintain query performance.
535
+
536
+
### Automated Log Purging
537
+
538
+
The following stored procedure provides an efficient way to delete old log entries in batches, preventing transaction log bloat and minimizing system impact:
-- Delete in batches to prevent transaction log bloat and reduce lock contention
558
+
WHILE 1=1
559
+
BEGIN
560
+
DELETE TOP (@BatchSize)
561
+
FROMdbo.LogEvent WITH (ROWLOCK)
562
+
WHERE [Timestamp] < @Threshold;
563
+
564
+
SET @RowsDeleted = @@ROWCOUNT;
565
+
SET @TotalDeleted = @TotalDeleted + @RowsDeleted;
566
+
567
+
-- Exit if no more rows to delete
568
+
IF @RowsDeleted =0
569
+
BREAK;
570
+
571
+
-- Brief delay between batches to reduce contention
572
+
WAITFOR DELAY '00:00:00.100'; -- 100ms
573
+
END
574
+
575
+
-- Return summary
576
+
SELECT @TotalDeleted AS TotalRowsDeleted;
577
+
END
578
+
```
579
+
580
+
**How the procedure works:**
581
+
582
+
1.**Batch Processing**: Deletes records in configurable batches (default 10,000 rows) rather than all at once
583
+
- Prevents transaction log from filling up
584
+
- Reduces lock duration and blocking
585
+
- Allows other queries to access the table between batches
586
+
- Makes the operation recoverable if interrupted
587
+
588
+
2.**Row-Level Locking**: Uses `WITH (ROWLOCK)` hint to minimize lock escalation and reduce contention with concurrent operations
589
+
590
+
3.**Threshold-Based Deletion**: Removes logs older than the specified retention period (default 90 days)
591
+
592
+
4.**Progress Tracking**: Returns total deleted rows and provides feedback during execution
593
+
594
+
### Alternative: Table Partitioning
595
+
596
+
For very high-volume logging scenarios, consider implementing table partitioning by date:
597
+
598
+
-**Benefits**: Near-instant deletion of old partitions, better query performance, easier maintenance
599
+
-**Trade-off**: More complex initial setup and management
600
+
-**Recommended for**: Systems generating millions of log entries per day
601
+
602
+
See [SQL Server table partitioning documentation](https://learn.microsoft.com/en-us/sql/relational-databases/partitions/partitioned-tables-and-indexes) for implementation details.
0 commit comments