Merge pull request #47 from microsoft/bw

added tempdb and fixed up vlf demos
This commit is contained in:
Bob Ward 2023-03-06 09:25:34 -06:00 коммит произвёл GitHub
Родитель e261d00dea a63ebdfe2a
Коммит 196a1c5a7a
Не найден ключ, соответствующий данной подписи
Идентификатор ключа GPG: 4AEE18F83AFDEB23
20 изменённых файлов: 142 добавлений и 16 удалений

Просмотреть файл

@ -0,0 +1,2 @@
net stop mssqlserver
net start mssqlserver /T6950 /T6962

Просмотреть файл

@ -0,0 +1,3 @@
sqlcmd -E -idisableopttempdb.sql
net stop mssqlserver
net start mssqlserver

Просмотреть файл

@ -0,0 +1,2 @@
ALTER SERVER CONFIGURATION SET MEMORY_OPTIMIZED TEMPDB_METADATA = OFF;
GO

Просмотреть файл

@ -0,0 +1,4 @@
USE master;
GO
ALTER DATABASE tempdb MODIFY FILE (NAME=templog , SIZE = 200Mb);
GO

Просмотреть файл

@ -0,0 +1,6 @@
USE master;
GO
SELECT name, physical_name, size*8192/1024 as size_kb, growth*8192/1024 as growth_kb
FROM sys.master_files
WHERE database_id = 2;
GO

Просмотреть файл

@ -0,0 +1 @@
sqlcmd -E -imodifytempdbfiles.sql

Просмотреть файл

@ -0,0 +1,10 @@
USE master;
GO
ALTER DATABASE tempdb MODIFY FILE (NAME=templog , SIZE = 200Mb, FILEGROWTH = 65536Kb);
GO
ALTER DATABASE tempdb REMOVE FILE temp2;
GO
ALTER DATABASE tempdb REMOVE FILE temp3;
GO
ALTER DATABASE tempdb REMOVE FILE temp4;
GO

Просмотреть файл

@ -0,0 +1,3 @@
sqlcmd -E -ioptimizetempdb.sql
net stop mssqlserver
net start mssqlserver

Просмотреть файл

@ -0,0 +1,2 @@
ALTER SERVER CONFIGURATION SET MEMORY_OPTIMIZED TEMPDB_METADATA = ON;
GO

Просмотреть файл

@ -0,0 +1,8 @@
USE tempdb;
GO
SELECT object_name(page_info.object_id), page_info.*
FROM sys.dm_exec_requests AS d
CROSS APPLY sys.fn_PageResCracker(d.page_resource) AS r
CROSS APPLY sys.dm_db_page_info(r.db_id, r.file_id, r.page_id,'DETAILED')
AS page_info;
GO

Просмотреть файл

@ -0,0 +1,66 @@
# Exercise for "hands-free" tempdb in SQL Server 2022
Follow these steps for an exercise to see system page latch concurrency enhancements for SQL Server 2022.
## Prerequisites
- SQL Server 2022 Evaluation or Developer Edition
- VM or computer with 4 CPUs and at least 8Gb RAM.
- SQL Server Management Studio (SSMS). The latest 18.x build or 19.x build will work.
- Download **ostress.exe** from https://aka.ms/ostress. Install using the RMLSetup.msi file that is downloaded. Use all defaults.
## Setup the exercise
1. Configure perfmon to track SQL Server **SQL Statistics:SQL Statistics/Batch requests/sec** (set Scale to 0.1) and **SQL Server:Wait Statistics/Page latch waits/Waits started per second**.
1. Execute the script **findtempdbfiles.sql** and save the output. A script is provided for the end of this exercise to restore back your tempdb file settings.
1. Start SQL Server in minimal mode using the command script **startsqlminimal.cmd**
1. Execute the command script **modifytempdbfiles.cmd**. This will execute the SQL script **modifytempdbfiles.sql** to expand the log to 200Mb (avoid any autogrow) and remove all tempdb files other than 1. If you have more than 4 tempdb files you need to edit this script to remove all of them except for tempdev.
**IMPORTANT:** If you are using an named instance you will need to edit all the .cmd scripts in this exercise to use a named instance. All the scripts assume a default instance.
## Exercise 1: Observe performance of a tempdb based workload without metadata optimization and without new SQL Server 2022 enhancements
1. Run **disableopttempdb.cmd** and then **disablegamsgam.cmd** from the command prompt.
**Note**: This will ensure tempdb metadata optimization is OFF and turn on two trace flags to disable GAM/SGAM concurrency enhancements. These trace flags are not documented and not supported for production use. They are only use to demonstrate new built-in enhancements.
1. Load the script **pageinfo.sql** into SSMS
1. Run **tempsql22stress.cmd 25** from the command prompt.
1. Execute **pageinfo.sql** from SSMS and observe that all the latch waits are for system table page latches
1. Observe perfmon stats
1. Observe final duration elapsed from **tempsql22stress.cmd**
## Exercise 2: Observe performance with tempdb metadata optimization enabled but without new SQL Server 2022 enhancements
1. Run **optimizetempdb.cmd**
1. Run **disablegamsgam.cmd**
1. Load the script **pageinfo.sql** into SSMS
1. Run **tempsql22stress.cmd 25** from the command prompt.
1. Execute **pageinfo.sql** from SSMS and observe that all the latch waits are for GAM pages.
1. Observe perfmon stats
1. Observe final duration elapsed from **tempsql22stress.cmd 25**
## Exercise 3: Observe performance with tempdb metadata optimization enabled and with new SQL Server 2022 enhancements
You could setup SQL Server with only one tempdb data file so one thing you could do is add more files. However, SQL Server 2022 includes enhancements to avoid latch contention for GAM and SGAM pages.
1. Execute the command script **restartsql.cmd**
Tempdb metadata optimization is already enabled and by restarting you are no longer using trace flags to disable new SQL Server 2022 enhancements.
1. Load the script **pageinfo.sql** into SSMS
1. Run **tempsql22stress.cmd 25** from the command prompt.
1. Execute **pageinfo.sql** from SSMS and observe there are no observable latch waits
1. Observe perfmon stats
1. Observe final duration elapsed from **tempsql22stress.cmd 25**
You have now achieved maximum performance with tempdb workloads and did not have to do any special configuration for tempdb files.
**Tip**: This exercise showed that you no longer may have to create multiple tempdb files for avoid system page latch contention. However, it is recommend to use the default setting from SQL Server setup for the number of files. I have run this same exercise on a 4 CPU machine with 4 files. With tempdb metadata optimization ON and using the new GAM/SGAM enhancements I got similar results from just using 1 file.
If you want to restore your tempdb file settings you can perform the following steps:
1. Edit the **restoretempdbfiles.sql** script to add or remove any extra files.
1. Execute the command script **restoretempdbfiles.cmd**. The script will display **Changed database context to 'master**' and exit back to the command prompt.
1. Execute the command script **restartsql.cmd**
1. Execute the script **findtempdbfiles.sql** to ensure your files are back to the correct configuration.

Просмотреть файл

@ -0,0 +1,2 @@
net stop mssqlserver
net start mssqlserver

Просмотреть файл

@ -0,0 +1 @@
sqlcmd -E -irestoretempdbfiles.sql

Просмотреть файл

@ -0,0 +1,10 @@
USE master;
GO
ALTER DATABASE tempdb MODIFY FILE (NAME=templog, SIZE = 8192Kb, FILEGROWTH = 65536kb);
GO
ALTER DATABASE tempdb ADD FILE (NAME=temp2, FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL16.MSSQLSERVER\MSSQL\DATA\tempdb_mssql_2.ndf', SIZE = 8192Kb, FILEGROWTH = 65536Kb);
GO
ALTER DATABASE tempdb ADD FILE (NAME=temp3, FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL16.MSSQLSERVER\MSSQL\DATA\tempdb_mssql_3.ndf', SIZE = 8192Kb, FILEGROWTH = 65536Kb);
GO
ALTER DATABASE tempdb ADD FILE (NAME=temp4, FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL16.MSSQLSERVER\MSSQL\DATA\tempdb_mssql_4.ndf', SIZE = 8192Kb, FILEGROWTH = 65536Kb);
GO

Просмотреть файл

@ -0,0 +1,2 @@
net stop mssqlserver
net start mssqlserver /f /mSQLCMD

Просмотреть файл

@ -0,0 +1 @@
"c:\Program Files\Microsoft Corporation\RMLUtils\ostress" -E -Q"declare @t table (c1 varchar(100)); insert into @t values ('x');" -n%1 -r1000 -q -T146

Просмотреть файл

@ -0,0 +1,10 @@
USE [master]
GO
DROP DATABASE IF EXISTS testvlf;
GO
CREATE DATABASE testvlf
ON PRIMARY
( NAME = N'testvlf', FILENAME = N'C:\data\testvlf.mdf' , SIZE = 2GB , MAXSIZE = UNLIMITED, FILEGROWTH = 65536KB)
LOG ON
( NAME = N'testvlf_log', FILENAME = N'c:\data\testvlf_log.ldf' , SIZE = 8MB , MAXSIZE = 2048GB , FILEGROWTH = 65536KB);
GO

Просмотреть файл

@ -1,13 +1,3 @@
USE [master]
GO
DROP DATABASE IF EXISTS testvlf;
GO
CREATE DATABASE testvlf
ON PRIMARY
( NAME = N'testvlf', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL16.MSSQLSERVER\MSSQL\DATA\testvlf.mdf' , SIZE = 2GB , MAXSIZE = UNLIMITED, FILEGROWTH = 65536KB)
LOG ON
( NAME = N'testvlf_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL16.MSSQLSERVER\MSSQL\DATA\testvlf_log.ldf' , SIZE = 8MB , MAXSIZE = 2048GB , FILEGROWTH = 65536KB);
GO
USE testvlf;
GO
DROP TABLE IF EXISTS growtable;

Просмотреть файл

@ -8,18 +8,21 @@ First show the log autogrow behavior in SQL Server 2019
### Setup
**Note**: I choose to run SQL 2019 in a VM with a slower disk to show performance differences. Zeroing a log file of 64Mb on autogrow has less of an impact on very fast disks.
- Install SQL Server 2019 (any edition)
- Run the script xe.sql to setup an Extended Event session to track log file size changes and wait types that indicate tlog zero writes are occurring. In SSMS, right click on the session and select Watch Live Data.
- Run the script **xe.sql** to setup an Extended Event session to track log file size changes and wait types that indicate tlog zero writes are occurring. In SSMS, right click on the session and select Watch Live Data.
- Edit the script **createdb.sql** for your file paths. This script is used to create the new db. Pay attention to the initial size and autogrow properties.
- Run the script **clear_wait_types.sql** to clear wait stats.
- Load the script **countvlfs.sql**
- Load the script **wait_types.sql**
### Reproduce log autogrows
- Run the script ddl.sql. Notice this takes only almost 30 seconds.
- Run the script **ddl.sql**. Notice this takes about 30 seconds.
- Observe in XEvent the different events. You see events for **PREEMPTIVE_OS_WRITEFILE_GATHER** which indicate zeroing files. This is for the CREATE DATABASE statement and expected.
- Now notice a pattern where you see database_file_size_changed events for the transaciton log combined with **PREEMPTIVE_OS_WRITEFILEGATHER** events. This shows that any log grow requires a write operation to zero out the log file growth.
- Run the query in wait_types.sql. Notice the total wait time for **PREEMPTIVE_OS_WRITEFILEGATHER** which is about 20 seconds. So our workload was delayed for 20 seconds trying to zero log growths.
- Now notice a pattern where you see **database_file_size_changed** events for the transaction log combined with **PREEMPTIVE_OS_WRITEFILEGATHER** events. This shows that any log grow requires a write operation to zero out the log file growth.
- Run the query in **wait_types.sql**. Notice the total wait time for **PREEMPTIVE_OS_WRITEFILEGATHER** which is about 20 seconds. So our workload was delayed for 20 seconds trying to zero log growths.
- Run the query in **countvlfs.sql**. Notice there are some 50 virtual log file rows.
### Observe the performance impact on recovery
@ -45,7 +48,7 @@ Show log autogrow enhancements for SQL Server 2022
- Load the script **countvlfs.sql**
- Load the script **wait_types.sql**
### Reproduce log autogrows
### Reproduce log autogrow
- Run the script **ddl.sql**. Notice this takes only a few seconds (it took ~30 seconds on SQL Server 2019)
- Observe in XEvent the different events. You see events for **PREEMPTIVE_OS_WRITEFILEGATHER** which indicate zeroing files. This is for the CREATE DATABASE statement and expected.

Просмотреть файл

@ -7,4 +7,4 @@ ADD EVENT sqlserver.database_file_size_change(
WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=ALLOW_SINGLE_EVENT_LOSS,MAX_DISPATCH_LATENCY=30 SECONDS,MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF)
GO
ALTER EVENT SESSION [track_log_autogrow] ON SERVER STATE=START;
GO
GO