├── sample-scripts ├── Readme.md ├── backup_restore │ ├── SqlBackup.bat │ ├── estimate_backup_restore.sql │ └── SQL_Express_Backups.sql ├── DOCs-to-Notebooks │ ├── Readme.md │ ├── T-shooting-SQL-SystemAdmins-Locked-out.ipynb │ ├── T-shooting_PagelatchEX_LastPageInsert.ipynb │ ├── MSSQLSERVER_35250.ipynb │ └── T-shooting-SQL-Slow-IO.ipynb ├── availability_groups │ └── read_scale_no_cluster │ │ ├── ReadMe.md │ │ ├── SQL AG 07 populate rows.sql │ │ ├── SQL AG 11 client commands.bat │ │ ├── SQL AG 08 listener for read scale scenarios.sql │ │ ├── SQL AG 03 create endpoint on all replicas.sql │ │ ├── SQL AG 05 join secondary replica to availability group.sql │ │ ├── SQL AG 02 create certificates on secondary replicas.sql │ │ ├── SQL AG 06 add database to availability group.sql │ │ ├── SQL AG 01 create certificates on primary.sql │ │ ├── SQL AG 10 Logins and Users.sql │ │ ├── SQL AG 13 planned manual failover - steps on secondary.sql │ │ ├── SQL AG 12 planned manual failover - steps on current primary.sql │ │ ├── SQL AG 04 create availability group.sql │ │ └── SQL AG 09 ReadOnly Routing.sql ├── database_space_management │ ├── SpaceusedByDatabase.sql │ ├── SpaceUsageByObjectAllocUnit.sql │ └── SpaceUsedByObject+Index.sql ├── filestream │ └── FileStreamTests.sql ├── performance │ ├── ActiveTransactions.sql │ └── Index_Maintenance_Recommendations.sql ├── extended_events │ └── Read_xel_files.sql └── security │ ├── application_roles │ └── UseAppRoleToViewServerInfo.sql │ └── manage-logins-permissions │ ├── sp_help_revlogin.sql │ └── sp_GetPermsInfo.sql ├── sqliaasselfhelp ├── activity_log_example.jpg ├── Azure_monitoring_example.jpg └── Resource_health_example.jpg ├── sqliosim ├── Sample configuration files.docx ├── Readme.md ├── sqliosim.cfg.linux │ ├── sqliosim.hwcache.cfg.ini │ ├── sqliosim.seqwrites.cfg.ini │ ├── sqliosim.default.cfg.ini │ ├── sqliosim.nothrottle.cfg.ini │ └── sqliosim.sparse.cfg.ini └── sqliosim.cfg.windows │ ├── sqliosim.hwcache.cfg.ini │ ├── sqliosim.seqwrites.cfg.ini │ ├── sqliosim.default.cfg.ini │ ├── sqliosim.nothrottle.cfg.ini │ └── sqliosim.sparse.cfg.ini ├── README.md ├── LICENSE ├── SECURITY.md ├── .gitignore └── sqldumper └── SQLDumpHelper.ps1 /sample-scripts/Readme.md: -------------------------------------------------------------------------------- 1 | You can use these sample scripts for various activities or operations that you perform with SQL Server. -------------------------------------------------------------------------------- /sqliaasselfhelp/activity_log_example.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/microsoft/mssql-support/HEAD/sqliaasselfhelp/activity_log_example.jpg -------------------------------------------------------------------------------- /sqliosim/Sample configuration files.docx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/microsoft/mssql-support/HEAD/sqliosim/Sample configuration files.docx -------------------------------------------------------------------------------- /sample-scripts/backup_restore/SqlBackup.bat: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/microsoft/mssql-support/HEAD/sample-scripts/backup_restore/SqlBackup.bat -------------------------------------------------------------------------------- /sqliaasselfhelp/Azure_monitoring_example.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/microsoft/mssql-support/HEAD/sqliaasselfhelp/Azure_monitoring_example.jpg -------------------------------------------------------------------------------- /sqliaasselfhelp/Resource_health_example.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/microsoft/mssql-support/HEAD/sqliaasselfhelp/Resource_health_example.jpg -------------------------------------------------------------------------------- /sample-scripts/DOCs-to-Notebooks/Readme.md: -------------------------------------------------------------------------------- 1 | # Notebooks from DOCs 2 | 3 | This folder contains ADS/Jupyter Notebooks that are based on Microsoft SQL Server documentation on https://docs.microsoft.com (DOCs). Currently this is Proof-of-Concept (PoC) project which may grow, if there is interest in it. 4 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/ReadMe.md: -------------------------------------------------------------------------------- 1 | This set of files allow you to create a read scale availability group without any cluster manager involved. The documentation for this feature is available at https://docs.microsoft.com/en-us/sql/database-engine/availability-groups/windows/configure-read-scale-availability-groups 2 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 07 populate rows.sql: -------------------------------------------------------------------------------- 1 | USE [db1] 2 | GO 3 | -- create a table 4 | CREATE TABLE tbl1 ( col1 int , col2 char(4000) ) 5 | GO 6 | -- populate rows 7 | INSERT INTO tbl1 VALUES ( RAND()*100 ,'abc') 8 | GO 10 9 | -- check the values 10 | SELECT * FROM tbl1 11 | GO 12 | -- clean the table 13 | TRUNCATE TABLE tbl1 14 | GO 15 | -------------------------------------------------------------------------------- /sample-scripts/database_space_management/SpaceusedByDatabase.sql: -------------------------------------------------------------------------------- 1 | -- ============================================= 2 | -- Author: Joseph Pilov 3 | -- Create date: 03-2017 4 | -- Description: Retrieve space usage by database 5 | -- ============================================= 6 | 7 | SELECT sum(size/128) size_mb, db_name(database_id) dbname 8 | FROM sys.master_files 9 | GROUP BY database_id 10 | ORDER BY size_mb DESC -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 11 client commands.bat: -------------------------------------------------------------------------------- 1 | START SQLCMD -U TestLogin -S ag-node001,2433 -d db1 -K ReadOnly -q"print '' select cast(@@servername as char(50)) as server_name, cast(suser_name() as char(50)) as login_name" 2 | 3 | START SQLCMD -U TestLogin -S ag-node001,2433 -d db1 -K ReadOnly -q"print '' select cast(@@servername as char(50)) as server_name, cast(suser_name() as char(50)) as login_name" -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 08 listener for read scale scenarios.sql: -------------------------------------------------------------------------------- 1 | USE [master] 2 | GO 3 | 4 | -- remove listener that exists previously 5 | ALTER AVAILABILITY GROUP [ag1] 6 | REMOVE LISTENER N'ag-node000'; 7 | GO 8 | 9 | -- create listener that maps to the listener of the primary replica IP to use for read-routing 10 | ALTER AVAILABILITY GROUP [ag1] 11 | ADD LISTENER N'ag-node000' ( 12 | WITH IP 13 | ((N'10.0.0.4', N'255.255.240.0') 14 | ) 15 | , PORT=2433); 16 | GO 17 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 03 create endpoint on all replicas.sql: -------------------------------------------------------------------------------- 1 | -- create the endpoint on all replicas after the certificates are created 2 | CREATE ENDPOINT [Hadr_endpoint] 3 | AS TCP (LISTENER_PORT = 5022) 4 | FOR DATABASE_MIRRORING ( 5 | ROLE = ALL, 6 | AUTHENTICATION = CERTIFICATE dbm_certificate, 7 | ENCRYPTION = REQUIRED ALGORITHM AES 8 | ); 9 | GO 10 | ALTER ENDPOINT [Hadr_endpoint] STATE = STARTED; 11 | GO 12 | 13 | -- make sure the port specified for the endpoint is opened for the replicas to communicate -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 05 join secondary replica to availability group.sql: -------------------------------------------------------------------------------- 1 | -- join the secondary replica to the availability group 2 | ALTER AVAILABILITY GROUP [ag1] JOIN WITH (CLUSTER_TYPE = NONE); 3 | GO 4 | ALTER AVAILABILITY GROUP [ag1] GRANT CREATE ANY DATABASE; 5 | GO 6 | 7 | -- check the status of the database in the availability group 8 | SELECT * FROM sys.databases WHERE name = 'db1'; 9 | GO 10 | SELECT DB_NAME(database_id) AS 'database', synchronization_state_desc FROM sys.dm_hadr_database_replica_states; 11 | GO 12 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 02 create certificates on secondary replicas.sql: -------------------------------------------------------------------------------- 1 | -- create the same certificate on all replicas that match the one present on the primary 2 | CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'YourPassword'; 3 | GO 4 | CREATE CERTIFICATE dbm_certificate 5 | FROM FILE = 'C:\Program Files\Microsoft SQL Server\MSSQL15.SQL2019\MSSQL\DATA\dbm_certificate.cer' 6 | WITH PRIVATE KEY ( 7 | FILE = 'C:\Program Files\Microsoft SQL Server\MSSQL15.SQL2019\MSSQL\DATA\dbm_certificate.pvk', 8 | DECRYPTION BY PASSWORD = 'YourPassword' 9 | ); 10 | GO 11 | 12 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 06 add database to availability group.sql: -------------------------------------------------------------------------------- 1 | -- create database 2 | CREATE DATABASE [db1]; 3 | GO 4 | ALTER DATABASE [db1] SET RECOVERY FULL; 5 | GO 6 | BACKUP DATABASE [db1] 7 | TO DISK = N'db1.bak'; 8 | GO 9 | 10 | -- add the database to the availability group 11 | ALTER AVAILABILITY GROUP [ag1] ADD DATABASE [db1]; 12 | GO 13 | 14 | -- check the status of this database in the availability group 15 | SELECT * FROM sys.databases WHERE name = 'db1'; 16 | GO 17 | SELECT DB_NAME(database_id) AS 'database', synchronization_state_desc FROM sys.dm_hadr_database_replica_states; 18 | GO 19 | -------------------------------------------------------------------------------- /sqliosim/Readme.md: -------------------------------------------------------------------------------- 1 | When you install SQL Server, you find the SQLIOSim tool in the BINN folder of your SQL Server installation. Customers can use these updated versions of the tool to simulate the IO activity on the disk subsystem. You can use this tool to perform reliability and integrity tests on disk subsystems. These tests simulate read, write, checkpoint, backup, sort, and read-ahead activities for Microsoft SQL Server. 2 | 3 | You can customize the behavior and nature of tests performed by SQLIOSim tool using configuration files that specify variosu configuration options, file and activity details. This folder provides you a few sample files to use for diifferent behaviors. Feel free to customize them as you see fit. 4 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 01 create certificates on primary.sql: -------------------------------------------------------------------------------- 1 | -- create certificate that will be used for endpoint authentication 2 | CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'YourPassword'; 3 | GO 4 | CREATE CERTIFICATE dbm_certificate WITH SUBJECT = 'dbm'; 5 | GO 6 | BACKUP CERTIFICATE dbm_certificate 7 | TO FILE = 'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\dbm_certificate.cer' 8 | WITH PRIVATE KEY ( 9 | FILE = 'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\dbm_certificate.pvk', 10 | ENCRYPTION BY PASSWORD = 'YourPassword' 11 | ); 12 | GO 13 | 14 | -- copy the .cer and .pck file to all replicas that need to communicate and authenticate with this replica endpoint -------------------------------------------------------------------------------- /sample-scripts/database_space_management/SpaceUsageByObjectAllocUnit.sql: -------------------------------------------------------------------------------- 1 | -- ============================================= 2 | -- Author: Joseph Pilov 3 | -- Create date: 03-2017 4 | -- Description: Retrieve space usage by object and type of allocation unit 5 | -- ============================================= 6 | 7 | 8 | SELECT 9 | t.object_id, 10 | OBJECT_NAME(t.object_id) ObjectName, 11 | sum(u.total_pages) * 8 Total_Reserved_kb, 12 | sum(u.used_pages) * 8 Used_Space_kb, 13 | u.type_desc, 14 | max(p.rows) RowsCount 15 | FROM 16 | sys.allocation_units u 17 | join sys.partitions p on u.container_id = p.hobt_id 18 | join sys.tables t on p.object_id = t.object_id 19 | GROUP BY 20 | t.object_id, 21 | OBJECT_NAME(t.object_id), 22 | u.type_desc 23 | ORDER BY 24 | Used_Space_kb desc, 25 | ObjectName -------------------------------------------------------------------------------- /sample-scripts/backup_restore/estimate_backup_restore.sql: -------------------------------------------------------------------------------- 1 | SELECT r.session_id AS [Session_Id] ,r.command AS [command] , 2 | CONVERT(NUMERIC(6, 2), r.percent_complete) AS [% Complete] , 3 | GETDATE() AS [Current Time] , 4 | CONVERT(VARCHAR(20), DATEADD(ms, r.estimated_completion_time, GetDate()), 20) AS [Estimated Completion Time] , 5 | CONVERT(NUMERIC(32, 2), r.total_elapsed_time / 1000.0 / 60.0) AS [Elapsed Min] , 6 | CONVERT(NUMERIC(32, 2), r.estimated_completion_time / 1000.0 / 60.0) AS [Estimated Min] , 7 | CONVERT(NUMERIC(32, 2), r.estimated_completion_time / 1000.0 / 60.0 / 60.0) AS [Estimated Hours] , 8 | CONVERT(VARCHAR(1000), ( SELECT SUBSTRING(TEXT, r.statement_start_offset / 2, 9 | CASE WHEN r.statement_end_offset = - 1 THEN 1000 10 | ELSE (r.statement_end_offset - r.statement_start_offset) / 2 END) 'Statement text' FROM sys.dm_exec_sql_text(sql_handle) )) 11 | FROM sys.dm_exec_requests r WHERE command like 'RESTORE%'or command like 'BACKUP%' -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | # Contributing 3 | 4 | This project welcomes contributions and suggestions. Most contributions require you to agree to a 5 | Contributor License Agreement (CLA) declaring that you have the right to, and actually do, grant us 6 | the rights to use your contribution. For details, visit https://cla.microsoft.com. 7 | 8 | When you submit a pull request, a CLA-bot will automatically determine whether you need to provide 9 | a CLA and decorate the PR appropriately (e.g., label, comment). Simply follow the instructions 10 | provided by the bot. You will only need to do this once across all repos using our CLA. 11 | 12 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). 13 | For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) or 14 | contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments. 15 | -------------------------------------------------------------------------------- /sample-scripts/database_space_management/SpaceUsedByObject+Index.sql: -------------------------------------------------------------------------------- 1 | -- ============================================= 2 | -- Author: Joseph Pilov 3 | -- Create date: 03-2017 4 | -- Description: Retrieve space usage by object and Index 5 | -- ============================================= 6 | 7 | SELECT 8 | t.NAME AS TableName, 9 | i.name AS indexName, 10 | SUM(p.rows) AS RowCounts, 11 | SUM(a.total_pages) AS TotalPages, 12 | SUM(a.used_pages) AS UsedPages, 13 | SUM(a.data_pages) AS DataPages, 14 | (SUM(a.total_pages) * 8) / 1024 AS TotalSpaceMB, 15 | (SUM(a.used_pages) * 8) / 1024 AS UsedSpaceMB, 16 | (SUM(a.data_pages) * 8) / 1024 AS DataSpaceMB 17 | FROM 18 | sys.tables t 19 | INNER JOIN 20 | sys.indexes i ON t.OBJECT_ID = i.object_id 21 | INNER JOIN 22 | sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id 23 | INNER JOIN 24 | sys.allocation_units a ON p.partition_id = a.container_id 25 | WHERE 26 | i.index_id > 0 27 | GROUP BY 28 | t.NAME, i.object_id, i.index_id, i.name 29 | ORDER BY 30 | OBJECT_NAME(i.object_id) 31 | 32 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 10 Logins and Users.sql: -------------------------------------------------------------------------------- 1 | 2 | -- create the SQL login on the primary replica 3 | USE [master] 4 | GO 5 | CREATE LOGIN [TestLogin] WITH PASSWORD=N'', DEFAULT_DATABASE=[master], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF 6 | GO 7 | 8 | -- extract the password hash and sid for the login you created now 9 | SELECT CAST( LOGINPROPERTY( name, 'PasswordHash' ) AS varbinary (256) ) as [Hash], [sid] FROM sys.server_principals WHERE name = 'TestLogin' 10 | GO 11 | -- replace the hash and sid in this create login statement 12 | CREATE LOGIN [TestLogin] WITH PASSWORD = HASHED, SID = , DEFAULT_DATABASE=[master], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF 13 | GO 14 | -- take this create login statement and execute it on all secondary replicas which are associated to this availability group 15 | 16 | -- execute this on the primary replica to create user and map to the login 17 | USE [db1] 18 | GO 19 | CREATE USER [TestLogin] FOR LOGIN [TestLogin] 20 | GO 21 | USE [db1] 22 | GO 23 | ALTER ROLE [db_datareader] ADD MEMBER [TestLogin] 24 | GO 25 | -------------------------------------------------------------------------------- /sample-scripts/filestream/FileStreamTests.sql: -------------------------------------------------------------------------------- 1 | -- enable file stream access configuration 2 | EXEC sp_configure 'filestream_access_level' , 2 3 | GO 4 | RECONFIGURE WITH OVERRIDE 5 | GO 6 | 7 | -- create database with filestream filegroup 8 | -- change the file locations as appropriate 9 | CREATE DATABASE myDb1 10 | ON 11 | PRIMARY (NAME = myDb1_data, FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL14.SQL2017\MSSQL\DATA\myDb1_data.mdf'), 12 | FILEGROUP FileStreamGroup1 CONTAINS FILESTREAM (NAME = myDb1FSFG1, FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL14.SQL2017\MSSQL\DATA\filestream\myDb1_FSFG1') 13 | LOG ON (NAME = myDb1_Log, FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL14.SQL2017\MSSQL\DATA\myDb1_log.ldf') 14 | GO 15 | 16 | USE myDb1 17 | GO 18 | -- create table that will use filestream containers 19 | CREATE TABLE tbl_test1 ([Id] [uniqueidentifier] ROWGUIDCOL NOT NULL UNIQUE, [SerialNumber] int, [Chart] varbinary(MAX) FILESTREAM NULL) 20 | GO 21 | 22 | -- store data 23 | INSERT INTO tbl_test1 VALUES (newid(), 1 , CAST('this is filestream info' as varbinary(MAX))) 24 | GO 25 | SELECT * FROM tbl_test1 26 | GO 27 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 13 planned manual failover - steps on secondary.sql: -------------------------------------------------------------------------------- 1 | 2 | -- check synchronization status 3 | SELECT ag.name, 4 | drs.database_id, 5 | drs.group_id, 6 | drs.replica_id, 7 | drs.synchronization_state_desc, 8 | ag.sequence_number 9 | FROM sys.dm_hadr_database_replica_states drs, sys.availability_groups ag 10 | WHERE drs.group_id = ag.group_id 11 | GO 12 | -- make sure the replica to be promoted is in synchronized status 13 | 14 | -- perform failover 15 | ALTER AVAILABILITY GROUP ag1 FORCE_FAILOVER_ALLOW_DATA_LOSS 16 | GO 17 | 18 | -- on the old primary set its status to secondary 19 | 20 | -- reset availability group attributes to the ones before failover 21 | ALTER AVAILABILITY GROUP [ag1] 22 | SET (REQUIRED_SYNCHRONIZED_SECONDARIES_TO_COMMIT = 0); 23 | GO 24 | 25 | ALTER AVAILABILITY GROUP [ag1] 26 | MODIFY REPLICA ON N'ag-node001' 27 | WITH (AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT); 28 | GO 29 | ALTER AVAILABILITY GROUP [ag1] 30 | MODIFY REPLICA ON N'ag-node000' 31 | WITH (AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT); 32 | GO 33 | 34 | -- make sure to recreate the listener for the new primary to enable read-only routing -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) Microsoft Corporation. All rights reserved. 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE 22 | -------------------------------------------------------------------------------- /sample-scripts/performance/ActiveTransactions.sql: -------------------------------------------------------------------------------- 1 | 2 | -- ============================================= 3 | -- Author: Joseph Pilov 4 | -- Create date: 03-2017 5 | -- Description: Get info about active transactions on the system 6 | -- ============================================= 7 | 8 | --active trans 9 | SELECT 10 | getdate() as now, 11 | DATEDIFF(SECOND, transaction_begin_time, GETDATE()) as tran_elapsed_time_seconds, 12 | * 13 | FROM 14 | sys.dm_tran_active_transactions at 15 | JOIN sys.dm_tran_session_transactions st ON st.transaction_id = at.transaction_id 16 | INNER JOIN sys.sysprocesses sp ON st.session_id = sp.spid 17 | CROSS APPLY sys.dm_exec_sql_text(sql_handle) txt 18 | ORDER BY 19 | tran_elapsed_time_seconds DESC 20 | 21 | 22 | 23 | --Active Row versioning transactions 24 | SELECT 25 | GETDATE() AS runtime, 26 | a.*, 27 | b.kpid, 28 | b.blocked, 29 | b.lastwaittype, 30 | b.waitresource, 31 | db_name(b.dbid) as database_name, 32 | b.cpu, 33 | b.physical_io, 34 | b.memusage, 35 | b.login_time, 36 | b.last_batch, 37 | b.open_tran, 38 | b.status, 39 | b.hostname, 40 | b.program_name, 41 | b.cmd, 42 | b.loginame, 43 | request_id, 44 | c.* 45 | FROM 46 | sys.dm_tran_active_snapshot_database_transactions a 47 | INNER JOIN sys.sysprocesses b 48 | ON a.session_id = b.spid 49 | CROSS APPLY sys.dm_exec_sql_text(sql_handle) c 50 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 12 planned manual failover - steps on current primary.sql: -------------------------------------------------------------------------------- 1 | -- Make the current primary replica SYNCHRONOUS_COMMIT 2 | ALTER AVAILABILITY GROUP [ag1] 3 | MODIFY REPLICA ON N'ag-node001' 4 | WITH (AVAILABILITY_MODE = SYNCHRONOUS_COMMIT); 5 | GO 6 | 7 | -- Make the target secondary replica SYNCHRONOUS_COMMIT 8 | ALTER AVAILABILITY GROUP [ag1] 9 | MODIFY REPLICA ON N'ag-node001' 10 | WITH (AVAILABILITY_MODE = SYNCHRONOUS_COMMIT); 11 | GO 12 | 13 | -- check synchronization status 14 | SELECT ag.name, 15 | drs.database_id, 16 | drs.group_id, 17 | drs.replica_id, 18 | drs.synchronization_state_desc, 19 | ag.sequence_number 20 | FROM sys.dm_hadr_database_replica_states drs, sys.availability_groups ag 21 | WHERE drs.group_id = ag.group_id 22 | GO 23 | 24 | -- set availability group attributes needed for failover 25 | ALTER AVAILABILITY GROUP [ag1] 26 | SET (REQUIRED_SYNCHRONIZED_SECONDARIES_TO_COMMIT = 1); 27 | GO 28 | 29 | -- take the availability group offline in current primary replica 30 | ALTER AVAILABILITY GROUP [ag1] OFFLINE 31 | GO 32 | 33 | -- now perform the failover operations on the target secondary 34 | 35 | -- set the old primary to secondary replica 36 | ALTER AVAILABILITY GROUP [ag1] 37 | SET (ROLE = SECONDARY); 38 | GO 39 | 40 | -- resume data movement 41 | ALTER DATABASE [db1] 42 | SET HADR RESUME 43 | GO 44 | 45 | -- last two steps need to be done on all secondary replicas after the failover operation to resume data movement 46 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 04 create availability group.sql: -------------------------------------------------------------------------------- 1 | -- create the availability group with the replicas specified 2 | CREATE AVAILABILITY GROUP [ag1] 3 | WITH (CLUSTER_TYPE = NONE) 4 | FOR REPLICA ON 5 | N'ag-node000' 6 | WITH ( 7 | ENDPOINT_URL = N'tcp://ag-node000:5022', 8 | AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT, 9 | FAILOVER_MODE = MANUAL, 10 | SEEDING_MODE = AUTOMATIC, 11 | SECONDARY_ROLE (ALLOW_CONNECTIONS = ALL) 12 | ), 13 | N'ag-node001' 14 | WITH ( 15 | ENDPOINT_URL = N'tcp://ag-node001:5022', 16 | AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT, 17 | FAILOVER_MODE = MANUAL, 18 | SEEDING_MODE = AUTOMATIC, 19 | SECONDARY_ROLE (ALLOW_CONNECTIONS = ALL) 20 | ), 21 | N'ag-node002' 22 | WITH ( 23 | ENDPOINT_URL = N'tcp://ag-node002:5022', 24 | AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT, 25 | FAILOVER_MODE = MANUAL, 26 | SEEDING_MODE = AUTOMATIC, 27 | SECONDARY_ROLE (ALLOW_CONNECTIONS = ALL) 28 | ); 29 | GO 30 | ALTER AVAILABILITY GROUP [ag1] GRANT CREATE ANY DATABASE; 31 | GO 32 | 33 | -- if you want to add more replicas later 34 | ALTER AVAILABILITY GROUP [ag1] ADD REPLICA ON 'ag-node003' 35 | WITH ( 36 | ENDPOINT_URL = N'tcp://ag-node003:5022', 37 | AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT, 38 | FAILOVER_MODE = MANUAL, 39 | SEEDING_MODE = AUTOMATIC 40 | ); 41 | GO 42 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.linux/sqliosim.hwcache.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=10000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=100 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | UserCount=0 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | UserCount=0 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | [File1] 64 | FileName=f:\sqliosim.mdx 65 | InitialSize=100 66 | MaxSize=100 67 | Increment=10 68 | Shrinkable=FALSE 69 | LogFile=FALSE 70 | Sparse=FALSE 71 | 72 | [File2] 73 | FileName=f:\sqliosim.ldx 74 | InitialSize=50 75 | MaxSize=50 76 | Increment=0 77 | Shrinkable=FALSE 78 | LogFile=TRUE 79 | Sparse=FALSE 80 | 81 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.windows/sqliosim.hwcache.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=10000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=100 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | UserCount=0 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | UserCount=0 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | [File1] 64 | FileName=f:\sqliosim.mdx 65 | InitialSize=100 66 | MaxSize=100 67 | Increment=10 68 | Shrinkable=FALSE 69 | LogFile=FALSE 70 | Sparse=FALSE 71 | 72 | [File2] 73 | FileName=f:\sqliosim.ldx 74 | InitialSize=50 75 | MaxSize=50 76 | Increment=0 77 | Shrinkable=FALSE 78 | LogFile=TRUE 79 | Sparse=FALSE 80 | 81 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.linux/sqliosim.seqwrites.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=10000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=100 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=FALSE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | UserCount=0 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | UserCount=0 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | UserCount=0 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=600 53 | BuffersBUMax=1000 54 | DelayAfterCycles=2 55 | BUDelay=1 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | ;[File1] 64 | ;FileName=f:\sqliosim.mdx 65 | ;InitialSize=100 66 | ;MaxSize=100 67 | ;Increment=10 68 | ;Shrinkable=FALSE 69 | ;LogFile=FALSE 70 | ;Sparse=FALSE 71 | 72 | ;[File2] 73 | ;FileName=f:\sqliosim.ldx 74 | ;InitialSize=50 75 | ;MaxSize=50 76 | ;Increment=0 77 | ;Shrinkable=FALSE 78 | ;LogFile=TRUE 79 | ;Sparse=FALSE 80 | 81 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.windows/sqliosim.seqwrites.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=10000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=100 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=FALSE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | UserCount=0 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | UserCount=0 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | UserCount=0 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=600 53 | BuffersBUMax=1000 54 | DelayAfterCycles=2 55 | BUDelay=1 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | ;[File1] 64 | ;FileName=f:\sqliosim.mdx 65 | ;InitialSize=100 66 | ;MaxSize=100 67 | ;Increment=10 68 | ;Shrinkable=FALSE 69 | ;LogFile=FALSE 70 | ;Sparse=FALSE 71 | 72 | ;[File2] 73 | ;FileName=f:\sqliosim.ldx 74 | ;InitialSize=50 75 | ;MaxSize=50 76 | ;Increment=0 77 | ;Shrinkable=FALSE 78 | ;LogFile=TRUE 79 | ;Sparse=FALSE 80 | 81 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.linux/sqliosim.default.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=1000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=100 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | ;UserCount=2 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | ;UserCount=2 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | ;[File1] 64 | ;FileName=f:\sqliosim.mdx 65 | ;InitialSize=4096 66 | ;MaxSize=8192 67 | ;Increment=10 68 | ;Shrinkable=TRUE 69 | ;LogFile=FALSE 70 | ;Sparse=FALSE 71 | 72 | ;[File2] 73 | ;FileName=f:\sqliosim.ldx 74 | ;InitialSize=50 75 | ;MaxSize=50 76 | ;Increment=0 77 | ;Shrinkable=FALSE 78 | ;LogFile=TRUE 79 | ;Sparse=FALSE 80 | 81 | ;[File3] 82 | ;FileName= 83 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.windows/sqliosim.default.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=1000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=100 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | ;UserCount=2 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | ;UserCount=2 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | ;[File1] 64 | ;FileName=f:\sqliosim.mdx 65 | ;InitialSize=4096 66 | ;MaxSize=8192 67 | ;Increment=10 68 | ;Shrinkable=TRUE 69 | ;LogFile=FALSE 70 | ;Sparse=FALSE 71 | 72 | ;[File2] 73 | ;FileName=f:\sqliosim.ldx 74 | ;InitialSize=50 75 | ;MaxSize=50 76 | ;Increment=0 77 | ;Shrinkable=FALSE 78 | ;LogFile=TRUE 79 | ;Sparse=FALSE 80 | 81 | ;[File3] 82 | ;FileName= 83 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.linux/sqliosim.nothrottle.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=1000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=1000000 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | ;UserCount=2 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=10 42 | 43 | [ReadAheadUser] 44 | ;UserCount=2 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=10 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | ;[File1] 64 | ;FileName=f:\sqliosim.mdx 65 | ;InitialSize=4096 66 | ;MaxSize=8192 67 | ;Increment=10 68 | ;Shrinkable=TRUE 69 | ;LogFile=FALSE 70 | ;Sparse=FALSE 71 | 72 | ;[File2] 73 | ;FileName=f:\sqliosim.ldx 74 | ;InitialSize=50 75 | ;MaxSize=50 76 | ;Increment=0 77 | ;Shrinkable=FALSE 78 | ;LogFile=TRUE 79 | ;Sparse=FALSE 80 | 81 | ;[File3] 82 | ;FileName= 83 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.windows/sqliosim.nothrottle.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | ;MaxMemoryMB=209 7 | StopOnError=TRUE 8 | TestCycles=1 9 | TestCycleDuration=300 10 | CacheHitRatio=1000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=1000000 15 | AllowIOBursts=TRUE 16 | UseScatterGather=TRUE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | ;UserCount=2 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=10 42 | 43 | [ReadAheadUser] 44 | ;UserCount=2 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=10 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | ;[File1] 64 | ;FileName=f:\sqliosim.mdx 65 | ;InitialSize=4096 66 | ;MaxSize=8192 67 | ;Increment=10 68 | ;Shrinkable=TRUE 69 | ;LogFile=FALSE 70 | ;Sparse=FALSE 71 | 72 | ;[File2] 73 | ;FileName=f:\sqliosim.ldx 74 | ;InitialSize=50 75 | ;MaxSize=50 76 | ;Increment=0 77 | ;Shrinkable=FALSE 78 | ;LogFile=TRUE 79 | ;Sparse=FALSE 80 | 81 | ;[File3] 82 | ;FileName= 83 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.linux/sqliosim.sparse.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | MaxMemoryMB=32 7 | StopOnError=TRUE 8 | TestCycles=3 9 | TestCycleDuration=600 10 | CacheHitRatio=1000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=10000 15 | AllowIOBursts=TRUE 16 | UseScatterGather=FALSE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | ;UserCount=2 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | ;UserCount=2 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | [File1] 64 | FileName=sqliosim.mdx 65 | InitialSize=1000 66 | MaxSize=1000 67 | Increment=10 68 | Shrinkable=FALSE 69 | LogFile=FALSE 70 | Sparse=FALSE 71 | 72 | [File2] 73 | FileName=sqliosim.ldx 74 | InitialSize=50 75 | MaxSize=50 76 | Increment=0 77 | Shrinkable=FALSE 78 | LogFile=TRUE 79 | Sparse=FALSE 80 | 81 | [File3] 82 | FileName=sqliosim.mdx:replica 83 | InitialSize=1000 84 | MaxSize=1000 85 | Increment=10 86 | Shrinkable=FALSE 87 | LogFile=FALSE 88 | Sparse=TRUE 89 | -------------------------------------------------------------------------------- /sqliosim/sqliosim.cfg.windows/sqliosim.sparse.cfg.ini: -------------------------------------------------------------------------------- 1 | [CONFIG] 2 | ErrorFile=sqliosim.log.xml 3 | ;CPUCount=2 4 | ;Affinity=0 5 | ;IOAffinity=0 6 | MaxMemoryMB=32 7 | StopOnError=TRUE 8 | TestCycles=3 9 | TestCycleDuration=600 10 | CacheHitRatio=1000 11 | NoBuffering=TRUE 12 | WriteThrough=TRUE 13 | MaxOutstandingIO=0 14 | TargetIODuration=10000 15 | AllowIOBursts=TRUE 16 | UseScatterGather=FALSE 17 | ForceReadAhead=TRUE 18 | DeleteFilesAtStartup=TRUE 19 | DeleteFilesAtShutdown=FALSE 20 | StampFiles=FALSE 21 | 22 | [RandomUser] 23 | ;UserCount=4 24 | JumpToNewRegionPercentage=500 25 | MinIOChainLength=50 26 | MaxIOChainLength=100 27 | RandomUserReadWriteRatio=9000 28 | MinLogPerBuffer=64 29 | MaxLogPerBuffer=8192 30 | RollbackChance=100 31 | SleepAfter=5 32 | YieldPercentage=0 33 | CPUSimulation=FALSE 34 | CPUCyclesMin=0 35 | CPUCyclesMax=0 36 | 37 | [AuditUser] 38 | ;UserCount=2 39 | BuffersValidated=64 40 | DelayAfterCycles=2 41 | AuditDelay=200 42 | 43 | [ReadAheadUser] 44 | ;UserCount=2 45 | BuffersRAMin=32 46 | BuffersRAMax=64 47 | DelayAfterCycles=2 48 | RADelay=200 49 | 50 | [BulkUpdateUser] 51 | ;UserCount=4 52 | BuffersBUMin=64 53 | BuffersBUMax=128 54 | DelayAfterCycles=2 55 | BUDelay=10 56 | 57 | [ShrinkUser] 58 | MinShrinkInterval=120 59 | MaxShrinkInterval=600 60 | MinExtends=1 61 | MaxExtends=20 62 | 63 | [File1] 64 | FileName=sqliosim.mdx 65 | InitialSize=1000 66 | MaxSize=1000 67 | Increment=10 68 | Shrinkable=FALSE 69 | LogFile=FALSE 70 | Sparse=FALSE 71 | 72 | [File2] 73 | FileName=sqliosim.ldx 74 | InitialSize=50 75 | MaxSize=50 76 | Increment=0 77 | Shrinkable=FALSE 78 | LogFile=TRUE 79 | Sparse=FALSE 80 | 81 | [File3] 82 | FileName=sqliosim.mdx:replica 83 | InitialSize=1000 84 | MaxSize=1000 85 | Increment=10 86 | Shrinkable=FALSE 87 | LogFile=FALSE 88 | Sparse=TRUE 89 | -------------------------------------------------------------------------------- /sample-scripts/availability_groups/read_scale_no_cluster/SQL AG 09 ReadOnly Routing.sql: -------------------------------------------------------------------------------- 1 | -- you can execute this only on the primary replica 2 | -- this script configures node for read-routing, setup the routing URL and also configure the routing list 3 | 4 | -- 5 | ALTER AVAILABILITY GROUP [ag1] 6 | MODIFY REPLICA ON 7 | N'ag-node000' WITH 8 | (SECONDARY_ROLE (ALLOW_CONNECTIONS = READ_ONLY)); 9 | GO 10 | ALTER AVAILABILITY GROUP [ag1] 11 | MODIFY REPLICA ON 12 | N'ag-node000' WITH 13 | (SECONDARY_ROLE (READ_ONLY_ROUTING_URL = N'TCP://ag-node000:1433')); 14 | GO 15 | 16 | ALTER AVAILABILITY GROUP [ag1] 17 | MODIFY REPLICA ON 18 | N'ag-node001' WITH 19 | (SECONDARY_ROLE (ALLOW_CONNECTIONS = READ_ONLY)); 20 | GO 21 | ALTER AVAILABILITY GROUP [ag1] 22 | MODIFY REPLICA ON 23 | N'ag-node001' WITH 24 | (SECONDARY_ROLE (READ_ONLY_ROUTING_URL = N'TCP://ag-node001:1433')); 25 | GO 26 | 27 | ALTER AVAILABILITY GROUP [ag1] 28 | MODIFY REPLICA ON 29 | N'ag-node002' WITH 30 | (SECONDARY_ROLE (ALLOW_CONNECTIONS = READ_ONLY)); 31 | GO 32 | ALTER AVAILABILITY GROUP [ag1] 33 | MODIFY REPLICA ON 34 | N'ag-node002' WITH 35 | (SECONDARY_ROLE (READ_ONLY_ROUTING_URL = N'TCP://ag-node002:1433')); 36 | GO 37 | 38 | ALTER AVAILABILITY GROUP [ag1] 39 | MODIFY REPLICA ON 40 | N'ag-node000' WITH 41 | (PRIMARY_ROLE (READ_ONLY_ROUTING_LIST=(('ag-node001','ag-node002'),'ag-node000'))); 42 | GO 43 | 44 | ALTER AVAILABILITY GROUP [ag1] 45 | MODIFY REPLICA ON 46 | N'ag-node001' WITH 47 | (PRIMARY_ROLE (READ_ONLY_ROUTING_LIST=(('ag-node000','ag-node002'),'ag-node001'))); 48 | GO 49 | 50 | ALTER AVAILABILITY GROUP [ag1] 51 | MODIFY REPLICA ON 52 | N'ag-node002' WITH 53 | (PRIMARY_ROLE (READ_ONLY_ROUTING_LIST=(('ag-node001','ag-node000'),'ag-node002'))); 54 | GO 55 | -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | ## Security 4 | 5 | Microsoft takes the security of our software products and services seriously, which includes all source code repositories managed through our GitHub organizations, which include [Microsoft](https://github.com/Microsoft), [Azure](https://github.com/Azure), [DotNet](https://github.com/dotnet), [AspNet](https://github.com/aspnet), [Xamarin](https://github.com/xamarin), and [our GitHub organizations](https://opensource.microsoft.com/). 6 | 7 | If you believe you have found a security vulnerability in any Microsoft-owned repository that meets [Microsoft's definition of a security vulnerability](https://aka.ms/opensource/security/definition), please report it to us as described below. 8 | 9 | ## Reporting Security Issues 10 | 11 | **Please do not report security vulnerabilities through public GitHub issues.** 12 | 13 | Instead, please report them to the Microsoft Security Response Center (MSRC) at [https://msrc.microsoft.com/create-report](https://aka.ms/opensource/security/create-report). 14 | 15 | If you prefer to submit without logging in, send email to [secure@microsoft.com](mailto:secure@microsoft.com). If possible, encrypt your message with our PGP key; please download it from the [Microsoft Security Response Center PGP Key page](https://aka.ms/opensource/security/pgpkey). 16 | 17 | You should receive a response within 24 hours. If for some reason you do not, please follow up via email to ensure we received your original message. Additional information can be found at [microsoft.com/msrc](https://aka.ms/opensource/security/msrc). 18 | 19 | Please include the requested information listed below (as much as you can provide) to help us better understand the nature and scope of the possible issue: 20 | 21 | * Type of issue (e.g. buffer overflow, SQL injection, cross-site scripting, etc.) 22 | * Full paths of source file(s) related to the manifestation of the issue 23 | * The location of the affected source code (tag/branch/commit or direct URL) 24 | * Any special configuration required to reproduce the issue 25 | * Step-by-step instructions to reproduce the issue 26 | * Proof-of-concept or exploit code (if possible) 27 | * Impact of the issue, including how an attacker might exploit the issue 28 | 29 | This information will help us triage your report more quickly. 30 | 31 | If you are reporting for a bug bounty, more complete reports can contribute to a higher bounty award. Please visit our [Microsoft Bug Bounty Program](https://aka.ms/opensource/security/bounty) page for more details about our active programs. 32 | 33 | ## Preferred Languages 34 | 35 | We prefer all communications to be in English. 36 | 37 | ## Policy 38 | 39 | Microsoft follows the principle of [Coordinated Vulnerability Disclosure](https://aka.ms/opensource/security/cvd). 40 | 41 | 42 | -------------------------------------------------------------------------------- /sample-scripts/extended_events/Read_xel_files.sql: -------------------------------------------------------------------------------- 1 | -- read the extended event data from the file and store it into a table 2 | select * into tbl_fn_xe_read_file 3 | from sys.fn_xe_file_target_read_file('file_name.xel', null, null, null); 4 | go 5 | 6 | -- review the structure of the table and understand the columns 7 | select top 100 * from tbl_fn_xe_read_file 8 | go 9 | 10 | -- get a list of all events captured in the XE file 11 | select distinct [object_name], count(*) from tbl_fn_xe_read_file 12 | group by [object_name] 13 | go 14 | 15 | -- now extract the events of interest into a seperate table so we can process them and apply transformations quickly 16 | select timestamp_utc, convert(XML, event_data) as event_data into tbl_HadrMsgTypePrimaryProgressMsg 17 | from tbl_fn_xe_read_file 18 | where [object_name] = 'hadr_transport_dump_message' 19 | go 20 | 21 | -- review a few records to understand the fields present in the XML document (event, data, actions) 22 | select top 100 * from tbl_HadrMsgTypePrimaryProgressMsg 23 | go 24 | 25 | -- start shredding the rows and extract the event, data and actions 26 | SELECT event_data.value('(event/@name)[1]', 'varchar(50)') AS event_name 27 | , event_data.value('(event/@timestamp)[1]', 'varchar(50)') AS [TIMESTAMP] 28 | ,event_data.value('(event/data[@name="operation"]/text)[1]','nvarchar(1024)') AS [c_operation] 29 | ,event_data.value('(event/data[@name="operation_reason"]/text)[1]','nvarchar(1024)') AS [c_operation_reason] 30 | ,event_data.value('(event/data[@name="sequence_number"]/value)[1]','int') AS [c_sequence_number] 31 | ,event_data.value('(event/data[@name="acknowledgment_number"]/value)[1]','int') AS [c_acknowledgment_number] 32 | ,event_data.value('(event/data[@name="message_type"]/text)[1]','nvarchar(1024)') AS [c_message_type] 33 | ,event_data.value('(event/data[@name="message_log_id"]/value)[1]','nvarchar(1024)') AS c_message_log_id 34 | ,event_data.value('(event/data[@name="availability_group_id"]/value)[1]','nvarchar(1024)') AS c_availability_group_id 35 | ,event_data.value('(event/data[@name="local_availability_replica_id"]/value)[1]','nvarchar(1024)') AS c_local_availability_replica_id 36 | ,event_data.value('(event/data[@name="target_availability_replica_id"]/value)[1]','nvarchar(1024)') AS c_target_availability_replica_id 37 | ,event_data.value('(event/data[@name="connection_session_id"]/value)[1]','nvarchar(1024)') AS c_connection_session_id 38 | ,event_data.value('(event/data[@name="database_replica_id"]/value)[1]','nvarchar(1024)') AS c_database_replica_id 39 | ,event_data.value('(event/action[@name="session_id"]/value)[1]','int') AS a_session_id 40 | ,event_data.value('(event/action[@name="system_thread_id"]/value)[1]','int') AS a_system_thread_id 41 | INTO tbl_HadrMsgTypePrimaryProgressMsg_shred 42 | FROM tbl_HadrMsgTypePrimaryProgressMsg AS evts 43 | GO 44 | 45 | -- get aggregate information about the type of events 46 | select [c_message_type], [c_operation], [c_operation_reason], count(*) as Event_Count 47 | from tbl_HadrMsgTypePrimaryProgressMsg_shred where c_message_type = 'HadrMsgTypePrimaryProgressMsg' 48 | group by [c_message_type], [c_operation], [c_operation_reason] 49 | order by [c_message_type], [c_operation], [c_operation_reason] 50 | go 51 | 52 | -- review a sample of the rows 53 | select top 100 * 54 | from tbl_HadrMsgTypePrimaryProgressMsg_shred 55 | where [c_message_type] = 'HadrMsgTypePrimaryProgressMsg' 56 | go 57 | -------------------------------------------------------------------------------- /sample-scripts/performance/Index_Maintenance_Recommendations.sql: -------------------------------------------------------------------------------- 1 | -- ============================================= 2 | -- Author: Sait ORHAN 3 | -- Create date: 2020-12-10 4 | -- Description: Getting indexes, avg fragmentations, gives advice for index, creates reorganize and rebuild queries, table space in MB 5 | -- ============================================= 6 | 7 | declare @indexName nvarchar(255) 8 | declare @schemaName nvarchar(255) 9 | declare @tableName nvarchar(255) 10 | 11 | declare @rowCount int 12 | declare @UsedMB numeric(36, 2) 13 | declare @UnusedMB numeric(36, 2) 14 | declare @TotalMB numeric(36, 2) 15 | 16 | if OBJECT_ID('tempdb..#Indexes') is not null 17 | BEGIN 18 | DROP TABLE #Indexes 19 | END 20 | 21 | -- Create temp table 22 | CREATE TABLE #Indexes( 23 | Id int primary key identity, 24 | SchemaName nvarchar(255), 25 | TableName nvarchar(255), 26 | IndexName nvarchar(255), 27 | IndexType nvarchar(255), 28 | Avg_fragmentation float, 29 | ActionNeed nvarchar(255), 30 | StatsUpdated datetime, 31 | [RowCount] int, 32 | TableUsedMB numeric(36, 3), 33 | TableUnusedMB numeric(36, 3), 34 | TableTotalMB numeric(36, 3), 35 | ReorganizeIndex nvarchar(1000), 36 | ReorganizeTable nvarchar(1000), 37 | RebuildIndex nvarchar(1000), 38 | RebuildTable nvarchar(1000), 39 | UpdateStats nvarchar(1000), 40 | ) 41 | 42 | -- getting infos 43 | INSERT INTO #Indexes( 44 | SchemaName, 45 | TableName, 46 | IndexName, 47 | IndexType, 48 | Avg_fragmentation , 49 | ActionNeed, 50 | StatsUpdated, 51 | ReorganizeIndex, 52 | ReorganizeTable, 53 | RebuildIndex , 54 | RebuildTable, 55 | UpdateStats 56 | ) 57 | 58 | SELECT 59 | s.name [Schema], -- schema name 60 | t.name TableName, -- table name 61 | i.name IndexName, -- index name 62 | frag.index_type_desc IndexType, -- index type 63 | frag.avg_fragmentation_in_percent, -- fragmentation in percent 64 | 65 | (CASE 66 | WHEN frag.avg_fragmentation_in_percent < 5 THEN 'Nothing' 67 | WHEN frag.avg_fragmentation_in_percent between 5 and 30 THEN 'Reorganize' 68 | WHEN frag.avg_fragmentation_in_percent > 30 THEN 'Rebuild' end), -- advice for action 69 | STATS_DATE(t.object_id, i.index_id), 70 | CONCAT('ALTER INDEX [',i.name ,'] ON [', s.name, '].[' , t.name , '] REORGANIZE;') [ReorganizeIndex], -- index reorganize query 71 | CONCAT('ALTER INDEX ALL ON [', s.name, '].[' , t.name ,'] REORGANIZE;') [ReorganizeAllTable], -- reorganize all index on table 72 | CONCAT('ALTER INDEX [', i.name, '] ON [', s.name, '].[' , t.name, '] REBUILD ;') [RebuildIndex], -- index rebuid query 73 | CONCAT('ALTER INDEX ALL ON [', s.name, '].[' , t.name ,'] REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON, ONLINE = ON);') [RebuildTable], -- rebuild all index on table 74 | CONCAT('UPDATE STATISTICS [' , s.name , '].[' , t.name, ']') 75 | FROM sys.tables t 76 | JOIN sys.schemas s ON t.schema_id = s.schema_id 77 | JOIN sys.indexes i ON t.object_id = i.object_id 78 | JOIN sys.dm_db_index_physical_stats(DB_ID(), null, null, null, null) as frag on frag.object_id = t.object_id and frag.index_id = i.index_id 79 | WHERE t.type = 'U' and frag.alloc_unit_type_desc = 'IN_ROW_DATA' 80 | ORDER BY frag.avg_fragmentation_in_percent desc 81 | 82 | DECLARE saitorhan_cls CURSOR FOR 83 | 84 | SELECT 85 | i.name, 86 | s.Name, -- AS SchemaName, 87 | t.Name, -- AS TableName, 88 | p.rows, -- AS RowCounts, 89 | CAST(ROUND((SUM(a.used_pages) / 128.00), 3) AS NUMERIC(36, 3)), -- AS Used_MB, 90 | CAST(ROUND((SUM(a.total_pages) - SUM(a.used_pages)) / 128.00, 3) AS NUMERIC(36, 2)),-- AS Unused_MB, 91 | CAST(ROUND((SUM(a.total_pages) / 128.00), 2) AS NUMERIC(36, 3)) -- AS Total_MB 92 | FROM sys.tables t 93 | INNER JOIN sys.indexes i ON t.object_id = i.object_id 94 | INNER JOIN sys.partitions p ON i.object_id = p.object_id AND i.index_id = p.index_id 95 | INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id 96 | INNER JOIN sys.schemas s ON t.schema_id = s.schema_id 97 | GROUP BY t.Name, s.Name, p.Rows, i.name 98 | ORDER BY s.Name, t.Name 99 | 100 | OPEN saitorhan_cls 101 | FETCH NEXT FROM saitorhan_cls into @indexName, @schemaName, @tableName ,@rowCount, @UsedMB, @UnusedMB, @TotalMB 102 | 103 | WHILE @@FETCH_STATUS = 0 104 | BEGIN 105 | 106 | UPDATE #Indexes SET [RowCount] = @rowCount, TableUsedMB = @UsedMB, TableUnusedMB = @UnusedMB, TableTotalMB = @TotalMB where TableName = @tableName and SchemaName = @schemaName 107 | 108 | FETCH NEXT FROM saitorhan_cls into @indexName, @schemaName, @tableName ,@rowCount, @UsedMB, @UnusedMB, @TotalMB 109 | END 110 | CLOSE saitorhan_cls 111 | DEALLOCATE saitorhan_cls 112 | 113 | 114 | SELECT * FROM #Indexes ORDER BY TableTotalMB DESC 115 | 116 | -------------------------------------------------------------------------------- /sample-scripts/security/application_roles/UseAppRoleToViewServerInfo.sql: -------------------------------------------------------------------------------- 1 | -- ============================================================================ 2 | -- - Application role access to server information - UseAppRoleToViewServerInfo.sql 3 | -- 4 | -- 5 | -- This code is companion code that shows an example of application role access 6 | -- to server information by using a certificate-signed procedure. 7 | -- 8 | -- ============================================================================ 9 | 10 | USE master 11 | GO 12 | 13 | CREATE DATABASE approle_db ; 14 | GO 15 | 16 | CREATE LOGIN some_login WITH PASSWORD = 'SomePa$$word!' ; 17 | GO 18 | 19 | USE approle_db 20 | GO 21 | 22 | CREATE USER some_user FOR LOGIN some_login 23 | GO 24 | 25 | CREATE APPLICATION ROLE an_approle WITH PASSWORD = 'SomeAppRolePa$$word!' ; 26 | GO 27 | 28 | --------------------------------------------------------------------- 29 | -- This section shows how to use a certificate to authenticate 30 | -- a signed stored procedure. 31 | --------------------------------------------------------------------- 32 | 33 | CREATE LOGIN execute_as_login WITH PASSWORD = 'SomePa$$word!' ; 34 | GO 35 | 36 | USE master 37 | GO 38 | 39 | GRANT VIEW ANY DEFINITION TO execute_as_login ; 40 | GRANT VIEW SERVER STATE TO execute_as_login ; 41 | GO 42 | 43 | USE approle_db 44 | GO 45 | 46 | CREATE USER execute_as_user FOR LOGIN execute_as_login ; 47 | GO 48 | 49 | -- 50 | -- You must use EXECUTE AS 'execute_as_user' here because the application role 51 | -- does not have a server identity. The application role cannot use 52 | -- the certificate permissions on the server. Therefore, you 53 | -- need a new execution context to which you can grant 54 | -- the needed VIEW* permissions. 55 | -- 56 | CREATE PROC usp_access_server_system_tables 57 | WITH EXECUTE AS 'execute_as_user' 58 | AS 59 | SELECT * FROM master.dbo.syslogins ; 60 | SELECT * FROM master.dbo.sysprocesses ; 61 | GO 62 | 63 | GRANT EXECUTE ON usp_access_server_system_tables TO an_approle ; 64 | GO 65 | 66 | CREATE CERTIFICATE signing_cert ENCRYPTION BY PASSWORD = 'SomeCertPa$$word' 67 | WITH SUBJECT = 'Signing Cert' ; 68 | GO 69 | 70 | BACKUP CERTIFICATE signing_cert TO FILE = 'signing_cert.cer' ; 71 | GO 72 | 73 | ADD SIGNATURE TO usp_access_server_system_tables 74 | BY CERTIFICATE signing_cert WITH PASSWORD = 'SomeCertPa$$word' ; 75 | GO 76 | 77 | --------------------------------------------------------------------- 78 | -- We must create a copy of the signing certificate in the target 79 | -- database. In this case, the target database is the master database. 80 | -- This copy of the signing certificate can vouch 81 | -- for the execution contexts that enter this database from the 82 | -- signed procedure. 83 | --------------------------------------------------------------------- 84 | USE master 85 | GO 86 | 87 | CREATE CERTIFICATE signing_cert FROM FILE = 'signing_cert.cer' ; 88 | GO 89 | 90 | -- 91 | -- Because the VIEW* permissions in question are server-level permissions, 92 | -- we need an AUTHENTICATE SERVER on a login-mapped certificate. 93 | -- 94 | CREATE LOGIN signing_cert_login FROM CERTIFICATE signing_cert ; 95 | GO 96 | 97 | GRANT AUTHENTICATE SERVER TO signing_cert_login 98 | GO 99 | 100 | 101 | --------------------------------------------------------------------- 102 | -- Now you can open a new connection as "some_login" and 103 | -- set the application role. Then, call the "usp_access_server_system_tables" 104 | -- procedure, and obtain verification that you can access server-level information 105 | -- when the application role-based application runs. 106 | 107 | 108 | 109 | 110 | -------------------------------------------------- 111 | -- Connect as some_login (open a new connection) 112 | -------------------------------------------------- 113 | 114 | 115 | USE approle_db 116 | GO 117 | EXEC sp_setapprole 'an_approle', 'SomeAppRolePa$$word!' 118 | GO 119 | EXEC usp_access_server_system_tables 120 | GO 121 | 122 | 123 | 124 | --------------------------------------------------------------------- 125 | 126 | 127 | --------------------------------------------------------------------- 128 | -- Go back to original connection to ... 129 | -- Clean up after the procedure. 130 | 131 | --------------------------------------------------------------------- 132 | 133 | 134 | USE master 135 | GO 136 | DROP DATABASE approle_db ; 137 | GO 138 | 139 | DROP LOGIN some_login; 140 | GO 141 | 142 | DROP LOGIN execute_as_login; 143 | GO 144 | 145 | DROP LOGIN signing_cert_login ; 146 | GO 147 | 148 | DROP CERTIFICATE signing_cert; 149 | GO 150 | 151 | -- 152 | -- Make sure to delete the certificate file. For example, delete 153 | -- C:\Program Files\Microsoft SQL Server\MSSQL.\MSSQL\Data\signing_cert.cer 154 | -- 155 | 156 | -------------------------------------------------------------------------------- /sample-scripts/backup_restore/SQL_Express_Backups.sql: -------------------------------------------------------------------------------- 1 | -- Copyright ? Microsoft Corporation. All Rights Reserved. 2 | -- This code released under the terms of the 3 | -- Microsoft Public License (MS-PL, http://opensource.org/licenses/ms-pl.html.) 4 | USE [master] 5 | GO 6 | /****** Object: StoredProcedure [dbo].[sp_BackupDatabases] ******/ 7 | SET ANSI_NULLS ON 8 | GO 9 | SET QUOTED_IDENTIFIER ON 10 | GO 11 | -- ============================================= 12 | -- Author: Microsoft 13 | -- Create date: 2010-02-06 14 | -- Description: Backup Databases for SQLExpress 15 | -- Parameter1: databaseName 16 | -- Parameter2: backupType F=full, D=differential, L=log 17 | -- Parameter3: backup file location 18 | -- ============================================= 19 | CREATE PROCEDURE [dbo].[sp_BackupDatabases] 20 | @databaseName sysname = null, 21 | @backupType CHAR(1), 22 | @backupLocation nvarchar(200) 23 | AS 24 | SET NOCOUNT ON; 25 | DECLARE @DBs TABLE 26 | ( 27 | ID int IDENTITY PRIMARY KEY, 28 | DBNAME nvarchar(500) 29 | ) 30 | -- Pick out only databases which are online in case ALL databases are chosen to be backed up 31 | -- If specific database is chosen to be backed up only pick that out from @DBs 32 | INSERT INTO @DBs (DBNAME) 33 | SELECT Name FROM master.sys.databases 34 | where state=0 35 | AND name= ISNULL(@databaseName ,name) 36 | ORDER BY Name 37 | -- Filter out databases which do not need to backed up 38 | IF @backupType='F' 39 | BEGIN 40 | DELETE @DBs where DBNAME IN ('tempdb','Northwind','pubs','AdventureWorks') 41 | END 42 | ELSE IF @backupType='D' 43 | BEGIN 44 | DELETE @DBs where DBNAME IN ('tempdb','Northwind','pubs','master','AdventureWorks') 45 | END 46 | ELSE IF @backupType='L' 47 | BEGIN 48 | DELETE @DBs where DBNAME IN ('tempdb','Northwind','pubs','master','AdventureWorks') 49 | END 50 | ELSE 51 | BEGIN 52 | RETURN 53 | END 54 | -- Declare variables 55 | DECLARE @BackupName nvarchar(100) 56 | DECLARE @BackupFile nvarchar(300) 57 | DECLARE @DBNAME nvarchar(300) 58 | DECLARE @sqlCommand NVARCHAR(1000) 59 | DECLARE @dateTime NVARCHAR(20) 60 | DECLARE @Loop int 61 | -- Loop through the databases one by one 62 | SELECT @Loop = min(ID) FROM @DBs 63 | WHILE @Loop IS NOT NULL 64 | BEGIN 65 | -- Database Names have to be in [dbname] format since some have - or _ in their name 66 | SET @DBNAME = '['+(SELECT DBNAME FROM @DBs WHERE ID = @Loop)+']' 67 | -- Set the current date and time n yyyyhhmmss format 68 | SET @dateTime = REPLACE(CONVERT(VARCHAR, GETDATE(),101),'/','') + '_' + REPLACE(CONVERT(VARCHAR, GETDATE(),108),':','') 69 | -- Create backup filename in path\filename.extension format for full,diff and log backups 70 | IF @backupType = 'F' 71 | SET @BackupFile = @backupLocation+REPLACE(REPLACE(@DBNAME, '[',''),']','')+ '_FULL_'+ @dateTime+ '.BAK' 72 | ELSE IF @backupType = 'D' 73 | SET @BackupFile = @backupLocation+REPLACE(REPLACE(@DBNAME, '[',''),']','')+ '_DIFF_'+ @dateTime+ '.BAK' 74 | ELSE IF @backupType = 'L' 75 | SET @BackupFile = @backupLocation+REPLACE(REPLACE(@DBNAME, '[',''),']','')+ '_LOG_'+ @dateTime+ '.TRN' 76 | -- Provide the backup a name for storing in the media 77 | IF @backupType = 'F' 78 | SET @BackupName = REPLACE(REPLACE(@DBNAME,'[',''),']','') +' full backup for '+ @dateTime 79 | IF @backupType = 'D' 80 | SET @BackupName = REPLACE(REPLACE(@DBNAME,'[',''),']','') +' differential backup for '+ @dateTime 81 | IF @backupType = 'L' 82 | SET @BackupName = REPLACE(REPLACE(@DBNAME,'[',''),']','') +' log backup for '+ @dateTime 83 | -- Generate the dynamic SQL command to be executed 84 | IF @backupType = 'F' 85 | BEGIN 86 | SET @sqlCommand = 'BACKUP DATABASE ' +@DBNAME+ ' TO DISK = '''+@BackupFile+ ''' WITH INIT, NAME= ''' +@BackupName+''', NOSKIP, NOFORMAT' 87 | END 88 | IF @backupType = 'D' 89 | BEGIN 90 | SET @sqlCommand = 'BACKUP DATABASE ' +@DBNAME+ ' TO DISK = '''+@BackupFile+ ''' WITH DIFFERENTIAL, INIT, NAME= ''' +@BackupName+''', NOSKIP, NOFORMAT' 91 | END 92 | IF @backupType = 'L' 93 | BEGIN 94 | SET @sqlCommand = 'BACKUP LOG ' +@DBNAME+ ' TO DISK = '''+@BackupFile+ ''' WITH INIT, NAME= ''' +@BackupName+''', NOSKIP, NOFORMAT' 95 | END 96 | -- Execute the generated SQL command 97 | EXEC(@sqlCommand) 98 | -- Goto the next database 99 | SELECT @Loop = min(ID) FROM @DBs where ID>@Loop 100 | END -------------------------------------------------------------------------------- /sample-scripts/security/manage-logins-permissions/sp_help_revlogin.sql: -------------------------------------------------------------------------------- 1 | /*Note This script creates two stored procedures in the master database. The procedures are named sp_hexadecimal and sp_help_revlogin. */ 2 | -- Create stored procedure sp_hexadecimal 3 | USE master 4 | GO 5 | IF OBJECT_ID ('sp_hexadecimal') IS NOT NULL 6 | DROP PROCEDURE sp_hexadecimal 7 | GO 8 | CREATE PROCEDURE sp_hexadecimal 9 | @binvalue varbinary(256), 10 | @hexvalue varchar (514) OUTPUT 11 | AS 12 | DECLARE @charvalue varchar (514) 13 | DECLARE @i int 14 | DECLARE @length int 15 | DECLARE @hexstring char(16) 16 | SELECT @charvalue = '0x' 17 | SELECT @i = 1 18 | SELECT @length = DATALENGTH (@binvalue) 19 | SELECT @hexstring = '0123456789ABCDEF' 20 | WHILE (@i <= @length) 21 | BEGIN 22 | DECLARE @tempint int 23 | DECLARE @firstint int 24 | DECLARE @secondint int 25 | SELECT @tempint = CONVERT(int, SUBSTRING(@binvalue,@i,1)) 26 | SELECT @firstint = FLOOR(@tempint/16) 27 | SELECT @secondint = @tempint - (@firstint*16) 28 | SELECT @charvalue = @charvalue + 29 | SUBSTRING(@hexstring, @firstint+1, 1) + 30 | SUBSTRING(@hexstring, @secondint+1, 1) 31 | SELECT @i = @i + 1 32 | END 33 | 34 | SELECT @hexvalue = @charvalue 35 | GO 36 | 37 | -- Create stored procedure sp_help_revlogin 38 | IF OBJECT_ID ('sp_help_revlogin') IS NOT NULL 39 | DROP PROCEDURE sp_help_revlogin 40 | GO 41 | CREATE PROCEDURE sp_help_revlogin @login_name sysname = NULL AS 42 | DECLARE @name sysname 43 | DECLARE @type varchar (1) 44 | DECLARE @hasaccess int 45 | DECLARE @denylogin int 46 | DECLARE @is_disabled int 47 | DECLARE @PWD_varbinary varbinary (256) 48 | DECLARE @PWD_string varchar (514) 49 | DECLARE @SID_varbinary varbinary (85) 50 | DECLARE @SID_string varchar (514) 51 | DECLARE @tmpstr varchar (1024) 52 | DECLARE @is_policy_checked varchar (3) 53 | DECLARE @is_expiration_checked varchar (3) 54 | 55 | DECLARE @defaultdb sysname 56 | 57 | IF (@login_name IS NULL) 58 | DECLARE login_curs CURSOR FOR 59 | 60 | SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM 61 | sys.server_principals p LEFT JOIN sys.syslogins l 62 | ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name <> 'sa' 63 | ELSE 64 | DECLARE login_curs CURSOR FOR 65 | 66 | 67 | SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM 68 | sys.server_principals p LEFT JOIN sys.syslogins l 69 | ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name = @login_name 70 | OPEN login_curs 71 | 72 | FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin 73 | IF (@@fetch_status = -1) 74 | BEGIN 75 | PRINT 'No login(s) found.' 76 | CLOSE login_curs 77 | DEALLOCATE login_curs 78 | RETURN -1 79 | END 80 | SET @tmpstr = '/* sp_help_revlogin script ' 81 | PRINT @tmpstr 82 | SET @tmpstr = '** Generated ' + CONVERT (varchar, GETDATE()) + ' on ' + @@SERVERNAME + ' */' 83 | PRINT @tmpstr 84 | PRINT '' 85 | WHILE (@@fetch_status <> -1) 86 | BEGIN 87 | IF (@@fetch_status <> -2) 88 | BEGIN 89 | PRINT '' 90 | SET @tmpstr = '-- Login: ' + @name 91 | PRINT @tmpstr 92 | IF (@type IN ( 'G', 'U')) 93 | BEGIN -- NT authenticated account/group 94 | 95 | SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']' 96 | END 97 | ELSE BEGIN -- SQL Server authentication 98 | -- obtain password and sid 99 | SET @PWD_varbinary = CAST( LOGINPROPERTY( @name, 'PasswordHash' ) AS varbinary (256) ) 100 | EXEC sp_hexadecimal @PWD_varbinary, @PWD_string OUT 101 | EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT 102 | 103 | -- obtain password policy state 104 | SELECT @is_policy_checked = CASE is_policy_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END FROM sys.sql_logins WHERE name = @name 105 | SELECT @is_expiration_checked = CASE is_expiration_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END FROM sys.sql_logins WHERE name = @name 106 | 107 | SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' WITH PASSWORD = ' + @PWD_string + ' HASHED, SID = ' + @SID_string + ', DEFAULT_DATABASE = [' + @defaultdb + ']' 108 | 109 | IF ( @is_policy_checked IS NOT NULL ) 110 | BEGIN 111 | SET @tmpstr = @tmpstr + ', CHECK_POLICY = ' + @is_policy_checked 112 | END 113 | IF ( @is_expiration_checked IS NOT NULL ) 114 | BEGIN 115 | SET @tmpstr = @tmpstr + ', CHECK_EXPIRATION = ' + @is_expiration_checked 116 | END 117 | END 118 | IF (@denylogin = 1) 119 | BEGIN -- login is denied access 120 | SET @tmpstr = @tmpstr + '; DENY CONNECT SQL TO ' + QUOTENAME( @name ) 121 | END 122 | ELSE IF (@hasaccess = 0) 123 | BEGIN -- login exists but does not have access 124 | SET @tmpstr = @tmpstr + '; REVOKE CONNECT SQL TO ' + QUOTENAME( @name ) 125 | END 126 | IF (@is_disabled = 1) 127 | BEGIN -- login is disabled 128 | SET @tmpstr = @tmpstr + '; ALTER LOGIN ' + QUOTENAME( @name ) + ' DISABLE' 129 | END 130 | PRINT @tmpstr 131 | END 132 | 133 | FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin 134 | END 135 | CLOSE login_curs 136 | DEALLOCATE login_curs 137 | RETURN 0 138 | GO 139 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ## Ignore Visual Studio temporary files, build results, and 2 | ## files generated by popular Visual Studio add-ons. 3 | ## 4 | ## Get latest from https://github.com/github/gitignore/blob/master/VisualStudio.gitignore 5 | 6 | # User-specific files 7 | *.suo 8 | *.user 9 | *.userosscache 10 | *.sln.docstates 11 | 12 | # User-specific files (MonoDevelop/Xamarin Studio) 13 | *.userprefs 14 | 15 | # Build results 16 | [Dd]ebug/ 17 | [Dd]ebugPublic/ 18 | [Rr]elease/ 19 | [Rr]eleases/ 20 | x64/ 21 | x86/ 22 | bld/ 23 | [Bb]in/ 24 | [Oo]bj/ 25 | [Ll]og/ 26 | 27 | # Visual Studio 2015/2017 cache/options directory 28 | .vs/ 29 | # Uncomment if you have tasks that create the project's static files in wwwroot 30 | #wwwroot/ 31 | 32 | # Visual Studio 2017 auto generated files 33 | Generated\ Files/ 34 | 35 | # MSTest test Results 36 | [Tt]est[Rr]esult*/ 37 | [Bb]uild[Ll]og.* 38 | 39 | # NUNIT 40 | *.VisualState.xml 41 | TestResult.xml 42 | 43 | # Build Results of an ATL Project 44 | [Dd]ebugPS/ 45 | [Rr]eleasePS/ 46 | dlldata.c 47 | 48 | # Benchmark Results 49 | BenchmarkDotNet.Artifacts/ 50 | 51 | # .NET Core 52 | project.lock.json 53 | project.fragment.lock.json 54 | artifacts/ 55 | **/Properties/launchSettings.json 56 | 57 | # StyleCop 58 | StyleCopReport.xml 59 | 60 | # Files built by Visual Studio 61 | *_i.c 62 | *_p.c 63 | *_i.h 64 | *.ilk 65 | *.meta 66 | *.obj 67 | *.iobj 68 | *.pch 69 | *.pdb 70 | *.ipdb 71 | *.pgc 72 | *.pgd 73 | *.rsp 74 | *.sbr 75 | *.tlb 76 | *.tli 77 | *.tlh 78 | *.tmp 79 | *.tmp_proj 80 | *.log 81 | *.vspscc 82 | *.vssscc 83 | .builds 84 | *.pidb 85 | *.svclog 86 | *.scc 87 | 88 | # Chutzpah Test files 89 | _Chutzpah* 90 | 91 | # Visual C++ cache files 92 | ipch/ 93 | *.aps 94 | *.ncb 95 | *.opendb 96 | *.opensdf 97 | *.sdf 98 | *.cachefile 99 | *.VC.db 100 | *.VC.VC.opendb 101 | 102 | # Visual Studio profiler 103 | *.psess 104 | *.vsp 105 | *.vspx 106 | *.sap 107 | 108 | # Visual Studio Trace Files 109 | *.e2e 110 | 111 | # TFS 2012 Local Workspace 112 | $tf/ 113 | 114 | # Guidance Automation Toolkit 115 | *.gpState 116 | 117 | # ReSharper is a .NET coding add-in 118 | _ReSharper*/ 119 | *.[Rr]e[Ss]harper 120 | *.DotSettings.user 121 | 122 | # JustCode is a .NET coding add-in 123 | .JustCode 124 | 125 | # TeamCity is a build add-in 126 | _TeamCity* 127 | 128 | # DotCover is a Code Coverage Tool 129 | *.dotCover 130 | 131 | # AxoCover is a Code Coverage Tool 132 | .axoCover/* 133 | !.axoCover/settings.json 134 | 135 | # Visual Studio code coverage results 136 | *.coverage 137 | *.coveragexml 138 | 139 | # NCrunch 140 | _NCrunch_* 141 | .*crunch*.local.xml 142 | nCrunchTemp_* 143 | 144 | # MightyMoose 145 | *.mm.* 146 | AutoTest.Net/ 147 | 148 | # Web workbench (sass) 149 | .sass-cache/ 150 | 151 | # Installshield output folder 152 | [Ee]xpress/ 153 | 154 | # DocProject is a documentation generator add-in 155 | DocProject/buildhelp/ 156 | DocProject/Help/*.HxT 157 | DocProject/Help/*.HxC 158 | DocProject/Help/*.hhc 159 | DocProject/Help/*.hhk 160 | DocProject/Help/*.hhp 161 | DocProject/Help/Html2 162 | DocProject/Help/html 163 | 164 | # Click-Once directory 165 | publish/ 166 | 167 | # Publish Web Output 168 | *.[Pp]ublish.xml 169 | *.azurePubxml 170 | # Note: Comment the next line if you want to checkin your web deploy settings, 171 | # but database connection strings (with potential passwords) will be unencrypted 172 | *.pubxml 173 | *.publishproj 174 | 175 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 176 | # checkin your Azure Web App publish settings, but sensitive information contained 177 | # in these scripts will be unencrypted 178 | PublishScripts/ 179 | 180 | # NuGet Packages 181 | *.nupkg 182 | # The packages folder can be ignored because of Package Restore 183 | **/[Pp]ackages/* 184 | # except build/, which is used as an MSBuild target. 185 | !**/[Pp]ackages/build/ 186 | # Uncomment if necessary however generally it will be regenerated when needed 187 | #!**/[Pp]ackages/repositories.config 188 | # NuGet v3's project.json files produces more ignorable files 189 | *.nuget.props 190 | *.nuget.targets 191 | 192 | # Microsoft Azure Build Output 193 | csx/ 194 | *.build.csdef 195 | 196 | # Microsoft Azure Emulator 197 | ecf/ 198 | rcf/ 199 | 200 | # Windows Store app package directories and files 201 | AppPackages/ 202 | BundleArtifacts/ 203 | Package.StoreAssociation.xml 204 | _pkginfo.txt 205 | *.appx 206 | 207 | # Visual Studio cache files 208 | # files ending in .cache can be ignored 209 | *.[Cc]ache 210 | # but keep track of directories ending in .cache 211 | !*.[Cc]ache/ 212 | 213 | # Others 214 | ClientBin/ 215 | ~$* 216 | *~ 217 | *.dbmdl 218 | *.dbproj.schemaview 219 | *.jfm 220 | *.pfx 221 | *.publishsettings 222 | orleans.codegen.cs 223 | 224 | # Including strong name files can present a security risk 225 | # (https://github.com/github/gitignore/pull/2483#issue-259490424) 226 | #*.snk 227 | 228 | # Since there are multiple workflows, uncomment next line to ignore bower_components 229 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 230 | #bower_components/ 231 | 232 | # RIA/Silverlight projects 233 | Generated_Code/ 234 | 235 | # Backup & report files from converting an old project file 236 | # to a newer Visual Studio version. Backup files are not needed, 237 | # because we have git ;-) 238 | _UpgradeReport_Files/ 239 | Backup*/ 240 | UpgradeLog*.XML 241 | UpgradeLog*.htm 242 | ServiceFabricBackup/ 243 | *.rptproj.bak 244 | 245 | # SQL Server files 246 | *.mdf 247 | *.ldf 248 | *.ndf 249 | 250 | # Business Intelligence projects 251 | *.rdl.data 252 | *.bim.layout 253 | *.bim_*.settings 254 | *.rptproj.rsuser 255 | 256 | # Microsoft Fakes 257 | FakesAssemblies/ 258 | 259 | # GhostDoc plugin setting file 260 | *.GhostDoc.xml 261 | 262 | # Node.js Tools for Visual Studio 263 | .ntvs_analysis.dat 264 | node_modules/ 265 | 266 | # Visual Studio 6 build log 267 | *.plg 268 | 269 | # Visual Studio 6 workspace options file 270 | *.opt 271 | 272 | # Visual Studio 6 auto-generated workspace file (contains which files were open etc.) 273 | *.vbw 274 | 275 | # Visual Studio LightSwitch build output 276 | **/*.HTMLClient/GeneratedArtifacts 277 | **/*.DesktopClient/GeneratedArtifacts 278 | **/*.DesktopClient/ModelManifest.xml 279 | **/*.Server/GeneratedArtifacts 280 | **/*.Server/ModelManifest.xml 281 | _Pvt_Extensions 282 | 283 | # Paket dependency manager 284 | .paket/paket.exe 285 | paket-files/ 286 | 287 | # FAKE - F# Make 288 | .fake/ 289 | 290 | # JetBrains Rider 291 | .idea/ 292 | *.sln.iml 293 | 294 | # CodeRush 295 | .cr/ 296 | 297 | # Python Tools for Visual Studio (PTVS) 298 | __pycache__/ 299 | *.pyc 300 | 301 | # Cake - Uncomment if you are using it 302 | # tools/** 303 | # !tools/packages.config 304 | 305 | # Tabs Studio 306 | *.tss 307 | 308 | # Telerik's JustMock configuration file 309 | *.jmconfig 310 | 311 | # BizTalk build output 312 | *.btp.cs 313 | *.btm.cs 314 | *.odx.cs 315 | *.xsd.cs 316 | 317 | # OpenCover UI analysis results 318 | OpenCover/ 319 | 320 | # Azure Stream Analytics local run output 321 | ASALocalRun/ 322 | 323 | # MSBuild Binary and Structured Log 324 | *.binlog 325 | 326 | # NVidia Nsight GPU debugger configuration file 327 | *.nvuser 328 | 329 | # MFractors (Xamarin productivity tool) working folder 330 | .mfractor/ 331 | -------------------------------------------------------------------------------- /sample-scripts/security/manage-logins-permissions/sp_GetPermsInfo.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Login - the name of the login for which you want to check permissions. 3 | GrantOrDeny - 0: show only DENY; 1: show only GRANT; NULL: show both (default) 4 | 5 | The stored proc will attempt to impersonate the provide login for the purpose of 6 | enumerating Windows groups to which that login belongs. If unable to complete 7 | impersonation, an error will be raised and execution will continue. 8 | 9 | Example: 10 | The below will get only DENY info for login 'MyDomain\bob' and groups/roles 11 | to which 'MyDomain\bob' is a member. 12 | 13 | EXEC sp_GetPermsInfo @Login = 'MyDomain\bob', @GrantOrDeny = 0 14 | */ 15 | CREATE OR ALTER PROCEDURE sp_GetPermsInfo (@Login SYSNAME, @GrantOrDeny BIT = NULL) 16 | AS BEGIN 17 | 18 | SET NOCOUNT ON; 19 | 20 | DECLARE 21 | @LoginPrinID INT 22 | , @SID VARBINARY(32) 23 | , @CurDB SYSNAME 24 | , @QueryText NVARCHAR(1024) 25 | , @Err VARCHAR(512) 26 | --Do nothing if login doesn't exist 27 | IF(NOT EXISTS (SELECT 1 FROM sys.server_principals WHERE name = @Login)) 28 | BEGIN 29 | SET @Err = 'No login found with name: ' + @Login 30 | RAISERROR(@Err, 15, 1) 31 | RETURN -1 32 | END 33 | 34 | --By creating this even if not needed (as opposed to single variable if not Win Login), 35 | --we avoid having to do a ton of additional scripting for conditional logic later 36 | CREATE TABLE #LoginAndGroupInfo 37 | ( 38 | [name] SYSNAME 39 | , [principal_id] INT 40 | , [sid] VARBINARY(64) 41 | ) 42 | 43 | 44 | BEGIN TRY 45 | EXECUTE AS LOGIN = @Login 46 | 47 | --@Login member of any Windows group listed that isn't @Login itself 48 | INSERT INTO #LoginAndGroupInfo([name], [principal_id], [sid]) 49 | SELECT DISTINCT p.[name], p.[principal_id], p.[sid] 50 | FROM sys.server_principals p 51 | LEFT JOIN [sys].[login_token] t ON t.[sid] = p.[sid] 52 | WHERE (t.[principal_id] IS NULL AND p.[name] = @Login) 53 | OR t.[name] = @Login 54 | OR (t.[principal_id] > 0 AND t.[type] = 'WINDOWS GROUP'); 55 | END TRY 56 | BEGIN CATCH 57 | --If we can't impersonate, we won't get any Windows groups info, but still need to get login... 58 | INSERT INTO #LoginAndGroupInfo([name], [principal_id], [sid]) 59 | SELECT [name], [principal_id], [sid] 60 | FROM [sys].[server_principals] 61 | WHERE [name] = @Login 62 | 63 | SET @Err = 'Unable to impersonate login ' + @Login + '. Results may be incomplete.'; 64 | RAISERROR(@Err, 15, 1); 65 | GOTO Post_Impersonation_Attempt; 66 | END CATCH 67 | 68 | 69 | Post_Impersonation_Attempt: 70 | 71 | REVERT; 72 | 73 | 74 | --Get Server Role Membership Info 75 | SELECT l.name [Login], p.name [ServerRole] 76 | INTO #ServerRoleMemberships 77 | FROM [sys].[server_principals] p 78 | JOIN [sys].[server_role_members] m ON m.[role_principal_id] = p.[principal_id] 79 | JOIN #LoginAndGroupInfo l ON l.[principal_id] = m.[member_principal_id] 80 | 81 | --Always check public 82 | INSERT INTO #ServerRoleMemberships(Login, ServerRole) 83 | SELECT @Login, 'Public' 84 | 85 | --Get Server Permission Info 86 | SELECT 87 | l.[name] 88 | , [class_desc] [Class] 89 | , [permission_name] [Permission] 90 | , [state_desc] [State] 91 | INTO #ServerPerms 92 | FROM [sys].[server_permissions] p 93 | JOIN #LoginAndGroupInfo l ON l.[principal_id] = p.[grantee_principal_id] 94 | 95 | --Also for server roles of which this login is a member 96 | INSERT INTO #ServerPerms([name], [Class], [Permission], [State]) 97 | SELECT p.[name], m.[class_desc], m.[permission_name], m.[state_desc] 98 | FROM [sys].[server_permissions] m 99 | JOIN [sys].[server_principals] p ON p.[principal_id] = m.[grantee_principal_id] 100 | JOIN #ServerRoleMemberships r ON r.[ServerRole] = p.[name] 101 | 102 | 103 | --Get List of Databases 104 | SELECT [name] 105 | INTO #Databases 106 | FROM [sys].[databases] 107 | 108 | 109 | --Setup for loop to get DB info 110 | CREATE TABLE #DBRoleMembership 111 | ( 112 | [Database] SYSNAME 113 | , [Login] SYSNAME 114 | , [User] SYSNAME 115 | , [DBRole] SYSNAME 116 | ) 117 | 118 | CREATE TABLE #DBPerms 119 | ( 120 | [Database] SYSNAME 121 | , [Login] SYSNAME 122 | , [User] SYSNAME 123 | , [Class] NVARCHAR(50) 124 | , [Permission] NVARCHAR(256) 125 | , [State] NVARCHAR(16) 126 | ) 127 | 128 | 129 | --Loop over all databases, getting DB Role & permissions info from each 130 | SELECT TOP(1) @CurDB = [name] 131 | FROM #Databases 132 | 133 | WHILE(@CurDB IS NOT NULL) 134 | BEGIN 135 | SET @QueryText = 'INSERT INTO #DBRoleMembership ([Database], [Login], [User], [DBRole])' + CHAR(10) 136 | + 'SELECT ''' + @CurDB + ''', l.[name], u.[name], r.[name]' + CHAR(10) 137 | + 'FROM ['+@CurDB+'].[sys].[database_principals] u' + CHAR(10) 138 | + ' JOIN ['+@CurDB+'].[sys].[database_role_members] m ON m.[member_principal_id] = u.[principal_id]' + CHAR(10) 139 | + ' JOIN ['+@CurDB+'].[sys].[database_principals] r ON r.[principal_id] = m.[role_principal_id]' + CHAR(10) 140 | + ' JOIN #LoginAndGroupInfo l ON l.[sid] = u.[sid];' + CHAR(10) + CHAR(10) 141 | --Always include public 142 | + 'INSERT INTO #DBRoleMembership ([Database], [Login], [User], [DBRole])' 143 | + 'SELECT ''' + @CurDB + ''', ''' + @Login + ''', ''N\A'', ''public''' + CHAR(10) 144 | 145 | EXEC(@QueryText) 146 | 147 | SET @QueryText = 'INSERT INTO #DBPerms([Database], [Login], [User], [Class], [Permission], [State])' + CHAR(10) 148 | + 'SELECT ''' + @CurDB + ''', l.[name], u.[name], p.[class_desc], p.[permission_name], p.[state_desc]' + CHAR(10) 149 | + 'FROM ['+@CurDB+'].[sys].[database_principals] u' + CHAR(10) 150 | + ' JOIN ['+@CurDB+'].[sys].[database_permissions] p ON u.[principal_id] = p.[grantee_principal_id]' + CHAR(10) 151 | + ' JOIN #LoginAndGroupInfo l ON l.[sid] = u.[sid]' + CHAR(10) 152 | 153 | EXEC(@QueryText) 154 | 155 | --Include permissions for roles 156 | SET @QueryText = 'INSERT INTO #DBPerms([Database], [Login], [User], [Class], [Permission], [State])' + CHAR(10) 157 | + 'SELECT ''' + @CurDB + ''', l.[Login], u.[name], p.[class_desc], p.[permission_name], p.[state_desc]' + CHAR(10) 158 | + 'FROM ['+@CurDB+'].[sys].[database_principals] u' + CHAR(10) 159 | + ' JOIN ['+@CurDB+'].[sys].[database_permissions] p ON u.[principal_id] = p.[grantee_principal_id]' + CHAR(10) 160 | + ' JOIN #DBRoleMembership l ON l.[DBRole] = u.[name]' + CHAR(10) 161 | 162 | EXEC(@QueryText) 163 | 164 | DELETE FROM #Databases 165 | WHERE [name] = @CurDB 166 | 167 | SET @CurDB = NULL 168 | 169 | SELECT TOP(1) @CurDB = [name] 170 | FROM #Databases 171 | END 172 | 173 | --From here down it's just printing the results. 174 | IF (EXISTS(SELECT 1 FROM #ServerPerms WHERE [State] = 'DENY') 175 | OR EXISTS(SELECT 1 FROM #DBPerms WHERE [State] = 'DENY')) 176 | AND (@GrantOrDeny <> 1 OR @GrantOrDeny IS NULL) 177 | BEGIN 178 | SELECT DISTINCT '**** SERVER PERMISSION: ' + [Permission] COLLATE SQL_Latin1_General_CP1_CI_AS + ' HAS BEEN DENIED****' 179 | FROM #ServerPerms 180 | WHERE [State] = 'DENY' 181 | UNION ALL 182 | SELECT DISTINCT '**** DATABASE PERMISSION: ' + [Permission] COLLATE SQL_Latin1_General_CP1_CI_AS + ' HAS BEEN DENIED****' 183 | FROM #DBPerms 184 | WHERE [State] = 'DENY' 185 | 186 | END 187 | 188 | IF EXISTS (SELECT 1 FROM #DBRoleMembership WHERE [DBRole] LIKE '%DENY%') 189 | AND (@GrantOrDeny <> 1 OR @GrantOrDeny IS NULL) 190 | BEGIN 191 | SELECT '**** IS MEMBER OF ' + [DBRole] + ' IN DATABASE ' + [Database] + '****' 192 | FROM #DBRoleMembership 193 | WHERE [DBRole] LIKE '%DENY%' 194 | END 195 | 196 | IF EXISTS(SELECT 1 FROM #ServerRoleMemberships) 197 | BEGIN 198 | SELECT '' [Server Role Membership:] 199 | SELECT * 200 | FROM #ServerRoleMemberships 201 | ORDER BY [ServerRole] 202 | END 203 | ELSE BEGIN 204 | SELECT 'Not a member of any server roles' 205 | END 206 | 207 | IF EXISTS(SELECT 1 FROM #ServerPerms) 208 | BEGIN 209 | SELECT '' [Explicit Server Permissions:] 210 | SELECT * 211 | FROM #ServerPerms 212 | WHERE [State] LIKE 213 | CASE 214 | WHEN @GrantOrDeny = 0 THEN 'DENY' 215 | WHEN @GrantOrDeny = 1 THEN 'GRANT' 216 | ELSE '%' 217 | END 218 | ORDER BY [State], [Class], [Permission] 219 | END 220 | ELSE BEGIN 221 | SELECT 'No explicit server permissions set' 222 | END 223 | 224 | IF EXISTS(SELECT 1 FROM #DBRoleMembership) 225 | BEGIN 226 | SELECT '' [Database Role Memberships:] 227 | SELECT DISTINCT * 228 | FROM #DBRoleMembership 229 | ORDER BY [Database], [User], [DBRole] 230 | END 231 | ELSE BEGIN 232 | SELECT 'Not mapped to any user which is a member of a database role' 233 | END 234 | 235 | IF EXISTS(SELECT 1 FROM #DBPerms) 236 | BEGIN 237 | SELECT '' [Explicit Database Permissions:] 238 | SELECT DISTINCT * 239 | FROM #DBPerms 240 | WHERE [State] LIKE 241 | CASE 242 | WHEN @GrantOrDeny = 0 THEN 'DENY' 243 | WHEN @GrantOrDeny = 1 THEN 'GRANT' 244 | ELSE '%' 245 | END 246 | ORDER BY [Database], [State], [Class], [Permission] 247 | END 248 | ELSE BEGIN 249 | SELECT 'Not mapped to any user with explicit database permissions set' 250 | END 251 | END 252 | -------------------------------------------------------------------------------- /sqldumper/SQLDumpHelper.ps1: -------------------------------------------------------------------------------- 1 | $isInt = $false 2 | $isIntValDcnt = $false 3 | $isIntValDelay = $false 4 | $SqlPidInt = 0 5 | $NumFoler ="" 6 | $OneThruFour = "" 7 | $SqlDumpTypeSelection = "" 8 | $SSASDumpTypeSelection = "" 9 | $SSISDumpTypeSelection = "" 10 | $SQLNumfolder=0 11 | $SQLDumperDir="" 12 | $OutputFolder="" 13 | $DumpType ="0x0120" 14 | $ValidPid 15 | $SharedFolderFound=$false 16 | $YesNo ="" 17 | $ProductNumber="" 18 | $ProductStr = "" 19 | 20 | Write-Host "" 21 | Write-Host "`**********************************************************************" 22 | Write-Host "This script helps you generate one or more SQL Server memory dumps" 23 | Write-Host "It presents you with choices on:` 24 | -target SQL Server process (if more than one) 25 | -type of memory dump 26 | -count and time interval (if multiple memory dumps) 27 | You can interrupt this script using CTRL+C" 28 | Write-Host "***********************************************************************" 29 | 30 | #check for administrator rights 31 | #debugging tools like SQLDumper.exe require Admin privileges to generate a memory dump 32 | 33 | if (-not ([Security.Principal.WindowsPrincipal] [Security.Principal.WindowsIdentity]::GetCurrent()).IsInRole([Security.Principal.WindowsBuiltInRole]::Administrator)) 34 | { 35 | Write-Warning "Administrator rights are required to generate a memory dump!`nPlease re-run this script as an Administrator!" 36 | #break 37 | } 38 | 39 | #what product would you like to generate a memory dump 40 | while(($ProductNumber -ne "1") -and ($ProductNumber -ne "2") -and ($ProductNumber -ne "3") -and ($ProductNumber -ne "4") -and ($ProductNumber -ne "5")) 41 | { 42 | Write-Host "Which product would you like to generate a memory dump of?" -ForegroundColor Yellow 43 | Write-Host "1) SQL Server" 44 | Write-Host "2) SSAS (Analysis Services) " 45 | Write-Host "3) SSIS (Integration Services)" 46 | Write-Host "4) SSRS (Reporting Services)" 47 | Write-Host "5) SQL Server Agent" 48 | Write-Host "" 49 | $ProductNumber = Read-Host "Enter 1-5>" 50 | 51 | if (($ProductNumber -ne "1") -and ($ProductNumber -ne "2") -and ($ProductNumber -ne "3") -and ($ProductNumber -ne "4")-and ($ProductNumber -ne "5")) 52 | { 53 | Write-Host "" 54 | Write-Host "Please enter a valid number from list above!" 55 | Write-Host "" 56 | Start-Sleep -Milliseconds 300 57 | } 58 | } 59 | 60 | if ($ProductNumber -eq "1") 61 | { 62 | $SqlTaskList = Tasklist /SVC /FI "imagename eq sqlservr*" /FO CSV | ConvertFrom-Csv 63 | $ProductStr = "SQL Server" 64 | } 65 | elseif ($ProductNumber -eq "2") 66 | { 67 | $SqlTaskList = Tasklist /SVC /FI "imagename eq msmdsrv*" /FO CSV | ConvertFrom-Csv 68 | $ProductStr = "SSAS (Analysis Services)" 69 | } 70 | elseif ($ProductNumber -eq "3") 71 | { 72 | $SqlTaskList = Tasklist /SVC /FI "imagename eq msdtssrvr*" /FO CSV | ConvertFrom-Csv 73 | $ProductStr = "SSIS (Integration Services)" 74 | } 75 | elseif ($ProductNumber -eq "4") 76 | { 77 | $SqlTaskList = Tasklist /SVC /FI "imagename eq reportingservicesservice*" /FO CSV | ConvertFrom-Csv 78 | $ProductStr = "SSRS (Reporting Services)" 79 | } 80 | elseif ($ProductNumber -eq "5") 81 | { 82 | $SqlTaskList = Tasklist /SVC /FI "imagename eq sqlagent*" /FO CSV | ConvertFrom-Csv 83 | $ProductStr = "SQL Server Agent" 84 | } 85 | 86 | if ($SqlTaskList.Count -eq 0) 87 | { 88 | Write-Host "There are curerntly no running instances of $ProductStr. Exiting..." -ForegroundColor Green 89 | break 90 | } 91 | 92 | #if multiple SQL Server instances, get the user to input PID for desired SQL Server 93 | if ($SqlTaskList.Count -gt 1) 94 | { 95 | Write-Host "More than one $ProductStr instance found." 96 | 97 | $SqlTaskList | Select-Object PID, "Image name", Services |Out-Host 98 | 99 | #check input and make sure it is a valid integer 100 | while(($isInt -eq $false) -or ($ValidPid -eq $false)) 101 | { 102 | Write-Host "Please enter the PID for the desired SQL service from list above" -ForegroundColor Yellow 103 | $SqlPidStr = Read-Host ">" 104 | 105 | try{ 106 | $SqlPidInt = [convert]::ToInt32($SqlPidStr) 107 | $isInt = $true 108 | } 109 | 110 | catch [FormatException] 111 | { 112 | Write-Host "The value entered for PID '",$SqlPidStr,"' is not an integer" 113 | } 114 | 115 | #validate this PID is in the list discovered 116 | for($i=0;$i -lt $SqlTaskList.Count;$i++) 117 | { 118 | if($SqlPidInt -eq [int]$SqlTaskList.PID[$i]) 119 | { 120 | $ValidPid = $true 121 | break; 122 | } 123 | else 124 | { 125 | $ValidPid = $false 126 | } 127 | } 128 | } 129 | 130 | Write-Host "Using PID=$SqlPidInt for generating a $ProductStr memory dump" -ForegroundColor Green 131 | Write-Host "" 132 | 133 | } 134 | else #if only one SQL Server/SSAS on the box, go here 135 | { 136 | $SqlTaskList | Select-Object PID, "Image name", Services |Out-Host 137 | $SqlPidInt = [convert]::ToInt32($SqlTaskList.PID) 138 | 139 | Write-Host "Using PID=", $SqlPidInt, " for generating a $ProductStr memory dump" -ForegroundColor Green 140 | Write-Host "" 141 | } 142 | 143 | #dump type 144 | 145 | if ($ProductNumber -eq "1") #SQL Server memory dump 146 | { 147 | #ask what type of SQL Server memory dump 148 | while(($SqlDumpTypeSelection -ne "1") -and ($SqlDumpTypeSelection -ne "2") -And ($SqlDumpTypeSelection -ne "3") -And ($SqlDumpTypeSelection -ne "4" )) 149 | { 150 | Write-Host "Which type of memory dump would you like to generate?" -ForegroundColor Yellow 151 | Write-Host "1) Mini-dump" 152 | Write-Host "2) Mini-dump with referenced memory " -NoNewLine; Write-Host "(Recommended)" 153 | Write-Host "3) Filtered dump " -NoNewline; Write-Host "(Not Recommended)" -ForegroundColor Red 154 | Write-Host "4) Full dump " -NoNewline; Write-Host "(Do Not Use on Production systems!)" -ForegroundColor Red 155 | Write-Host "" 156 | $SqlDumpTypeSelection = Read-Host "Enter 1-4>" 157 | 158 | if (($SqlDumpTypeSelection -ne "1") -and ($SqlDumpTypeSelection -ne "2") -And ($SqlDumpTypeSelection -ne "3") -And ($SqlDumpTypeSelection -ne "4" )) 159 | { 160 | Write-Host "" 161 | Write-Host "Please enter a valid type of memory dump!" 162 | Write-Host "" 163 | Start-Sleep -Milliseconds 300 164 | } 165 | } 166 | 167 | Write-Host "" 168 | 169 | switch ($SqlDumpTypeSelection) 170 | { 171 | "1" {$DumpType="0x0120";break} 172 | "2" {$DumpType="0x0128";break} 173 | "3" {$DumpType="0x8100";break} 174 | "4" {$DumpType="0x01100";break} 175 | default {"0x0120"; break} 176 | 177 | } 178 | 179 | } 180 | elseif ($ProductNumber -eq "2") #SSAS dump 181 | { 182 | 183 | #ask what type of SSAS memory dump 184 | while(($SSASDumpTypeSelection -ne "1") -and ($SSASDumpTypeSelection -ne "2")) 185 | { 186 | Write-Host "Which type of memory dump would you like to generate?" -ForegroundColor Yellow 187 | Write-Host "1) Mini-dump" 188 | Write-Host "2) Full dump " -NoNewline; Write-Host "(Do Not Use on Production systems!)" -ForegroundColor Red 189 | Write-Host "" 190 | $SSASDumpTypeSelection = Read-Host "Enter 1-2>" 191 | 192 | if (($SSASDumpTypeSelection -ne "1") -and ($SSASDumpTypeSelection -ne "2")) 193 | { 194 | Write-Host "" 195 | Write-Host "Please enter a valid type of memory dump!" 196 | Write-Host "" 197 | Start-Sleep -Milliseconds 300 198 | } 199 | } 200 | 201 | Write-Host "" 202 | 203 | switch ($SSASDumpTypeSelection) 204 | { 205 | "1" {$DumpType="0x0";break} 206 | "2" {$DumpType="0x34";break} 207 | default {"0x0120"; break} 208 | 209 | } 210 | } 211 | 212 | elseif ($ProductNumber -eq "3" -or $ProductNumber -eq "4" -or $ProductNumber -eq "5") #SSIS/SSRS/SQL Agent dump 213 | { 214 | 215 | #ask what type of SSIS memory dump 216 | while(($SSISDumpTypeSelection -ne "1") -and ($SSISDumpTypeSelection -ne "2")) 217 | { 218 | Write-Host "Which type of memory dump would you like to generate?" -ForegroundColor Yellow 219 | Write-Host "1) Mini-dump" 220 | Write-Host "2) Full dump" 221 | Write-Host "" 222 | $SSISDumpTypeSelection = Read-Host "Enter 1-2>" 223 | 224 | if (($SSISDumpTypeSelection -ne "1") -and ($SSISDumpTypeSelection -ne "2")) 225 | { 226 | Write-Host "" 227 | Write-Host "Please enter a valid type of memory dump!" 228 | Write-Host "" 229 | Start-Sleep -Milliseconds 300 230 | } 231 | } 232 | 233 | Write-Host "" 234 | 235 | switch ($SSISDumpTypeSelection) 236 | { 237 | "1" {$DumpType="0x0";break} 238 | "2" {$DumpType="0x34";break} 239 | default {"0x0120"; break} 240 | 241 | } 242 | } 243 | 244 | # Sqldumper.exe PID 0 0x0128 0 c:\temp 245 | #output folder 246 | while($OutputFolder -eq "" -or !(Test-Path -Path $OutputFolder)) 247 | { 248 | Write-Host "" 249 | Write-Host "Where would your like the memory dump stored (output folder)?" -ForegroundColor Yellow 250 | $OutputFolder = Read-Host "Enter an output folder with no quotes (e.g. C:\MyTempFolder or C:\My Folder)" 251 | if ($OutputFolder -eq "" -or !(Test-Path -Path $OutputFolder)) 252 | { 253 | Write-Host "'" $OutputFolder "' is not a valid folder. Please, enter a valid folder location" -ForegroundColor Yellow 254 | } 255 | } 256 | 257 | #find the highest version of SQLDumper.exe on the machine 258 | $NumFolder = dir "c:\Program Files\microsoft sql server\1*" | Select-Object @{name = "DirNameInt"; expression={[int]($_.Name)}}, Name, Mode | Where-Object Mode -Match "da*" | Sort-Object DirNameInt -Descending 259 | 260 | for($j=0;($j -lt $NumFolder.Count); $j++) 261 | { 262 | $SQLNumfolder = $NumFolder.DirNameInt[$j] #start with the highest value from sorted folder names - latest version of dumper 263 | $SQLDumperDir = "c:\Program Files\microsoft sql server\"+$SQLNumfolder.ToString()+"\Shared\" 264 | $TestPathDumperDir = $SQLDumperDir+"sqldumper.exe" 265 | 266 | $TestPathResult = Test-Path -Path $SQLDumperDir 267 | 268 | if ($TestPathResult -eq $true) 269 | { 270 | break; 271 | } 272 | } 273 | 274 | #build the SQLDumper.exe command e.g. (Sqldumper.exe 1096 0 0x0128 0 c:\temp\) 275 | 276 | $cmd = "$([char]34)"+$SQLDumperDir + "sqldumper.exe$([char]34)" 277 | $arglist = $SqlPidInt.ToString() + " 0 " +$DumpType +" 0 $([char]34)" + $OutputFolder + "$([char]34)" 278 | Write-Host "Command for dump generation: ", $cmd, $arglist -ForegroundColor Green 279 | 280 | #do-we-want-multiple-dumps section 281 | Write-Host "" 282 | Write-Host "This utility can generate multiple memory dumps, at a certain interval" 283 | Write-Host "Would you like to collect multiple memory dumps?" -ForegroundColor Yellow 284 | 285 | #validate Y/N input 286 | while (($YesNo -ne "y") -and ($YesNo -ne "n")) 287 | { 288 | $YesNo = Read-Host "Enter Y or N>" 289 | 290 | if (($YesNo -eq "y") -or ($YesNo -eq "n") ) 291 | { 292 | break 293 | } 294 | else 295 | { 296 | Write-Host "Not a valid 'Y' or 'N' response" 297 | } 298 | } 299 | 300 | #get input on how many dumps and at what interval 301 | if ($YesNo -eq "y") 302 | { 303 | while(($isIntValDcnt -eq $false)) 304 | { 305 | Write-Host "How many dumps would you like to generate for this SQL Server?" -ForegroundColor Yellow 306 | $DumpCountStr = Read-Host ">" 307 | 308 | try{ 309 | $DumpCountInt = [convert]::ToInt32($DumpCountStr) 310 | $isIntValDcnt = $true 311 | } 312 | 313 | catch [FormatException] 314 | { 315 | Write-Host "The value entered for dump count '",$DumpCountStr,"' is not an integer" 316 | } 317 | } 318 | 319 | while(($isIntValDelay -eq $false)) 320 | { 321 | Write-Host "How frequently (in seconds) would you like to generate the memory dumps?" -ForegroundColor Yellow 322 | $DelayIntervalStr = Read-Host ">" 323 | 324 | try{ 325 | $DelayIntervalInt = [convert]::ToInt32($DelayIntervalStr) 326 | $isIntValDelay = $true 327 | } 328 | 329 | catch [FormatException] 330 | { 331 | Write-Host "The value entered for frequency (in seconds) '",$DelayIntervalStr,"' is not an integer" 332 | } 333 | } 334 | 335 | Write-Host "Generating $DumpCountInt memory dumps at a $DelayIntervalStr-second interval" -ForegroundColor Green 336 | 337 | #loop to generate multiple dumps 338 | $cntr = 0 339 | while($true) 340 | { 341 | Start-Process -FilePath $cmd -Wait -Verb runAs -ArgumentList $arglist 342 | $cntr++ 343 | 344 | Write-Host "Generated $cntr memory dump(s)." -ForegroundColor Green 345 | 346 | if ($cntr -ge $DumpCountInt) 347 | { 348 | break 349 | } 350 | Start-Sleep -S $DelayIntervalInt 351 | } 352 | 353 | #print what files exist in the output folder 354 | Write-Host "" 355 | Write-Host "Here are all the memory dumps in the output folder '$OutputFolder'" -ForegroundColor Green 356 | $MemoryDumps = $OutputFolder + "\SQLDmpr*" 357 | Get-ChildItem -Path $MemoryDumps 358 | 359 | Write-Host "" 360 | Write-Host "Process complete" 361 | } 362 | 363 | else #produce just a single dump 364 | { 365 | Start-Process -FilePath $cmd -Wait -Verb runAs -ArgumentList $arglist 366 | 367 | #print what files exist in the output folder 368 | Write-Host "" 369 | Write-Host "Here are all the memory dumps in the output folder '$OutputFolder'" -ForegroundColor Green 370 | $MemoryDumps = $OutputFolder + "\SQLDmpr*" 371 | Get-ChildItem -Path $MemoryDumps 372 | 373 | Write-Host "" 374 | Write-Host "Process complete" 375 | } 376 | 377 | Write-Host "For errors and completion status, review SQLDUMPER_ERRORLOG.log created by SQLDumper.exe in the output folder '$OutputFolder'. `Or if SQLDumper.exe failed look in the folder from which you are running this script" -------------------------------------------------------------------------------- /sample-scripts/DOCs-to-Notebooks/T-shooting-SQL-SystemAdmins-Locked-out.ipynb: -------------------------------------------------------------------------------- 1 | { 2 | "metadata": { 3 | "kernelspec": { 4 | "name": "powershell", 5 | "display_name": "PowerShell", 6 | "language": "powershell" 7 | }, 8 | "language_info": { 9 | "name": "powershell", 10 | "codemirror_mode": "shell", 11 | "mimetype": "text/x-sh", 12 | "file_extension": ".ps1" 13 | }, 14 | "azdata_notebook_guid": "9121088A-F440-4AD9-9F05-F87A76A12D57", 15 | "extensions": { 16 | "azuredatastudio": { 17 | "version": 1, 18 | "views": [] 19 | } 20 | } 21 | }, 22 | "nbformat_minor": 2, 23 | "nbformat": 4, 24 | "cells": [ 25 | { 26 | "cell_type": "markdown", 27 | "source": [ 28 | "# Connect to SQL Server when system administrators are locked out\n", 29 | "\n", 30 | "**Applies to:** SQL Server (all supported versions)\n", 31 | "\n", 32 | "This article describes how you can regain access to the SQL Server Database Engine as a system administrator if you've been locked out. A system administrator can lose access to an instance of SQL Server due to one of the following reasons:\n", 33 | "\n", 34 | "- All logins that are members of the sysadmin fixed server role have been removed by mistake.\n", 35 | " \n", 36 | "- All Windows Groups that are members of the sysadmin fixed server role have been removed by mistake.\n", 37 | " \n", 38 | "- The logins that are members of the sysadmin fixed server role are for individuals who have left the company or who are not available.\n", 39 | " \n", 40 | "- The sa account is disabled or no one knows the password.\n", 41 | " \n", 42 | "\n", 43 | "## Resolution\n", 44 | "\n", 45 | "In order to resolve your access issue, we recommend that you start the instance of SQL Server in single-user mode. This mode prevents other connections from occurring while you try to regain access. From here, you can connect to your instance of SQL Server and add your login to the **sysadmin** server role. Detailed steps for this solution are provided in the [step-by-step-instructions](#step-by-step-instructions) section.\n", 46 | "\n", 47 | "You can start an instance of SQL Server in single-user mode with either the `-m` or `-f` options from the command line. Any member of the computer's local Administrators group can then connect to the instance of SQL Server as a member of the **sysadmin** fixed server role.\n", 48 | "\n", 49 | "When you start the instance in single-user mode, first stop the SQL Server Agent service. Otherwise, SQL Server Agent might connect first, taking the only available connection to the server and blocking you from logging in.\n", 50 | "\n", 51 | "It's also possible for an unknown client application to take the only available connection before you are able to log in. In order to prevent this from happening, you can use the `-m` option followed by an application name to limit connections to a single connection from the specified application. For example, starting SQL Server with `-mSQLCMD` limits connections to a single connection that identifies itself as the **sqlcmd** client program. To connect through the Query Editor in \\\\Management Studio, use `-m\"Microsoft SQL Server Management Studio - Query\"`.\n", 52 | "\n", 53 | "> \\[!IMPORTANT\\] \n", 54 | "> Do not use `-m` with an application name as a security feature. Client applications specify the application name through the connection string settings, so it can easily be spoofed with a false name.\n", 55 | "\n", 56 | "The following table summarizes the different ways to start your instance in single-user mode in the command line.\n", 57 | "\n", 58 | "| Option | Description | When to use |\n", 59 | "| :-- | :-- | :-- |\n", 60 | "| `-m` | Limits connections to a single connection | When there are no other users attempting to connect to the instance or you are not sure of the application name you are using to connect to the instance. |\n", 61 | "| `-mSQLCMD` | Limits connections to a single connection that must identify itself as the **sqlcmd** client program | When you plan to connect to the instance with **sqlcmd** and you want to prevent other applications from taking the only available connection. |\n", 62 | "| `-m\"Microsoft SQL Server Management Studio - Query\"` | Limits connections to a single connection that must identify itself as the **Microsoft SQL Server Management Studio - Query** application. | When you plan to connect to the instance through the Query Editor in Management Studio and you want to prevent other applications from taking the only available connection. |\n", 63 | "| `-f` | Limits connections to a single connection and starts the instance in minimal configuration | When some other configuration is preventing you from starting. |\n", 64 | "| | | |\n", 65 | "\n", 66 | "## Step by step Instructions\n", 67 | "\n", 68 | "For step-by-step instructions about how to start SQL Server in single-user mode, see [Start SQL Server in Single-User Mode](..\\..\\database-engine\\configure-windows\\start-sql-server-in-single-user-mode.md).\n", 69 | "\n", 70 | "### Using Powershell\n", 71 | "\n", 72 | "1. Open a Windows Powershell command - Run as an Administrator.\n", 73 | "2. Set up service name and SQL Server instance, and Windows login variables. Replace these with values to match your environment\n", 74 | "" 75 | ], 76 | "metadata": { 77 | "azdata_cell_guid": "61f036d6-4e68-4988-80a6-8a2747a87bc8" 78 | }, 79 | "attachments": {} 80 | }, 81 | { 82 | "cell_type": "code", 83 | "source": [ 84 | "$service_name = \"MSSQL`$sql2019\" # for a default instace use: \"MSSQLSERVER\"\r\n", 85 | "$sql_server_instance = \"myserver\\sql2019\"\r\n", 86 | "$login_to_be_granted_access = \"[CONTOSO\\PatK]\"" 87 | ], 88 | "metadata": { 89 | "azdata_cell_guid": "6e3d2c52-12f8-4cc1-8d02-d9c641d914db" 90 | }, 91 | "outputs": [], 92 | "execution_count": null 93 | }, 94 | { 95 | "cell_type": "markdown", 96 | "source": [ 97 | "3. Stop SQL Server service so it can be restarted with single-user mode, using the following command:\n", 98 | "\n", 99 | "> \\[!NOTE\\] To stop and start a service, you need to run this Notebook as an Administrator, or else you will receive an \"Access is denied\" error. Start your notebook application (Azure Data Studio, e.g.) as an Administrator" 100 | ], 101 | "metadata": { 102 | "azdata_cell_guid": "a1c5af02-cec2-4984-a154-dee9d0e4c841" 103 | }, 104 | "attachments": {} 105 | }, 106 | { 107 | "cell_type": "code", 108 | "source": [ 109 | " net stop $service_name" 110 | ], 111 | "metadata": { 112 | "azdata_cell_guid": "feaaf2e7-301e-4bea-8327-a0f49b548539" 113 | }, 114 | "outputs": [], 115 | "execution_count": null 116 | }, 117 | { 118 | "cell_type": "markdown", 119 | "source": [ 120 | "4. Now start your SQL Server instance in a single user mode and only allow SQLCMD.exe to connect (/mSQLCMD)\r\n", 121 | "\r\n", 122 | " > [!NOTE] \r\n", 123 | " > Be sure to use upper-case SQLCMD\r\n", 124 | "" 125 | ], 126 | "metadata": { 127 | "azdata_cell_guid": "d3e91f9e-5b1c-4df4-9a49-536daaaa2ed4" 128 | } 129 | }, 130 | { 131 | "cell_type": "code", 132 | "source": [ 133 | "net start $service_name /f /mSQLCMD" 134 | ], 135 | "metadata": { 136 | "azdata_cell_guid": "47eaf6f0-5575-4f45-9328-7923d174b323" 137 | }, 138 | "outputs": [], 139 | "execution_count": null 140 | }, 141 | { 142 | "cell_type": "markdown", 143 | "source": [ 144 | "5. Using **SQLCMD** execute a CREATE LOGIN command followed by ALTER SERVER ROLE command. This step assumes you have logged into Windows with an account that is a member of the Local Administrators group. This assumes you have replaced the domain and login names with the credentials you want to give Sysadmin membership.\r\n", 145 | "" 146 | ], 147 | "metadata": { 148 | "azdata_cell_guid": "dd5061ec-2cd4-4113-b4a5-1e4921dfd7e5" 149 | } 150 | }, 151 | { 152 | "cell_type": "code", 153 | "source": [ 154 | "sqlcmd.exe -E -S $sql_server_instance -Q \"CREATE LOGIN $login_to_be_granted_access FROM WINDOWS; ALTER SERVER ROLE sysadmin ADD MEMBER $login_to_be_granted_access; \"" 155 | ], 156 | "metadata": { 157 | "azdata_cell_guid": "f319f737-130e-4166-9744-4da69942b49a" 158 | }, 159 | "outputs": [], 160 | "execution_count": null 161 | }, 162 | { 163 | "cell_type": "markdown", 164 | "source": [ 165 | " > [!NOTE] \r\n", 166 | " > If you receive the following error, you must ensure no other SQLCMD has connected to SQL Server:
\r\n", 167 | " > `Sqlcmd: Error: Microsoft ODBC Driver X for SQL Server : Login failed for user 'CONTOSO\\BobD'. Reason: Server is in single user mode. Only one administrator can connect at this time..`\r\n", 168 | "\r\n", 169 | "6. **Mixed Mode (optional):** If your SQL Server is running in mixed authentication mode, you can also:\r\n", 170 | " a. Grant the Sysadmin role membership to a SQL login. Execute code such as the following to create a new SQL Server authentication login that is a member of the sysadmin fixed server role. Replace \"?j8:z$G=JE9\" with a strong password of your choice.\r\n", 171 | "" 172 | ], 173 | "metadata": { 174 | "azdata_cell_guid": "8b48fd76-29a5-4f33-9ef6-b17153fb3bf6" 175 | } 176 | }, 177 | { 178 | "cell_type": "code", 179 | "source": [ 180 | "$strong_password = \"j8:zG=J?E9\"\r\n", 181 | "sqlcmd.exe -E -S $sql_server_instance -Q \"CREATE LOGIN TempLogin WITH PASSWORD = '$strong_password'; ALTER SERVER ROLE sysadmin ADD MEMBER TempLogin; \"" 182 | ], 183 | "metadata": { 184 | "azdata_cell_guid": "d3abda8f-b514-4d3a-8099-30406e554107" 185 | }, 186 | "outputs": [], 187 | "execution_count": null 188 | }, 189 | { 190 | "cell_type": "markdown", 191 | "source": [ 192 | " b. Also, if your SQL Server is running in mixed authentication mode and you want to reset the password of an enabled **sa** account. Change the password of the sa account with the following syntax. Be sure to replace \"j8:zG=J?E9\" with a strong password of your choice:" 193 | ], 194 | "metadata": { 195 | "azdata_cell_guid": "96379768-95dd-4149-a179-faed2882c343" 196 | } 197 | }, 198 | { 199 | "cell_type": "code", 200 | "source": [ 201 | "$strong_password = \"j8:zG=J?E9\"\r\n", 202 | "sqlcmd.exe -E -S $sql_server_instance -Q \"ALTER LOGIN sa WITH PASSWORD = $strong_password; \"" 203 | ], 204 | "metadata": { 205 | "azdata_cell_guid": "f70ce0ea-796f-4876-95ad-06371cdc40b8" 206 | }, 207 | "outputs": [], 208 | "execution_count": null 209 | }, 210 | { 211 | "cell_type": "markdown", 212 | "source": [ 213 | "7. Stop and restart your SQL Server instance in multi-user mode" 214 | ], 215 | "metadata": { 216 | "azdata_cell_guid": "b3559f2c-0bd4-424e-9a00-90bd3682dc5e" 217 | } 218 | }, 219 | { 220 | "cell_type": "code", 221 | "source": [ 222 | "net stop $service_name\r\n", 223 | "net start $service_name" 224 | ], 225 | "metadata": { 226 | "azdata_cell_guid": "8ee689d0-9693-41d7-8fca-567bdecae72f" 227 | }, 228 | "outputs": [], 229 | "execution_count": null 230 | }, 231 | { 232 | "cell_type": "markdown", 233 | "source": [ 234 | "### Using SQL Server Configuration Manager and Management Studio (SSMS)\r\n", 235 | "\r\n", 236 | "\r\n", 237 | "These instructions assume,\r\n", 238 | "\r\n", 239 | "* SQL Server running on Windows 8 or higher. Slight adjustments for earlier versions of SQL Server or Windows are provided where applicable.\r\n", 240 | "\r\n", 241 | "* Management Studio is installed on the computer. \r\n", 242 | "\r\n", 243 | "Perform these instructions while logged in to Windows as a member of the local administrators group.\r\n", 244 | "\r\n", 245 | "1. From the Windows Start menu, right-click the icon for SQL Server Configuration Manager and choose **Run as administrator** to pass your administrator credentials to Configuration Manager. \r\n", 246 | " \r\n", 247 | "2. In SQL Server Configuration Manager, in the left pane, select **SQL Server Services**. In the right-pane, find your instance of SQL Server. (The default instance of SQL Server includes **(MSSQLSERVER)** after the computer name. Named instances appear in upper case with the same name that they have in Registered Servers.) Right-click the instance of SQL Server, and then click **Properties**. \r\n", 248 | " \r\n", 249 | "3. On the **Startup Parameters** tab, in the **Specify a startup parameter** box, type `-m` and then click **Add**. (That's a dash then lower case letter m.) \r\n", 250 | " \r\n", 251 | " > [!NOTE] \r\n", 252 | " > For some earlier versions of SQL Server there is no **Startup Parameters** tab. In that case, on the **Advanced** tab, double-click **Startup Parameters**. The parameters open up in a very small window. Be careful not to change any of the existing parameters. At the very end, add a new parameter `;-m` and then click **OK**. (That's a semi-colon then a dash then lower case letter m.) \r\n", 253 | " \r\n", 254 | "4. Click **OK**, and after the message to restart, right-click your server name, and then click **Restart**. \r\n", 255 | " \r\n", 256 | "5. After SQL Server has restarted, your server will be in single-user mode. Make sure that SQL Server Agent is not running. If started, it will take your only connection. \r\n", 257 | " \r\n", 258 | "6. From the Windows Start menu, right-click the icon for [!INCLUDE[ssManStudio](../../includes/ssmanstudio-md.md)] and select **Run as administrator**. This will pass your administrator credentials to SSMS.\r\n", 259 | " \r\n", 260 | " > [!NOTE] \r\n", 261 | " > For earlier versions of Windows, the **Run as administrator** option appears as a sub-menu. \r\n", 262 | " \r\n", 263 | " In some configurations, SSMS will attempt to make several connections. Multiple connections will fail because SQL Server is in single-user mode. Based on your scenario, perform one of the following actions. \r\n", 264 | " \r\n", 265 | " a. Connect with Object Explorer using Windows Authentication, which includes your Administrator credentials. Expand **Security**, expand **Logins**, and double-click your own login. On the **Server Roles** page, select **sysadmin**, and then click **OK**. \r\n", 266 | " \r\n", 267 | " b. Instead of connecting with Object Explorer, connect with a Query Window using Windows Authentication (which includes your Administrator credentials). (You can only connect this way if you did not connect with Object Explorer.) Execute code such as the following to add a new Windows Authentication login that is a member of the **sysadmin** fixed server role. The following example adds a domain user named `CONTOSO\\PatK`. \r\n", 268 | " " 269 | ], 270 | "metadata": { 271 | "azdata_cell_guid": "e45b51aa-320c-437e-ad13-ef92b8deacdc" 272 | } 273 | }, 274 | { 275 | "cell_type": "code", 276 | "source": [ 277 | "CREATE LOGIN [CONTOSO\\PatK] FROM WINDOWS; \r\n", 278 | "ALTER SERVER ROLE sysadmin ADD MEMBER [CONTOSO\\PatK];" 279 | ], 280 | "metadata": { 281 | "azdata_cell_guid": "c316a5d9-41e7-4dd3-9bbf-bcbd9442b829" 282 | }, 283 | "outputs": [], 284 | "execution_count": null 285 | }, 286 | { 287 | "cell_type": "markdown", 288 | "source": [ 289 | "           c. If your SQL Server is running in mixed authentication mode, connect with a Query Window using Windows Authentication (which includes your Administrator credentials). Execute code such as the following to create a new SQL Server authentication login that is a member of the **sysadmin** fixed server role." 290 | ], 291 | "metadata": { 292 | "azdata_cell_guid": "ffbcc30c-e772-4b86-9022-b86d3d0852e9" 293 | }, 294 | "attachments": {} 295 | }, 296 | { 297 | "cell_type": "code", 298 | "source": [ 299 | "CREATE LOGIN TempLogin WITH PASSWORD = '************'; \r\n", 300 | "ALTER SERVER ROLE sysadmin ADD MEMBER TempLogin; " 301 | ], 302 | "metadata": { 303 | "azdata_cell_guid": "c80a9307-0b94-4896-befc-ff495a197133" 304 | }, 305 | "outputs": [], 306 | "execution_count": null 307 | }, 308 | { 309 | "cell_type": "markdown", 310 | "source": [ 311 | " > \\[!WARNING\\] \n", 312 | " > Replace ****\\*\\*\\*\\***** with a strong password.\n", 313 | "\n", 314 | "          d. If your SQL Server is running in mixed authentication mode and you want to reset the password of the **sa** account, connect with a Query Window using Windows Authentication (which includes your Administrator credentials). Change the password of the **sa** account with the following syntax." 315 | ], 316 | "metadata": { 317 | "azdata_cell_guid": "19866c10-db4d-45b5-9d75-4e7575639247" 318 | }, 319 | "attachments": {} 320 | }, 321 | { 322 | "cell_type": "code", 323 | "source": [ 324 | "ALTER LOGIN sa WITH PASSWORD = '************'; " 325 | ], 326 | "metadata": { 327 | "azdata_cell_guid": "984ef2f0-f2a7-43e7-8a9f-a1c343319c71" 328 | }, 329 | "outputs": [], 330 | "execution_count": null 331 | }, 332 | { 333 | "cell_type": "markdown", 334 | "source": [ 335 | " \r\n", 336 | " > [!WARNING] \r\n", 337 | " > Replace ************ with a strong password. \r\n", 338 | "\r\n", 339 | "7. Close [!INCLUDE[ssManStudio](../../includes/ssmanstudio-md.md)]. \r\n", 340 | " \r\n", 341 | "8. These next few steps change SQL Server back to multi-user mode. In SQL Server Configuration Manager, in the left pane, select **SQL Server Services**.\r\n", 342 | "\r\n", 343 | "9. In the right-pane, right-click the instance of SQL Server, and then click **Properties**. \r\n", 344 | " \r\n", 345 | "10. On the **Startup Parameters** tab, in the **Existing parameters** box, select `-m` and then click **Remove**. \r\n", 346 | " \r\n", 347 | " > [!NOTE] \r\n", 348 | " > For some earlier versions of SQL Server there is no **Startup Parameters** tab. In that case, on the **Advanced** tab, double-click **Startup Parameters**. The parameters open up in a very small window. Remove the `;-m` which you added earlier, and then click **OK**. \r\n", 349 | " \r\n", 350 | "11. Right-click your server name, and then click **Restart**. Make sure to start SQL Server Agent again if you stopped it before starting SQL Server in single-user mode.\r\n", 351 | " \r\n", 352 | "Now you should be able to connect normally with one of the accounts that is now a member of the **sysadmin** fixed server role. \r\n", 353 | " \r\n", 354 | "## See Also \r\n", 355 | "\r\n", 356 | "* [Configure server startup options](../../database-engine/configure-windows/scm-services-configure-server-startup-options.md)\r\n", 357 | "* [Database Engine Service Startup Options](../../database-engine/configure-windows/database-engine-service-startup-options.md) \r\n", 358 | "" 359 | ], 360 | "metadata": { 361 | "azdata_cell_guid": "c0fc7b68-8f51-46ad-8317-523e11103ebf" 362 | } 363 | } 364 | ] 365 | } 366 | -------------------------------------------------------------------------------- /sample-scripts/DOCs-to-Notebooks/T-shooting_PagelatchEX_LastPageInsert.ipynb: -------------------------------------------------------------------------------- 1 | { 2 | "metadata": { 3 | "kernelspec": { 4 | "name": "SQL", 5 | "display_name": "SQL", 6 | "language": "sql" 7 | }, 8 | "language_info": { 9 | "name": "sql", 10 | "version": "" 11 | }, 12 | "azdata_notebook_guid": "4612E70F-04A9-4645-810C-A25C209EAB9C", 13 | "extensions": { 14 | "azuredatastudio": { 15 | "version": 1, 16 | "views": [] 17 | } 18 | } 19 | }, 20 | "nbformat_minor": 2, 21 | "nbformat": 4, 22 | "cells": [ 23 | { 24 | "cell_type": "markdown", 25 | "source": [ 26 | "# Resolve last-page insert PAGELATCH_EX contention in SQL Server\r\n", 27 | "\r\n", 28 | "This article introduces how to resolve last-page insert PAGELATCH_EX contention in SQL Server.\r\n", 29 | "\r\n", 30 | "_Original product version:_   SQL Server \r\n", 31 | "_Original KB number:_   4460004\r\n", 32 | "\r\n", 33 | "## Symptoms\r\n", 34 | "\r\n", 35 | "Consider the following scenarios:\r\n", 36 | "\r\n", 37 | "- You have a column that includes sequential values, such as an Identity column or a DateTime column, that is being inserted through the **Getdate()** function.\r\n", 38 | "\r\n", 39 | "- You have a clustered index that has the sequential column as a leading column.\r\n", 40 | "\r\n", 41 | " > [!NOTE]\r\n", 42 | " > The most common scenario is a clustered primary key on an Identity column. Less frequently, this issue can be observed for nonclustered indexes.\r\n", 43 | "\r\n", 44 | "- Your application does frequent INSERT or UPDATE operations against the table.\r\n", 45 | "\r\n", 46 | "- You have many CPUs on the system. Typically, the server has 16 CPUs or more. This allows multiple sessions to do the INSERT operations against the same table concurrently.\r\n", 47 | "\r\n", 48 | "In this situation, you may experience a decrease in performance of your application. When you examine wait types in **sys.dm_exec_requests**, you observe waits on the **PAGELATCH_EX** wait type and many sessions that are waiting on this wait type.\r\n", 49 | "\r\n", 50 | "Another issue occurs if you run the following diagnostic query on your system:\r\n", 51 | "\r\n", 52 | "**select session_id, wait_type, wait_time, wait_resource from sys.dm_exec_requests where session_id > 50 and wait_type = 'pagelatch_ex'**\r\n", 53 | "\r\n", 54 | "In this situation, you may get results that resemble the following.\r\n", 55 | "\r\n", 56 | "|session_id |wait_type |wait_time |wait_resource |\r\n", 57 | "|----------| ---------------------- |---------------| ------------------------|\r\n", 58 | "| 60 |PAGELATCH_EX |100 |5:1:4144|\r\n", 59 | "| 75 |PAGELATCH_EX| 123| 5:1:4144|\r\n", 60 | "| 79| PAGELATCH_EX |401 |5:1:4144 |\r\n", 61 | "|80 |PAGELATCH_EX |253 |5:1:4144 |\r\n", 62 | "|81 |PAGELATCH_EX |312 |5:1:4144 |\r\n", 63 | "|82 |PAGELATCH_EX |355 |5:1:4144 |\r\n", 64 | "|84 |PAGELATCH_EX |312| 5:1:4144 |\r\n", 65 | "|85 |PAGELATCH_EX |338 |5:1:4144 |\r\n", 66 | "|87| PAGELATCH_EX |405| 5:1:4144 |\r\n", 67 | "|88 |PAGELATCH_EX |111 |5:1:4144 |\r\n", 68 | "|90 |PAGELATCH_EX |38 |5:1:4144 |\r\n", 69 | "|92 |PAGELATCH_EX |115 |5:1:4144|\r\n", 70 | "| 94| PAGELATCH_EX| 49 |5:1:4144|\r\n", 71 | "| 101| PAGELATCH_EX |301 |5:1:4144 |\r\n", 72 | "|102 |PAGELATCH_EX |45| 5:1:4144 |\r\n", 73 | "|103 |PAGELATCH_EX |515 |5:1:4144 |\r\n", 74 | "|105| PAGELATCH_EX |39| 5:1:4144|\r\n", 75 | "\r\n", 76 | "You notice that multiple sessions are all waiting for the same resource that resembles the following:\r\n", 77 | "\r\n", 78 | "database_id = 5, file_id = 1, database page_id = 4144\r\n", 79 | "\r\n", 80 | "> [!NOTE]\r\n", 81 | "> The database_id should be a user database (the ID number is greater than or equal to **5**). If the database_id is **2**, you may, instead, be experiencing the issue that is discussed in [Files, trace flags and updates on TEMPDB](/archive/blogs/sql_server_team/tempdb-files-and-trace-flags-and-updates-oh-my).\r\n", 82 | "\r\n", 83 | "## Cause\r\n", 84 | "\r\n", 85 | "**PAGELATCH** (latch on a data or index page) is a thread-synchronization mechanism. It is used to synchronize short-term physical access to database pages that are located in the Buffer cache.\r\n", 86 | "\r\n", 87 | "**PAGELATCH** differs from a **PAGEIOLATCH**. The latter is used to synchronize physical access to pages when they are read from or written to disk.\r\n", 88 | "\r\n", 89 | "Page latches are common in every system because they ensure physical page protection. A clustered index orders the data by the leading key column. For this reason, when you create the index on a sequential column, this causes all new data inserts to occur on the same page at the end of the index until that page is filled. However, under high load, the concurrent INSERT operations may cause contention on the last page of the B-tree. This contention can occur on clustered and nonclustered indexes. This is because the nonclustered index orders the leaf-level pages by the leading key. This issue is also known as last-page insert contention.\r\n", 90 | "\r\n", 91 | "For more information, see [Diagnosing and Resolving Latch Contention on SQL Server](/sql/relational-databases/diagnose-resolve-latch-contention).\r\n", 92 | "\r\n", 93 | "## Resolution\r\n", 94 | "\r\n", 95 | "To resolve this contention, the overall strategy is to prevent all concurrent INSERT operations from accessing the same database page. Instead, make each INSERT operation access a different page and increase concurrency. Therefore, any of the following methods that organize the data by a column other than the sequential column achieves this goal.\r\n", 96 | "\r\n", 97 | "### 1. Confirm the contention on PAGELATCH_EX and identify the contention resource\r\n", 98 | "\r\n", 99 | "This T-SQL script helps you discover if there are `PAGELATCH_EX` waits on the system with multiple sessions (5 or more) with significant wait time (10 ms or more). It also helps you discover which object and index the contention is on using [sys.dm_exec_requests](/sql/relational-databases/system-dynamic-management-views/sys-dm-exec-requests-transact-sql) and [DBCC PAGE](https://techcommunity.microsoft.com/t5/sql-server/how-to-use-dbcc-page/ba-p/383094) or [sys.fn_PageResCracker](/sql/relational-databases/system-functions/sys-fn-pagerescracker-transact-sql) and [sys.dm_db_page_info](/sql/relational-databases/system-dynamic-management-views/sys-dm-db-page-info-transact-sql) (SQL Server 2019 only)." 100 | ], 101 | "metadata": { 102 | "azdata_cell_guid": "8528e73c-9a46-482b-a409-2200bf60c3b5" 103 | }, 104 | "attachments": {} 105 | }, 106 | { 107 | "cell_type": "code", 108 | "source": [ 109 | "SET NOCOUNT ON \r\n", 110 | "DECLARE @dbname SYSNAME, @dbid INT, @objectid INT, @indexid INT, @indexname SYSNAME, @sql VARCHAR(8000), @manul_identification VARCHAR(8000)\r\n", 111 | "\r\n", 112 | "IF (CONVERT(INT, SERVERPROPERTY('ProductMajorVersion')) >= 15)\r\n", 113 | "BEGIN\r\n", 114 | "\r\n", 115 | " DROP TABLE IF EXISTS #PageLatchEXContention\r\n", 116 | "\r\n", 117 | " SELECT DB_NAME(page_info.database_id) DbName, r.db_id DbId, page_info.[object_id] ObjectId, page_info.index_id IndexId\r\n", 118 | " INTO #PageLatchEXContention\r\n", 119 | " FROM sys.dm_exec_requests AS er\r\n", 120 | " CROSS APPLY sys.dm_exec_sql_text(er.sql_handle) AS st \r\n", 121 | " CROSS APPLY sys.fn_PageResCracker (er.page_resource) AS r \r\n", 122 | " CROSS APPLY sys.dm_db_page_info(r.[db_id], r.[file_id], r.page_id, 'DETAILED') AS page_info\r\n", 123 | " WHERE er.wait_type = 'PAGELATCH_EX' AND page_info.database_id not in (db_id('master'),db_id('msdb'), db_id('model'), db_id('tempdb')) \r\n", 124 | " GROUP BY DB_NAME(page_info.database_id), r.db_id, page_info.[object_id], page_info.index_id\r\n", 125 | " HAVING COUNT(er.session_id) > 5 AND Max (er.wait_time) > 10\r\n", 126 | "\r\n", 127 | " SELECT * FROM #PageLatchEXContention \r\n", 128 | " IF EXISTS (SELECT 1 FROM #PageLatchEXContention) \r\n", 129 | " BEGIN\r\n", 130 | " DECLARE optimize_for_seq_key_cursor CURSOR FOR\r\n", 131 | " SELECT DbName, DbId, ObjectId, IndexId FROM #PageLatchEXContention \r\n", 132 | " \r\n", 133 | " OPEN optimize_for_seq_key_cursor\r\n", 134 | " FETCH NEXT FROM optimize_for_seq_key_cursor into @dbname, @dbid, @objectid , @indexid \r\n", 135 | " WHILE @@FETCH_STATUS = 0\r\n", 136 | " BEGIN\r\n", 137 | " SELECT 'Consider using below statement to enable OPTIMIZE_FOR_SEQUENTIAL_KEY for the indexes in the \"' + @dbname + '\" database' AS Recommendation\r\n", 138 | " SELECT @sql = 'select ''use ' + @dbname + '; ALTER INDEX '' + i.name + '' ON ' + OBJECT_NAME(@objectid, @dbid) + ' SET (OPTIMIZE_FOR_SEQUENTIAL_KEY = ON )'' AS Corrective_Action from #PageLatchEXContention pl JOIN ' + @dbname+'.sys.indexes i ON pl.ObjectID = i.object_id WHERE object_id = ' + CONVERT(VARCHAR, @objectid) + ' AND index_id = ' + CONVERT(VARCHAR, @indexid)\r\n", 139 | "\r\n", 140 | " EXECUTE (@sql) \r\n", 141 | " FETCH NEXT FROM optimize_for_seq_key_cursor INTO @dbname, @dbid, @objectid , @indexid \r\n", 142 | "\r\n", 143 | " END\r\n", 144 | "\r\n", 145 | " CLOSE optimize_for_seq_key_cursor\r\n", 146 | " DEALLOCATE optimize_for_seq_key_cursor\r\n", 147 | " \r\n", 148 | " END\r\n", 149 | " ELSE\r\n", 150 | " SELECT 'No PAGELATCH_EX contention found on user databases on in SQL Server at this time'\r\n", 151 | "END\r\n", 152 | "ELSE\r\n", 153 | "BEGIN\r\n", 154 | " \r\n", 155 | " IF OBJECT_ID('tempdb..#PageLatchEXContentionLegacy') IS NOT NULL\r\n", 156 | " DROP TABLE #PageLatchEXContentionLegacy\r\n", 157 | " \r\n", 158 | " SELECT 'dbcc traceon (3604); dbcc page(' + replace(wait_resource,':',',') + ',3); dbcc traceoff (3604)' TSQL_Command\r\n", 159 | " INTO #PageLatchEXContentionLegacy\r\n", 160 | " FROM sys.dm_exec_requests er\r\n", 161 | " WHERE er.wait_type = 'PAGELATCH_EX' AND er.database_id NOT IN (db_id('master'),db_id('msdb'), db_id('model'), db_id('tempdb')) \r\n", 162 | " GROUP BY wait_resource\r\n", 163 | " HAVING COUNT(er.session_id) > 5 AND Max (er.wait_time) > 10\r\n", 164 | "\r\n", 165 | " SELECT * FROM #PageLatchEXContentionLegacy\r\n", 166 | " \r\n", 167 | " IF EXISTS(SELECT 1 FROM #PageLatchEXContentionLegacy)\r\n", 168 | " BEGIN\r\n", 169 | " SELECT 'On SQL Server 2017 or lower versions, you can manually identify the object where contention is occurring using DBCC PAGE locate the m_objId = ??. Then SELECT OBJECT_NAME(object_id_identified) and locate indexes with sequential values in this object' AS Recommendation\r\n", 170 | " \r\n", 171 | " DECLARE get_command CURSOR FOR\r\n", 172 | " SELECT TSQL_Command from #PageLatchEXContentionLegacy \r\n", 173 | "\r\n", 174 | " OPEN get_command\r\n", 175 | " FETCH NEXT FROM get_command into @sql\r\n", 176 | " WHILE @@FETCH_STATUS = 0\r\n", 177 | " BEGIN\r\n", 178 | " SELECT @sql AS Step1_Run_This_Command_To_Find_Object\r\n", 179 | " SELECT 'select OBJECT_NAME(object_id_identified)' AS Step2_Find_Object_Name_From_ID\r\n", 180 | " FETCH NEXT FROM get_command INTO @sql\r\n", 181 | " END\r\n", 182 | "\r\n", 183 | " CLOSE get_command\r\n", 184 | " DEALLOCATE get_command\r\n", 185 | "\r\n", 186 | " SELECT 'Follow https://docs.microsoft.com/troubleshoot/sql/performance/resolve-pagelatch-ex-contention for resolution recommendations that fits your environment best' Step3_Apply_KB_article\r\n", 187 | " \r\n", 188 | " END\r\n", 189 | " ELSE\r\n", 190 | " SELECT 'No PAGELATCH_EX contention found on user databases on in SQL Server at this time'\r\n", 191 | "\r\n", 192 | "END" 193 | ], 194 | "metadata": { 195 | "azdata_cell_guid": "53942579-6858-4486-8e29-ee9d4ef5885e" 196 | }, 197 | "outputs": [], 198 | "execution_count": null 199 | }, 200 | { 201 | "cell_type": "markdown", 202 | "source": [ 203 | "\r\n", 204 | "### 2. Choose a method to resolve the issue\r\n", 205 | "\r\n", 206 | "One of the following methods will help you resolve the issue. Choose the one that best fits your circumstances.\r\n", 207 | "\r\n", 208 | "### **Method 1: Use OPTIMIZE_FOR_SEQUENTIAL_KEY index option (SQL Server 2019 only)**\r\n", 209 | "\r\n", 210 | "In SQL Server 2019, a new index option (`OPTIMIZE_FOR_SEQUENTIAL_KEY`) was added that can help resolve this issue without using any of the following methods. See [Behind the Scenes on OPTIMIZE_FOR_SEQUENTIAL_KEY](https://techcommunity.microsoft.com/t5/SQL-Server/Behind-the-Scenes-on-OPTIMIZE-FOR-SEQUENTIAL-KEY/ba-p/806888) for more information.\r\n", 211 | "\r\n", 212 | "### **Method 2: Move primary key off identity column**\r\n", 213 | "\r\n", 214 | "Make the column that contains sequential values a nonclustered index, and then move the clustered index to another column. For example, for a primary key on an identity column, remove the clustered primary key, and then re-create it as a nonclustered primary key. This is the easiest method to follow, and it directly achieves the goal.\r\n", 215 | "\r\n", 216 | "For example, assume that you have the following table that was defined by using a clustered primary key on an Identity column." 217 | ], 218 | "metadata": { 219 | "azdata_cell_guid": "99116be7-e7cc-4903-9a35-49830e053116" 220 | } 221 | }, 222 | { 223 | "cell_type": "code", 224 | "source": [ 225 | "USE testDb;\r\n", 226 | "\r\n", 227 | "CREATE TABLE Customers \r\n", 228 | "( CustomerID bigint identity(1,1) not null Primary Key CLUSTERED, \r\n", 229 | "CustomerLastName varchar (32) not null, \r\n", 230 | "CustomerFirstName varchar(32) not null )" 231 | ], 232 | "metadata": { 233 | "azdata_cell_guid": "edb14efb-2ed7-4320-b8f1-6381de86ba49" 234 | }, 235 | "outputs": [], 236 | "execution_count": null 237 | }, 238 | { 239 | "cell_type": "markdown", 240 | "source": [ 241 | "\r\n", 242 | "To change this, you can remove the primary key index and redefine it." 243 | ], 244 | "metadata": { 245 | "azdata_cell_guid": "8a819017-fd2b-4765-b081-d02fac0945ec" 246 | } 247 | }, 248 | { 249 | "cell_type": "code", 250 | "source": [ 251 | "USE testDb;\r\n", 252 | "\r\n", 253 | "ALTER TABLE Customers \r\n", 254 | "DROP CONSTRAINT PK__Customer__A4AE64B98819CFF6 ;\r\n", 255 | "\r\n", 256 | "ALTER TABLE Customers \r\n", 257 | "add constraint pk_Cust1 \r\n", 258 | "primary key NONCLUSTERED (CustomerID)" 259 | ], 260 | "metadata": { 261 | "azdata_cell_guid": "042075f1-e0d4-44c8-b3f4-f9b641127095" 262 | }, 263 | "outputs": [], 264 | "execution_count": null 265 | }, 266 | { 267 | "cell_type": "markdown", 268 | "source": [ 269 | "### **Method 3: Make the leading key a non-sequential column**\r\n", 270 | "\r\n", 271 | "Reorder the clustered index definition in such a way that the leading column isn't the sequential column. This requires that the clustered index be a composite index. For example, in a customer table, you can make a **CustomerLastName** column be the leading column, followed by the **CustomerID**. We recommend that you thoroughly test this method to make sure that it meets performance requirements.\r\n", 272 | "" 273 | ], 274 | "metadata": { 275 | "azdata_cell_guid": "838e14e2-936e-477f-9dc5-cb4f6b3cf1a5" 276 | }, 277 | "attachments": {} 278 | }, 279 | { 280 | "cell_type": "code", 281 | "source": [ 282 | "USE testDb;\r\n", 283 | "\r\n", 284 | "ALTER TABLE Customers \r\n", 285 | "add constraint pk_Cust1 \r\n", 286 | "primary key clustered (CustomerLastName, CustomerID)" 287 | ], 288 | "metadata": { 289 | "azdata_cell_guid": "946e3fae-0393-44d7-9cf2-60302cee8882" 290 | }, 291 | "outputs": [], 292 | "execution_count": null 293 | }, 294 | { 295 | "cell_type": "markdown", 296 | "source": [ 297 | "### **Method 4: Add a non-sequential value as a leading key**\r\n", 298 | "\r\n", 299 | "Add a nonsequential hash value as the leading index key. This will also spread out the inserts. A hash value is generated as a modulo that matches the number of CPUs on the system. For example, on a 16-CPU system, you can use a modulo of 16. This method spreads out the INSERT operations uniformly against multiple database pages." 300 | ], 301 | "metadata": { 302 | "azdata_cell_guid": "5feb1f44-6a32-4545-953e-cefed69c7bcc" 303 | } 304 | }, 305 | { 306 | "cell_type": "code", 307 | "source": [ 308 | "USE testDb;\r\n", 309 | "\r\n", 310 | "CREATE TABLE Customers \r\n", 311 | "( CustomerID bigint identity(1,1) not null, \r\n", 312 | "CustomerLastName varchar (32) not null, \r\n", 313 | "CustomerFirstName varchar(32) not null ) ;\r\n", 314 | "\r\n", 315 | "\r\n", 316 | "ALTER TABLE Customers \r\n", 317 | "ADD [HashValue] AS (CONVERT([tinyint], abs([CustomerID])%16)) PERSISTED NOT NULL ;\r\n", 318 | "\r\n", 319 | "\r\n", 320 | "ALTER TABLE Customers \r\n", 321 | "ADD CONSTRAINT pk_table1 \r\n", 322 | "PRIMARY KEY CLUSTERED (HashValue, CustomerID);" 323 | ], 324 | "metadata": { 325 | "azdata_cell_guid": "a0702537-1bb1-46d2-9604-428cd1293b30" 326 | }, 327 | "outputs": [], 328 | "execution_count": null 329 | }, 330 | { 331 | "cell_type": "markdown", 332 | "source": [ 333 | "### **Method 5: Use a GUID as a leading key**\r\n", 334 | "\r\n", 335 | "Use a GUID as the leading key column of an index to ensure the uniform distribution of inserts.\r\n", 336 | "\r\n", 337 | "> [!NOTE]\r\n", 338 | "> Although it achieves the goal, we don't recommend this method because it presents multiple challenges, including a large index key, frequent page splits, low page density, and so on.\r\n", 339 | "\r\n", 340 | "### **Method 6: Use table partitioning and a computed column with a hash value**\r\n", 341 | "\r\n", 342 | "Use table partitioning and a computed column that has a hash value to spread out the INSERT operations. Because this method uses table partitioning, it's usable only on Enterprise editions of SQL Server.\r\n", 343 | "\r\n", 344 | "> [!NOTE]\r\n", 345 | "> You can use Partitioned tables in SQL Server 2016 SP1 Standard Edition. For more information, see the description of \"Table and index partitioning\" in the article [Editions and supported features of SQL Server 2016](/sql/sql-server/editions-and-components-of-sql-server-2016?view=sql-server-2017#RDBMSSP&preserve-view=true).\r\n", 346 | "\r\n", 347 | "The following is an example in a system that has 16 CPUs.\r\n", 348 | "\r\n", 349 | "" 350 | ], 351 | "metadata": { 352 | "azdata_cell_guid": "41e64205-cbe5-4920-ab45-c4efc9c6fe5c" 353 | } 354 | }, 355 | { 356 | "cell_type": "code", 357 | "source": [ 358 | "USE testDb;\r\n", 359 | "\r\n", 360 | "CREATE TABLE Customers \r\n", 361 | "( CustomerID bigint identity(1,1) not null, \r\n", 362 | "CustomerLastName varchar (32) not null, \r\n", 363 | "CustomerFirstName varchar(32) not null ) ;\r\n", 364 | "\r\n", 365 | "ALTER TABLE Customers \r\n", 366 | "ADD [HashID] AS CONVERT(tinyint, ABS(CustomerID % 16)) PERSISTED NOT NULL;\r\n", 367 | "\r\n", 368 | "\r\n", 369 | "CREATE PARTITION FUNCTION pf_hash (tinyint) AS RANGE LEFT FOR VALUES (0,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15) ;\r\n", 370 | "\r\n", 371 | "CREATE PARTITION SCHEME ps_hash AS PARTITION pf_hash ALL TO ([PRIMARY]) ;\r\n", 372 | "\r\n", 373 | "CREATE UNIQUE CLUSTERED INDEX CIX_Hash \r\n", 374 | "ON Customers (CustomerID, HashID) ON ps_hash(HashID);\r\n", 375 | "" 376 | ], 377 | "metadata": { 378 | "azdata_cell_guid": "0df81726-3a1f-423d-951a-b798e47dda08" 379 | }, 380 | "outputs": [ 381 | { 382 | "output_type": "display_data", 383 | "data": { 384 | "text/html": "Partition scheme 'ps_hash' has been created successfully. 'PRIMARY' is marked as the next used filegroup in partition scheme 'ps_hash'." 385 | }, 386 | "metadata": {} 387 | }, 388 | { 389 | "output_type": "error", 390 | "ename": "", 391 | "evalue": "Msg 3728, Level 16, State 1, Line 14\r\n'PK__Customer__A4AE64B98819CFF6' is not a constraint.", 392 | "traceback": [] 393 | }, 394 | { 395 | "output_type": "error", 396 | "ename": "", 397 | "evalue": "Msg 3727, Level 16, State 0, Line 14\r\nCould not drop constraint. See previous errors.", 398 | "traceback": [] 399 | }, 400 | { 401 | "output_type": "display_data", 402 | "data": { 403 | "text/html": "Total execution time: 00:00:00.019" 404 | }, 405 | "metadata": {} 406 | } 407 | ], 408 | "execution_count": 2 409 | }, 410 | { 411 | "cell_type": "markdown", 412 | "source": [ 413 | "### **Method 7: Switch to In-Memory OLTP**\r\n", 414 | "\r\n", 415 | "Alternatively, use In-Memory OLTP particularly if the latch contention is high. This technology eliminates the latch contention overall. However, you have to redesign and migrate the specific table(s), where page latch contention is observed, to a memory-optimized table. You can use the [Memory Optimization Advisor](/sql/relational-databases/in-memory-oltp/memory-optimization-advisor?view=sql-server-2017&preserve-view=true) and [Transaction Performance Analysis Report](/sql/relational-databases/in-memory-oltp/determining-if-a-table-or-stored-procedure-should-be-ported-to-in-memory-oltp?view=sql-server-2017&preserve-view=true) to determine whether migration is possible and the effort involved to do the migration. For more information about how In-Memory OLTP eliminates latch contention, download and review the document in [In-Memory OLTP - Common Workload Patterns and Migration Considerations](/previous-versions/dn673538(v=msdn.10)).\r\n", 416 | "\r\n", 417 | "## **References**\r\n", 418 | "\r\n", 419 | "[PAGELATCH_EX waits and heavy inserts](/archive/blogs/blogdoezequiel/pagelatch_ex-waits-and-heavy-inserts)" 420 | ], 421 | "metadata": { 422 | "azdata_cell_guid": "970f3120-0021-4694-b8f4-5b6b38ff92aa" 423 | } 424 | } 425 | ] 426 | } -------------------------------------------------------------------------------- /sample-scripts/DOCs-to-Notebooks/MSSQLSERVER_35250.ipynb: -------------------------------------------------------------------------------- 1 | { 2 | "metadata": { 3 | "kernelspec": { 4 | "name": "powershell", 5 | "display_name": "PowerShell", 6 | "language": "powershell" 7 | }, 8 | "language_info": { 9 | "name": "powershell", 10 | "codemirror_mode": "shell", 11 | "mimetype": "text/x-sh", 12 | "file_extension": ".ps1" 13 | }, 14 | "azdata_notebook_guid": "6CEA0362-E666-4456-B88F-CAFCC74E749C", 15 | "extensions": { 16 | "azuredatastudio": { 17 | "version": 1, 18 | "views": [] 19 | } 20 | } 21 | }, 22 | "nbformat_minor": 2, 23 | "nbformat": 4, 24 | "cells": [ 25 | { 26 | "cell_type": "markdown", 27 | "source": [ 28 | "# MSSQLSERVER\\_35250\n", 29 | "\n", 30 | "Applies to: ![yes](https://docs.microsoft.com/en-us/sql/includes/media/yes-icon.png?view=sql-server-2016)SQL Server (all supported versions)\n", 31 | "\n", 32 | "## DETAILS\n", 33 | "\n", 34 | "| Attribute | Value |\n", 35 | "| --- | --- |\n", 36 | "| Product Name | SQL Server |\n", 37 | "| Event ID | 35250 |\n", 38 | "| Event Source | MSSQLSERVER |\n", 39 | "| Component | SQLEngine |\n", 40 | "| Symbolic Name | HADR\\_PRIMARYNOTACTIVE |\n", 41 | "| Message Text | The connection to the primary replica is not active. The command cannot be processed. |\n", 42 | "\n", 43 | "### [](https://docs.microsoft.com/en-us/sql/relational-databases/errors-events/mssqlserver-35250-database-engine-error?view=sql-server-2016#explanation)" 44 | ], 45 | "metadata": { 46 | "azdata_cell_guid": "c7e761ea-489e-4e51-b4a9-c6fa79e0fae8", 47 | "extensions": { 48 | "azuredatastudio": { 49 | "views": [] 50 | } 51 | } 52 | } 53 | }, 54 | { 55 | "cell_type": "markdown", 56 | "source": [ 57 | "**Please make sure to change the values of these variables to match your environment**" 58 | ], 59 | "metadata": { 60 | "azdata_cell_guid": "7d365faf-7c43-4cd0-ac74-ad6a0f8e75cf", 61 | "extensions": { 62 | "azuredatastudio": { 63 | "views": [] 64 | } 65 | } 66 | }, 67 | "attachments": {} 68 | }, 69 | { 70 | "cell_type": "code", 71 | "source": [ 72 | "$ServerName = \"MyServer\" #replace with server name or virtual name in dobule-quotes \"MyServer\"\r\n", 73 | "$server_IP_address = \"192.168.2.27\"\r\n", 74 | "$port_number = 1433\r\n", 75 | "$DBName = \"master\"\r\n", 76 | "[string] $SQLInstance= $ServerName + \"\\\" + \"sql2017\" # please replace with server\\instance format. For default instance, just use $ServerName\r\n", 77 | "\r\n", 78 | "\r\n", 79 | "#create the SQL function to use throughout\r\n", 80 | "function ExecuteSqlQuery ($SQLInstance, $DBName, $SqlQuery) \r\n", 81 | "{\r\n", 82 | " \r\n", 83 | " $SqlConnection = New-Object System.Data.SQLClient.SQLConnection\r\n", 84 | " $SqlConnection.ConnectionString = \"server='$SQLInstance';database='$DBName';trusted_connection=true;\"\r\n", 85 | " $SqlConnection.Open()\r\n", 86 | " $SqlCmd = New-Object System.Data.SQLClient.SQLCommand\r\n", 87 | " $SqlCmd.Connection = $SqlConnection\r\n", 88 | " $SqlCmd.CommandText = $SQLQuery\r\n", 89 | " $Result = $SqlCmd.ExecuteReader()\r\n", 90 | " $DT = New-Object System.Data.DataTable \r\n", 91 | " $DT.Load($Result)\r\n", 92 | " $SqlConnection.Close() \r\n", 93 | " return $DT\r\n", 94 | "}" 95 | ], 96 | "metadata": { 97 | "azdata_cell_guid": "19304c57-1660-4a71-9b47-aea65355e375", 98 | "tags": [], 99 | "extensions": { 100 | "azuredatastudio": { 101 | "views": [] 102 | } 103 | } 104 | }, 105 | "outputs": [], 106 | "execution_count": null 107 | }, 108 | { 109 | "cell_type": "markdown", 110 | "source": [ 111 | "### Explanation\n", 112 | "\n", 113 | "This message occurs when attempting to join secondary databases to an Always On availability group. Inability to connect to the endpoint can typically cause this error.\n", 114 | "\n", 115 | "### [](https://docs.microsoft.com/en-us/sql/relational-databases/errors-events/mssqlserver-35250-database-engine-error?view=sql-server-2016#user-action)User Action\n", 116 | "\n", 117 | "> NOTE \n", 118 | "> All the following steps must be run on both the Primary replica and the problematic Secondary replica(s).\n", 119 | "\n", 120 | "1. Ensure the endpoint is created and started. Run the following query to discover the endpoint." 121 | ], 122 | "metadata": { 123 | "azdata_cell_guid": "478c72f4-fcf7-4867-b583-28559ba8f2da", 124 | "extensions": { 125 | "azuredatastudio": { 126 | "views": [] 127 | } 128 | } 129 | } 130 | }, 131 | { 132 | "cell_type": "code", 133 | "source": [ 134 | "clear\r\n", 135 | "\r\n", 136 | "\r\n", 137 | "[string] $SqlQuery= $(\"SELECT\r\n", 138 | " tep.name as EndPointName,\r\n", 139 | " sp.name As CreatedBy,\r\n", 140 | " tep.type_desc,\r\n", 141 | " tep.state_desc,\r\n", 142 | " tep.port\r\n", 143 | " FROM\r\n", 144 | " sys.tcp_endpoints tep\r\n", 145 | " INNER JOIN sys.server_principals sp ON tep.principal_id = sp.principal_id\r\n", 146 | " WHERE tep.type = 4\")\r\n", 147 | "\r\n", 148 | "$DT = New-Object System.Data.DataTable\r\n", 149 | "$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 150 | "\r\n", 151 | "#print the results\r\n", 152 | "$DT | Format-Table\r\n", 153 | "\r\n", 154 | "Write-Host (\"The Resultset contains: \" + $DT.Rows.Count + \" rows\")\r\n", 155 | "" 156 | ], 157 | "metadata": { 158 | "azdata_cell_guid": "4dcc5adc-8374-482b-b356-f1f00ac87edb", 159 | "tags": [], 160 | "extensions": { 161 | "azuredatastudio": { 162 | "views": [] 163 | } 164 | } 165 | }, 166 | "outputs": [], 167 | "execution_count": null 168 | }, 169 | { 170 | "cell_type": "markdown", 171 | "source": [ 172 | "> WARNING\n", 173 | "> Use caution when executing the next command as it can cause a momentary downtime for the replica.\n", 174 | "\n", 175 | "You can use these commands to restart the endpoint you discovered\n", 176 | "\n", 177 | "**Please make sure to change the values of the $endpoint variable to match your environment**" 178 | ], 179 | "metadata": { 180 | "azdata_cell_guid": "a5b7ba59-f455-447f-a328-7e238549d43c", 181 | "extensions": { 182 | "azuredatastudio": { 183 | "views": [] 184 | } 185 | } 186 | }, 187 | "attachments": {} 188 | }, 189 | { 190 | "cell_type": "code", 191 | "source": [ 192 | "\r\n", 193 | "$endpoint = \"TSQL Default VIA\" #please replace with valid AG/DBM endpoint\r\n", 194 | "\r\n", 195 | "[string] $SqlQuery= \"ALTER ENDPOINT [\" + $endpoint + \"] STATE = STOPPED; ALTER ENDPOINT [\" + $endpoint + \"] STATE = STARTED\"\r\n", 196 | "$DT = New-Object System.Data.DataTable\r\n", 197 | "#$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 198 | "\r\n", 199 | "#check status of endpoint\r\n", 200 | "$SqlQuery= \"SELECT * FROM sys.endpoints WHERE name = '\" + $endpoint +\"'\"\r\n", 201 | "$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 202 | "\r\n", 203 | "$DT | Format-Table\r\n", 204 | "\r\n", 205 | "#validate the data\r\n", 206 | "Write-Host (\"The table contains: \" + $DT.Rows.Count + \" rows\")\r\n", 207 | "" 208 | ], 209 | "metadata": { 210 | "azdata_cell_guid": "637f86e1-5db5-4a98-bb85-272ceb6825a5", 211 | "extensions": { 212 | "azuredatastudio": { 213 | "views": [] 214 | } 215 | } 216 | }, 217 | "outputs": [], 218 | "execution_count": null 219 | }, 220 | { 221 | "cell_type": "markdown", 222 | "source": [ 223 | " 2. Check if you can connect to the endpoint.\n", 224 | " \n", 225 | "\n", 226 | "- Use Telnet to validate connectivity. Here are examples of commands you can use:" 227 | ], 228 | "metadata": { 229 | "azdata_cell_guid": "09872772-70da-45f8-ab21-4c5a9be5cbb8", 230 | "extensions": { 231 | "azuredatastudio": { 232 | "views": [] 233 | } 234 | } 235 | } 236 | }, 237 | { 238 | "cell_type": "code", 239 | "source": [ 240 | "Test-NetConnection -ComputerName $ServerName -Port $port_number\r\n", 241 | "Test-NetConnection -ComputerName $server_IP_address -Port $port_number" 242 | ], 243 | "metadata": { 244 | "azdata_cell_guid": "471cdee8-05e9-47da-9600-fa93054b6877", 245 | "extensions": { 246 | "azuredatastudio": { 247 | "views": [] 248 | } 249 | } 250 | }, 251 | "outputs": [], 252 | "execution_count": null 253 | }, 254 | { 255 | "cell_type": "markdown", 256 | "source": [ 257 | "- If the Endpoint is listening and connection is successful, then you will see a blank screen.  If not, you will receive a connection error from Telnet\n", 258 | "- If Telnet connection to the IP address works but to the ServerName it does not, there is likely a DNS or name resolution issue\n", 259 | "- If connection works by ServerName and not by IP address, then there could be more than one endpoint defined on that server (another SQL instance perhaps) that is listening on that port. Though the status of the endpoint on the instance in question shows \"STARTED\" another instance may actually have the port binding and prevent the correct instance from listening and establishing TCP connections.\n", 260 | "- If Telnet fails to connect, look for Firewall and/or Anti-virus software that may be blocking the endpoint port in question. Check the firewall setting to see if it allows the endpoint port communication between the server instances that host primary replica and the secondary replica (port 5022 by default). Run the following PowerShell script to examine for disabled inbound traffic rules\n", 261 | "- If Telnet fails to connect, look for Firewall and/or antivirus software that may be blocking the endpoint port in question. If you are running SQL Server on Azure VM, additionally you would need to [ensure Network Security Group (NSG) allows the traffic to endpoint port](https://docs.microsoft.com/en-us/azure/virtual-machines/windows/nsg-quickstart-portal#create-an-inbound-security-rule). Check the firewall (and NSG, for Azure VM) setting to see if it allows the endpoint port communication between the server instances that host primary replica and the secondary replica (port 5022 by default)." 262 | ], 263 | "metadata": { 264 | "azdata_cell_guid": "f8024f18-343e-4ab5-bec2-57408c90e466", 265 | "extensions": { 266 | "azuredatastudio": { 267 | "views": [] 268 | } 269 | } 270 | } 271 | }, 272 | { 273 | "cell_type": "code", 274 | "source": [ 275 | "Get-NetFirewallRule -Action Block -Enabled True -Direction Inbound| Format-List" 276 | ], 277 | "metadata": { 278 | "azdata_cell_guid": "97d5a981-8e3b-4a16-a7a8-fdefada3ecb9", 279 | "extensions": { 280 | "azuredatastudio": { 281 | "views": [] 282 | } 283 | } 284 | }, 285 | "outputs": [], 286 | "execution_count": null 287 | }, 288 | { 289 | "cell_type": "markdown", 290 | "source": [ 291 | "- Capture a NETSTAT -a output and verify the status is a LISTENING or ESTABLISHED on the IP:Port for the endpoint specified." 292 | ], 293 | "metadata": { 294 | "azdata_cell_guid": "be46d341-f98f-4c16-98c9-9e7a2dcb5409", 295 | "extensions": { 296 | "azuredatastudio": { 297 | "views": [] 298 | } 299 | } 300 | } 301 | }, 302 | { 303 | "cell_type": "code", 304 | "source": [ 305 | "Get-NetTCPConnection -LocalAddress $server_IP_address" 306 | ], 307 | "metadata": { 308 | "azdata_cell_guid": "7d445c69-733c-46e1-9cc9-9e789bbd6809", 309 | "extensions": { 310 | "azuredatastudio": { 311 | "views": [] 312 | } 313 | } 314 | }, 315 | "outputs": [], 316 | "execution_count": null 317 | }, 318 | { 319 | "cell_type": "markdown", 320 | "source": [ 321 | "3.  Check for errors in the system. You can query the **sys.dm\\_hadr\\_availability\\_replica\\_states** for the last\\_connect\\_error\\_number that may help you diagnose the join issue. Depending on which replica was having difficulty communicating, you can query both the primary and secondary:" 322 | ], 323 | "metadata": { 324 | "azdata_cell_guid": "4db7a8de-33a9-4596-b80e-66b904d016c4", 325 | "extensions": { 326 | "azuredatastudio": { 327 | "views": [] 328 | } 329 | } 330 | } 331 | }, 332 | { 333 | "cell_type": "code", 334 | "source": [ 335 | "[string] $SqlQuery= $(\"select\r\n", 336 | " r.replica_server_name,\r\n", 337 | " r.endpoint_url,\r\n", 338 | " rs.connected_state_desc,\r\n", 339 | " rs.last_connect_error_description,\r\n", 340 | " rs.last_connect_error_number,\r\n", 341 | " rs.last_connect_error_timestamp\r\n", 342 | "from\r\n", 343 | " sys.dm_hadr_availability_replica_states rs\r\n", 344 | " join sys.availability_replicas r on rs.replica_id = r.replica_id\r\n", 345 | "where\r\n", 346 | " rs.is_local = 1\")\r\n", 347 | "$DT = New-Object System.Data.DataTable\r\n", 348 | "$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 349 | "$DT | Format-Table\r\n", 350 | "\r\n", 351 | "#validate the data\r\n", 352 | "Write-Host (\"The table contains: \" + $DT.Rows.Count + \" rows\")" 353 | ], 354 | "metadata": { 355 | "azdata_cell_guid": "593b02cf-0fd6-48db-be44-0948c24d8ad7", 356 | "extensions": { 357 | "azuredatastudio": { 358 | "views": [] 359 | } 360 | } 361 | }, 362 | "outputs": [], 363 | "execution_count": null 364 | }, 365 | { 366 | "cell_type": "markdown", 367 | "source": [ 368 | "For example, if the secondary was unable to communicate with the DNS server or if a replica's endpoint\\_url was configured incorrectly when creating the availability group, you may get the following results in the last\\_connect\\_error\\_description:\n", 369 | "\n", 370 | "`DNS Lookup failed with error '11001(No such host is known)`\n", 371 | "\n", 372 | "4.   Ensure the endpoint is configured for the correct IP/port that AG is defined for\n", 373 | "\n", 374 | "- Run the following query on the Primary and then each Secondary replica that is failing to connect. This will help you find the endpoint URL and port." 375 | ], 376 | "metadata": { 377 | "azdata_cell_guid": "4123de52-a0ed-46bc-bb1f-d7f4d292d403", 378 | "extensions": { 379 | "azuredatastudio": { 380 | "views": [] 381 | } 382 | } 383 | } 384 | }, 385 | { 386 | "cell_type": "code", 387 | "source": [ 388 | "\r\n", 389 | "\r\n", 390 | "[string] $SqlQuery= $(\"select endpoint_url from sys.availability_replicas\")\r\n", 391 | "$DT = New-Object System.Data.DataTable\r\n", 392 | "$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 393 | "\r\n", 394 | "$DT | Format-Table\r\n", 395 | "#validate the data\r\n", 396 | "Write-Host (\"The table contains: \" + $DT.Rows.Count + \" rows\")" 397 | ], 398 | "metadata": { 399 | "azdata_cell_guid": "d0b835e9-ebba-407d-8757-8acc5cbad20e", 400 | "extensions": { 401 | "azuredatastudio": { 402 | "views": [] 403 | } 404 | } 405 | }, 406 | "outputs": [], 407 | "execution_count": null 408 | }, 409 | { 410 | "cell_type": "markdown", 411 | "source": [ 412 | " - Run the following query to find the endpoints and ports." 413 | ], 414 | "metadata": { 415 | "azdata_cell_guid": "f5e9b66f-ba60-4eb0-903a-72339be02cc7", 416 | "extensions": { 417 | "azuredatastudio": { 418 | "views": [] 419 | } 420 | } 421 | } 422 | }, 423 | { 424 | "cell_type": "code", 425 | "source": [ 426 | "[string] $SqlQuery= $(\"SELECT\r\n", 427 | " tep.name as EndPointName,\r\n", 428 | " sp.name As CreatedBy,\r\n", 429 | " tep.type_desc,\r\n", 430 | " tep.state_desc,\r\n", 431 | " tep.port\r\n", 432 | "FROM\r\n", 433 | " sys.tcp_endpoints tep\r\n", 434 | " INNER JOIN sys.server_principals sp ON tep.principal_id = sp.principal_id\r\n", 435 | "WHERE\r\n", 436 | " tep.type = 4\")\r\n", 437 | "$DT = New-Object System.Data.DataTable\r\n", 438 | "$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 439 | "\r\n", 440 | "$DT | Format-Table\r\n", 441 | "#validate the data\r\n", 442 | "Write-Host (\"The table contains: \" + $DT.Rows.Count + \" rows\")" 443 | ], 444 | "metadata": { 445 | "azdata_cell_guid": "443882f8-611e-4690-a114-3c553096cc03", 446 | "extensions": { 447 | "azuredatastudio": { 448 | "views": [] 449 | } 450 | } 451 | }, 452 | "outputs": [], 453 | "execution_count": null 454 | }, 455 | { 456 | "cell_type": "markdown", 457 | "source": [ 458 | "- Compare endpoint\\_url and port from each query and ensure the port from the endpoint\\_url matches the port defined for the endpoint on each respective replica.\n", 459 | "\n", 460 | " ### Note\n", 461 | "\n", 462 | " If you are using specific IP addresses for the endpoint to listen on, versus the default of “listen all”, then you may have to define URLs  that use the specific IP address rather than the FQDN. \n", 463 | "\n", 464 | "5. Check whether the network service account has CONNECT permission to the endpoint. Run the following queries to list the accounts that have connect permission to the endpoint on the server(s) in question, and to show the permission assigned to each relevant endpoint." 465 | ], 466 | "metadata": { 467 | "azdata_cell_guid": "550b2eaf-3ad1-404a-8c96-18fa94308ac6", 468 | "extensions": { 469 | "azuredatastudio": { 470 | "views": [] 471 | } 472 | } 473 | } 474 | }, 475 | { 476 | "cell_type": "code", 477 | "source": [ 478 | "clear\r\n", 479 | "\r\n", 480 | "[string] $SqlQuery= $(\"SELECT \r\n", 481 | " perm.class_desc,\r\n", 482 | " prin.name,\r\n", 483 | " perm.permission_name,\r\n", 484 | " perm.state_desc,\r\n", 485 | " prin.type_desc as PrincipalType,\r\n", 486 | " prin.is_disabled\r\n", 487 | "FROM sys.server_permissions perm\r\n", 488 | " LEFT JOIN sys.server_principals prin ON perm.grantee_principal_id = prin.principal_id\r\n", 489 | " LEFT JOIN sys.tcp_endpoints tep ON perm.major_id = tep.endpoint_id\r\n", 490 | "WHERE \r\n", 491 | " perm.class_desc = 'ENDPOINT'\r\n", 492 | " AND perm.permission_name = 'CONNECT'\r\n", 493 | " AND tep.type = 4;\r\n", 494 | "\r\n", 495 | "SELECT \r\n", 496 | " ep.name, \r\n", 497 | " sp.state,\r\n", 498 | " CONVERT(nvarchar(38), suser_name(sp.grantor_principal_id)) AS grantor,\r\n", 499 | " sp.TYPE AS permission,\r\n", 500 | " CONVERT(nvarchar(46),suser_name(sp.grantee_principal_id)) AS grantee\r\n", 501 | "FROM sys.server_permissions SP \r\n", 502 | " INNER JOIN sys.endpoints ep ON sp.major_id = ep.endpoint_id\r\n", 503 | "AND EP.type = 4\r\n", 504 | "ORDER BY Permission,grantor, grantee;\")\r\n", 505 | "\r\n", 506 | "$DT = New-Object System.Data.DataTable\r\n", 507 | "$DT = ExecuteSqlQuery $SQLInstance $DBName $SqlQuery \r\n", 508 | "\r\n", 509 | "$DT | Format-Table\r\n", 510 | "#validate the data\r\n", 511 | "Write-Host (\"The table contains: \" + $DT.Rows.Count + \" rows\")" 512 | ], 513 | "metadata": { 514 | "azdata_cell_guid": "32f72887-f1b9-4173-9f71-945389a65dd2", 515 | "extensions": { 516 | "azuredatastudio": { 517 | "views": [] 518 | } 519 | } 520 | }, 521 | "outputs": [], 522 | "execution_count": null 523 | }, 524 | { 525 | "cell_type": "markdown", 526 | "source": [ 527 | "6. Check for possible name resolution issues\n", 528 | "\n", 529 | "- Validate DNS resolution by using NSLookup on the IP address and the name:" 530 | ], 531 | "metadata": { 532 | "azdata_cell_guid": "06ba61d4-22c0-457c-83e9-fe270b772773", 533 | "extensions": { 534 | "azuredatastudio": { 535 | "views": [] 536 | } 537 | } 538 | } 539 | }, 540 | { 541 | "cell_type": "code", 542 | "source": [ 543 | "Resolve-DnsName -Name $ServerName\r\n", 544 | "Resolve-DnsName -Name $server_IP_address" 545 | ], 546 | "metadata": { 547 | "azdata_cell_guid": "0f772880-24af-4056-ab00-ed71fcd7e49b", 548 | "tags": [], 549 | "extensions": { 550 | "azuredatastudio": { 551 | "views": [] 552 | } 553 | } 554 | }, 555 | "outputs": [], 556 | "execution_count": null 557 | }, 558 | { 559 | "cell_type": "markdown", 560 | "source": [ 561 | "- Does the name resolve to the correct IP address? Does the IP address resolve to the correct name?\n", 562 | "- Check for local HOSTS file entries on each node that may be pointing to an incorrect server. From Command Prompt print the HOSTS file using this:" 563 | ], 564 | "metadata": { 565 | "azdata_cell_guid": "67896d40-7fa6-46a1-8028-7d49ddda2b92", 566 | "extensions": { 567 | "azuredatastudio": { 568 | "views": [] 569 | } 570 | } 571 | } 572 | }, 573 | { 574 | "cell_type": "code", 575 | "source": [ 576 | "get-content 'C:\\WINDOWS\\system32\\drivers\\etc\\hosts'" 577 | ], 578 | "metadata": { 579 | "azdata_cell_guid": "96ac88f0-6ea1-4de4-b299-b1105cee0d71", 580 | "extensions": { 581 | "azuredatastudio": { 582 | "views": [] 583 | } 584 | } 585 | }, 586 | "outputs": [], 587 | "execution_count": null 588 | }, 589 | { 590 | "cell_type": "markdown", 591 | "source": [ 592 | "- Check if there are [Server Aliases for Use by a Client](https://docs.microsoft.com/en-us/sql/database-engine/configure-windows/create-or-delete-a-server-alias-for-use-by-a-client?view=sql-server-2016) defined on the replicas.\n", 593 | " \n", 594 | "\n", 595 | "7. Ensure your SQL Server is running a recent build (preferably the [latest build](https://docs.microsoft.com/en-us/troubleshoot/sql/general/determine-version-edition-update-level#latest-updates-available-for-currently-supported-versions-of-sql-server) to protect from running into issues like [KB3213703](https://support.microsoft.com/topic/kb3213703-fix-an-always-on-secondary-replica-goes-into-a-disconnecting-state-10131118-b63a-f49f-b140-907f77774dc2). \n", 596 | "\n", 597 | "For more information, refer to [Create Availability Group Fails With Error 35250 'Failed to join the database'](https://techcommunity.microsoft.com/t5/sql-server-support/create-availability-group-fails-with-error-35250-failed-to-join/ba-p/317987)" 598 | ], 599 | "metadata": { 600 | "azdata_cell_guid": "3f6d1672-d39c-4c40-980d-5f046b30456e", 601 | "extensions": { 602 | "azuredatastudio": { 603 | "views": [] 604 | } 605 | } 606 | } 607 | } 608 | ] 609 | } 610 | -------------------------------------------------------------------------------- /sample-scripts/DOCs-to-Notebooks/T-shooting-SQL-Slow-IO.ipynb: -------------------------------------------------------------------------------- 1 | { 2 | "metadata": { 3 | "kernelspec": { 4 | "name": "powershell", 5 | "display_name": "PowerShell", 6 | "language": "powershell" 7 | }, 8 | "language_info": { 9 | "name": "powershell", 10 | "codemirror_mode": "shell", 11 | "mimetype": "text/x-sh", 12 | "file_extension": ".ps1" 13 | }, 14 | "azdata_notebook_guid": "738155A3-A3F5-4504-9591-9915488C86DB", 15 | "extensions": { 16 | "azuredatastudio": { 17 | "version": 1, 18 | "views": [] 19 | } 20 | } 21 | }, 22 | "nbformat_minor": 2, 23 | "nbformat": 4, 24 | "cells": [ 25 | { 26 | "cell_type": "markdown", 27 | "source": [ 28 | "# Troubleshoot slow SQL Server performance caused by I/O issues\r\n", 29 | "\r\n", 30 | "This article provides guidance on what I/O issues cause slow SQL Server performance and how to troubleshoot the issues.\r\n", 31 | "\r\n", 32 | "## Define slow I/O performance\r\n", 33 | "\r\n", 34 | "Performance monitor counters are used to determine slow I/O performance. These counters measure how fast the I/O subsystem services each I/O request on average in terms of clock time. The specific [Performance monitor](https://docs.microsoft.com/windows-server/administration/windows-commands/perfmon) counters that measure I/O latency in Windows are `Avg Disk sec/ Read`, `Avg. Disk sec/Write`, and `Avg. Disk sec/Transfer` (cumulative of both reads and writes).\r\n", 35 | "\r\n", 36 | "In SQL Server, things work the same way. Commonly, you look at whether SQL Server reports any I/O bottlenecks measured in clock time (milliseconds). SQL Server makes I/O requests to the OS by calling the Win32 functions such as `WriteFile()`, `ReadFile()`, `WriteFileGather()`, and `ReadFileScatter()`. When it posts an I/O request, SQL Server times the request and reports the duration of the request using [wait types](https://docs.microsoft.com/sql/relational-databases/system-dynamic-management-views/sys-dm-os-wait-stats-transact-sql). SQL Server uses wait types to indicate I/O waits at different places in the product. The I/O related waits are:\r\n", 37 | "\r\n", 38 | "- [PAGEIOLATCH_SH](#pageiolatch_sh) / [PAGEIOLATCH_EX](#pageiolatch_ex)\r\n", 39 | "- [WRITELOG](#writelog)\r\n", 40 | "- [IO_COMPLETION](#io_completion)\r\n", 41 | "- [ASYNC_IO_COMPLETION](#async_io_completion)\r\n", 42 | "- [BACKUPIO](#backupio)\r\n", 43 | "\r\n", 44 | "If these waits exceed 10-15 milliseconds consistently, I/O is considered a bottleneck.\r\n", 45 | "\r\n", 46 | "> [!NOTE]\r\n", 47 | "> To provide context and perspective, in the world of troubleshooting SQL Server, CSS has observed cases where an I/O request took over one second and as high as 15 seconds per transfer-such I/O systems need optimization. Conversely, CSS has seen systems where the throughput is below one millisecond/transfer. With today's SSD/NVMe technology, advertised throughput rates range in tens of microseconds per transfer. Therefore, the 10-15 millisecond/transfer figure is a very approximate threshold we selected based on collective experience between Windows and SQL Server engineers over the years. Usually, when numbers go beyond this approximate threshold, SQL Server users start seeing latency in their workloads and report them. Ultimately, the expected throughput of an I/O subsystem is defined by the manufacturer, model, configuration, workload, and potentially multiple other factors.\r\n", 48 | "\r\n", 49 | "## Methodology\r\n", 50 | "\r\n", 51 | "The following flow chart describes the methodology Microsoft CSS uses to approach slow I/O issues with SQL Server. It isn't an exhaustive or exclusive approach but has proven useful in isolating the issue and resolving it.\r\n", 52 | "\r\n", 53 | "A [flow chart](#graphical-representation-of-the-methodology) at the end of this article provides a visual representation of this methodology.\r\n", 54 | "\r\n", 55 | "### Step 1: Is SQL Server reporting slow I/O?\r\n", 56 | "\r\n", 57 | "SQL Server may report I/O latency in several ways:\r\n", 58 | "\r\n", 59 | "- I/O wait types\r\n", 60 | "- DMV `sys.dm_io_virtual_file_stats`\r\n", 61 | "- Error log or Application Event log\r\n", 62 | "\r\n", 63 | "#### I/O wait types\r\n", 64 | "\r\n", 65 | "Determine if there's I/O latency reported by SQL Server wait types. The values `PAGEIOLATCH_*`, `WRITELOG`, and `ASYNC_IO_COMPLETION` and the values of several other less common wait types should generally stay below 10-15 milliseconds per I/O request. If these values are greater consistently, an I/O performance problem exists and requires further investigation. The following query may help you gather this diagnostic information on your system:" 66 | ], 67 | "metadata": { 68 | "azdata_cell_guid": "84fc9ea5-6558-49ce-a0c5-6b0eb2403b22" 69 | }, 70 | "attachments": {} 71 | }, 72 | { 73 | "cell_type": "code", 74 | "source": [ 75 | "#replace with server\\instance or server for default instance\r\n", 76 | "$sqlserver_instance = \"server\\instance\" \r\n", 77 | "\r\n", 78 | "for ([int]$i = 0; $i -lt 100; $i++)\r\n", 79 | "{\r\n", 80 | " \r\n", 81 | " sqlcmd -E -S $sqlserver_instance -Q \"SELECT r.session_id, r.wait_type, r.wait_time as wait_time_ms`\r\n", 82 | " FROM sys.dm_exec_requests r JOIN sys.dm_exec_sessions s `\r\n", 83 | " ON r.session_id = s.session_id `\r\n", 84 | " WHERE wait_type in ('PAGEIOLATCH_SH', 'PAGEIOLATCH_EX', 'WRITELOG', `\r\n", 85 | " 'IO_COMPLETION', 'ASYNC_IO_COMPLETION', 'BACKUPIO')`\r\n", 86 | " AND is_user_process = 1\"\r\n", 87 | "\r\n", 88 | " Start-Sleep -s 2\r\n", 89 | "}" 90 | ], 91 | "metadata": { 92 | "azdata_cell_guid": "679ee944-3da4-4a0c-97b7-701420e7bc65", 93 | "language": "powershell", 94 | "tags": [] 95 | }, 96 | "outputs": [], 97 | "execution_count": null 98 | }, 99 | { 100 | "cell_type": "markdown", 101 | "source": [ 102 | "\r\n", 103 | "#### File stats in sys.dm_io_virtual_file_stats\r\n", 104 | "\r\n", 105 | "To view the database file-level latency as reported in SQL Server, run the following query:" 106 | ], 107 | "metadata": { 108 | "azdata_cell_guid": "70a105c9-f4f5-4e99-bf3d-c76f713949e9" 109 | }, 110 | "attachments": {} 111 | }, 112 | { 113 | "cell_type": "code", 114 | "source": [ 115 | "#replace with server\\instance or server for default instance\r\n", 116 | "$sqlserver_instance = \"server\\instance\" \r\n", 117 | "\r\n", 118 | "sqlcmd -E -S $sqlserver_instance -Q \"SELECT LEFT(mf.physical_name,100), `\r\n", 119 | " ReadLatency = CASE WHEN num_of_reads = 0 THEN 0 ELSE (io_stall_read_ms / num_of_reads) END, `\r\n", 120 | " WriteLatency = CASE WHEN num_of_writes = 0 THEN 0 ELSE (io_stall_write_ms / num_of_writes) END, `\r\n", 121 | " AvgLatency = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 0 `\r\n", 122 | " ELSE (io_stall / (num_of_reads + num_of_writes)) END,`\r\n", 123 | " LatencyAssessment = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 'No data' ELSE `\r\n", 124 | " CASE WHEN (io_stall / (num_of_reads + num_of_writes)) < 2 THEN 'Excellent' `\r\n", 125 | " WHEN (io_stall / (num_of_reads + num_of_writes)) BETWEEN 2 AND 5 THEN 'Very good' `\r\n", 126 | " WHEN (io_stall / (num_of_reads + num_of_writes)) BETWEEN 6 AND 15 THEN 'Good' `\r\n", 127 | " WHEN (io_stall / (num_of_reads + num_of_writes)) BETWEEN 16 AND 100 THEN 'Poor' `\r\n", 128 | " WHEN (io_stall / (num_of_reads + num_of_writes)) BETWEEN 100 AND 500 THEN 'Bad' `\r\n", 129 | " ELSE 'Deplorable' END END, `\r\n", 130 | " [Avg KBs/Transfer] = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 0 `\r\n", 131 | " ELSE ((([num_of_bytes_read] + [num_of_bytes_written]) / (num_of_reads + num_of_writes)) / 1024) END, `\r\n", 132 | " LEFT (mf.physical_name, 2) AS Volume, `\r\n", 133 | " LEFT(DB_NAME (vfs.database_id),32) AS [Database Name]`\r\n", 134 | " FROM sys.dm_io_virtual_file_stats (NULL,NULL) AS vfs `\r\n", 135 | " JOIN sys.master_files AS mf ON vfs.database_id = mf.database_id `\r\n", 136 | " AND vfs.file_id = mf.file_id `\r\n", 137 | " ORDER BY AvgLatency DESC\"" 138 | ], 139 | "metadata": { 140 | "azdata_cell_guid": "10f1e00b-706f-4e61-b9bc-7e0ef7e472d1", 141 | "language": "powershell" 142 | }, 143 | "outputs": [], 144 | "execution_count": null 145 | }, 146 | { 147 | "cell_type": "markdown", 148 | "source": [ 149 | "\r\n", 150 | "Look at the `AvgLatency` and `LatencyAssessment` columns to understand the latency details.\r\n", 151 | "\r\n", 152 | "#### Error 833 reported in Errorlog or Application Event log\r\n", 153 | "\r\n", 154 | "In some cases, you may observe error 833 `SQL Server has encountered %d occurrence(s) of I/O requests taking longer than %d seconds to complete on file [%ls] in database [%ls] (%d)` in the error log. You can check SQL Server error logs on your system by running the following PowerShell command:\r\n", 155 | "" 156 | ], 157 | "metadata": { 158 | "language": "powershell", 159 | "azdata_cell_guid": "482b367b-40e7-476f-bcb2-028b9575ae8d" 160 | }, 161 | "attachments": {} 162 | }, 163 | { 164 | "cell_type": "code", 165 | "source": [ 166 | "Get-ChildItem -Path \"c:\\program files\\microsoft sql server\\mssql*\" -Recurse -Include Errorlog |\r\n", 167 | " Select-String \"occurrence(s) of I/O requests taking longer than Longer than 15 secs\"" 168 | ], 169 | "metadata": { 170 | "language": "powershell", 171 | "azdata_cell_guid": "2dc8be9a-9663-43b6-9421-3efbc59c8c0d" 172 | }, 173 | "outputs": [], 174 | "execution_count": null 175 | }, 176 | { 177 | "cell_type": "markdown", 178 | "source": [ 179 | "\r\n", 180 | "Also, for more information on this error, see the [MSSQLSERVER_833](https://docs.microsoft.com/sql/relational-databases/errors-events/mssqlserver-833-database-engine-error) section.\r\n", 181 | "\r\n", 182 | "### Step 2: Do Perfmon Counters indicate I/O latency?\r\n", 183 | "\r\n", 184 | "If SQL Server reports I/O latency, refer to OS counters. You can determine if there's an I/O problem by examining the latency counter `Avg Disk Sec/Transfer`. The following code snippet indicates one way to collect this information through PowerShell. It gathers counters on all disk volumes: \"_total\". Change to a specific drive volume (for example, \"D:\"). To find which volumes host your database files, run the following query in your SQL Server:" 185 | ], 186 | "metadata": { 187 | "language": "powershell", 188 | "azdata_cell_guid": "c1920cf6-458f-4b0a-a41c-35bae2732316" 189 | }, 190 | "attachments": {} 191 | }, 192 | { 193 | "cell_type": "code", 194 | "source": [ 195 | "#replace with server\\instance or server for default instance\r\n", 196 | "$sqlserver_instance = \"server\\instance\" \r\n", 197 | "sqlcmd -E -S $sqlserver_instance -Q \"SELECT DISTINCT LEFT(volume_mount_point, 32) AS volume_mount_point `\r\n", 198 | " FROM sys.master_files f `\r\n", 199 | " CROSS APPLY sys.dm_os_volume_stats(f.database_id, f.file_id) vs\"" 200 | ], 201 | "metadata": { 202 | "language": "powershell", 203 | "azdata_cell_guid": "a53d1ec2-6258-4f1a-a23d-520b2aa39209" 204 | }, 205 | "outputs": [], 206 | "execution_count": null 207 | }, 208 | { 209 | "cell_type": "markdown", 210 | "source": [ 211 | "Gather `Avg Disk Sec/Transfer` metrics on your volume of choice:" 212 | ], 213 | "metadata": { 214 | "language": "powershell", 215 | "azdata_cell_guid": "92cefa4e-2501-4f24-8c2f-ae30bb9fa56e" 216 | }, 217 | "attachments": {} 218 | }, 219 | { 220 | "cell_type": "code", 221 | "source": [ 222 | "clear\r\n", 223 | "$cntr = 0 \r\n", 224 | "\r\n", 225 | "# replace with your server name, unless local computer\r\n", 226 | "$serverName = $env:COMPUTERNAME\r\n", 227 | "\r\n", 228 | "# replace with your volume name - C: , D:, etc\r\n", 229 | "$volumeName = \"_total\"\r\n", 230 | "\r\n", 231 | "$Counters = @((\"\\\\$serverName\" +\"\\LogicalDisk($volumeName)\\Avg. disk sec/transfer\"))\r\n", 232 | "\r\n", 233 | "$disksectransfer = Get-Counter -Counter $Counters -MaxSamples 1 \r\n", 234 | "$avg = $($disksectransfer.CounterSamples | Select-Object CookedValue).CookedValue\r\n", 235 | "\r\n", 236 | "Get-Counter -Counter $Counters -SampleInterval 2 -MaxSamples 30 | ForEach-Object {\r\n", 237 | "$_.CounterSamples | ForEach-Object {\r\n", 238 | " [pscustomobject]@{\r\n", 239 | " TimeStamp = $_.TimeStamp\r\n", 240 | " Path = $_.Path\r\n", 241 | " Value = ([Math]::Round($_.CookedValue, 5))\r\n", 242 | " turn = $cntr = $cntr +1\r\n", 243 | " running_avg = [Math]::Round(($avg = (($_.CookedValue + $avg) / 2)), 5) \r\n", 244 | " \r\n", 245 | " } | Format-Table\r\n", 246 | " }\r\n", 247 | " }\r\n", 248 | "\r\n", 249 | " write-host \"Final_Running_Average: $([Math]::Round( $avg, 5)) sec/transfer`n\"\r\n", 250 | " \r\n", 251 | " if ($avg -gt 0.01)\r\n", 252 | " {\r\n", 253 | " Write-Host \"There ARE indications of slow I/O performance on your system\"\r\n", 254 | " }\r\n", 255 | " else\r\n", 256 | " {\r\n", 257 | " Write-Host \"There is NO indication of slow I/O performance on your system\"\r\n", 258 | " }" 259 | ], 260 | "metadata": { 261 | "language": "powershell", 262 | "azdata_cell_guid": "0002182b-7bba-4492-ada8-8b4cdb6ced24" 263 | }, 264 | "outputs": [], 265 | "execution_count": null 266 | }, 267 | { 268 | "cell_type": "markdown", 269 | "source": [ 270 | "If the values of this counter are consistently above 10-15 milliseconds, you need to look at the issue further. Occasional spikes don't count in most cases but be sure to double-check the duration of a spike. If the spike lasted one minute or more, it's more of a plateau than a spike.\r\n", 271 | "\r\n", 272 | "If the Performance monitor counters don't report latency, but SQL Server does, then the problem is between SQL Server and the Partition Manager, that is, filter drivers. The Partition Manager is an I/O layer where the OS collects [Perfmon](https://docs.microsoft.com/windows-server/administration/windows-commands/perfmon) counters. To address the latency, ensure proper exclusions of filter drivers and resolve filter driver issues. Filter drivers are used by programs like [Anti-virus software](https://docs.microsoft.com/windows-hardware/drivers/ifs/allocated-altitudes#320000---329998-fsfilter-anti-virus), [Backup solutions](https://docs.microsoft.com/windows-hardware/drivers/ifs/allocated-altitudes#280000---289998-fsfilter-continuous-backup), [Encryption](https://docs.microsoft.com/windows-hardware/drivers/ifs/allocated-altitudes#140000---149999-fsfilter-encryption), [Compression](https://docs.microsoft.com/windows-hardware/drivers/ifs/allocated-altitudes#160000---169999-fsfilter-compression), and so on. You can use this command to list filter drivers on the systems and the volumes they attach to. Then, you can look up the driver names and software vendors in the [Allocated filter altitudes](https://docs.microsoft.com/windows-hardware/drivers/ifs/allocated-altitudes) article." 273 | ], 274 | "metadata": { 275 | "language": "powershell", 276 | "azdata_cell_guid": "aec4fd38-262f-4009-a8fb-4a76099bda1d" 277 | }, 278 | "attachments": {} 279 | }, 280 | { 281 | "cell_type": "code", 282 | "source": [ 283 | "fltmc instances" 284 | ], 285 | "metadata": { 286 | "language": "powershell", 287 | "azdata_cell_guid": "0f16b7c7-b1a3-4368-b43b-9a2ce83e7594" 288 | }, 289 | "outputs": [], 290 | "execution_count": null 291 | }, 292 | { 293 | "cell_type": "markdown", 294 | "source": [ 295 | "For more information, see [How to choose antivirus software to run on computers that are running SQL Server](https://support.microsoft.com/topic/how-to-choose-antivirus-software-to-run-on-computers-that-are-running-sql-server-feda079b-3e24-186b-945a-3051f6f3a95b).\r\n", 296 | "\r\n", 297 | "Avoid using Encrypting File System (EFS) and file-system compression because they cause asynchronous I/O to become synchronous and therefore slower. For more information, see the [Asynchronous disk I/O appears as synchronous on Windows](https://docs.microsoft.com/troubleshoot/windows/win32/asynchronous-disk-io-synchronous#compression) article.\r\n", 298 | "\r\n", 299 | "### Step 3: Is the I/O subsystem overwhelmed beyond capacity?\r\n", 300 | "\r\n", 301 | "If SQL Server and the OS indicate that the I/O subsystem is slow, check if the cause is the system being overwhelmed beyond capacity. You can check capacity by looking at I/O counters `Disk Bytes/Sec`, `Disk Read Bytes/Sec`, or `Disk Write Bytes/Sec`. Be sure to check with your System Administrator or hardware vendor for the expected throughput specifications for your SAN (or other I/O subsystem). For example, you can push no more than 200 MB/sec of I/O through a 2 GB/sec HBA card or 2 GB/sec dedicated port on a SAN switch. The expected throughput capacity defined by a hardware manufacturer defines how you proceed from here." 302 | ], 303 | "metadata": { 304 | "language": "powershell", 305 | "azdata_cell_guid": "5b160cee-cd71-46ef-b478-54ed8494ae8b" 306 | }, 307 | "attachments": {} 308 | }, 309 | { 310 | "cell_type": "code", 311 | "source": [ 312 | "clear\r\n", 313 | "\r\n", 314 | "$serverName = $env:COMPUTERNAME\r\n", 315 | "$Counters = @(\r\n", 316 | " (\"\\\\$serverName\" +\"\\PhysicalDisk(*)\\Disk Bytes/sec\"),\r\n", 317 | " (\"\\\\$serverName\" +\"\\PhysicalDisk(*)\\Disk Read Bytes/sec\"),\r\n", 318 | " (\"\\\\$serverName\" +\"\\PhysicalDisk(*)\\Disk Write Bytes/sec\")\r\n", 319 | " )\r\n", 320 | "Get-Counter -Counter $Counters -SampleInterval 2 -MaxSamples 20 | ForEach-Object {\r\n", 321 | "$_.CounterSamples | ForEach-Object {\r\n", 322 | " [pscustomobject]@{\r\n", 323 | " TimeStamp = $_.TimeStamp\r\n", 324 | " Path = $_.Path\r\n", 325 | " Value = ([Math]::Round($_.CookedValue, 3)) }\r\n", 326 | " }\r\n", 327 | " }" 328 | ], 329 | "metadata": { 330 | "language": "powershell", 331 | "azdata_cell_guid": "4ddfc1a2-cb45-4b2d-be59-1e19d4f5869a" 332 | }, 333 | "outputs": [], 334 | "execution_count": null 335 | }, 336 | { 337 | "cell_type": "markdown", 338 | "source": [ 339 | "\r\n", 340 | "### Step 4: Is SQL Server driving the heavy I/O activity?\r\n", 341 | "\r\n", 342 | "If the I/O subsystem is overwhelmed beyond capacity, find out if SQL Server is the culprit by looking at `Buffer Manager: Page Reads/Sec` (most common culprit) and `Page Writes/Sec` (a lot less common) for the specific instance. If SQL Server is the main I/O driver and I/O volume is beyond what the system can handle, then work with the Application Development teams or application vendor to:\r\n", 343 | "\r\n", 344 | "- Tune queries, for example: better indexes, update statistics, rewrite queries, and redesign the database.\r\n", 345 | "- Increase [max server memory](https://docs.microsoft.com/sql/database-engine/configure-windows/server-memory-server-configuration-options) or add more RAM on the system. More RAM will cache more data or index pages without frequently re-reading from disk, which will reduce I/O activity.\r\n", 346 | "\r\n", 347 | "## Causes\r\n", 348 | "\r\n", 349 | "In general, the following issues are the high-level reasons why SQL Server queries suffer from I/O latency:\r\n", 350 | "\r\n", 351 | "- **Hardware issues:**\r\n", 352 | "\r\n", 353 | " - A SAN misconfiguration (switch, cables, HBA, storage)\r\n", 354 | "\r\n", 355 | " - Exceeded I/O capacity (unbalanced throughout the entire SAN network, not just back-end storage)\r\n", 356 | "\r\n", 357 | " - Drivers or firmware issues\r\n", 358 | "\r\n", 359 | " Hardware vendors and/or system administrators need to be engaged at this stage.\r\n", 360 | "\r\n", 361 | "- **Query issues:** SQL Server is saturating disk volumes with I/O requests and is pushing the I/O subsystem beyond capacity, which causes I/O transfer rates to be high. In this case, the solution is to find the queries that are causing a high number of logical reads (or writes) and tune those queries to minimize disk I/O-using appropriate indexes is the first step to do that. Also, keep statistics updated as they provide the query optimizer with sufficient information to choose the best plan. Also, incorrect database design and query design can lead to an increase in I/O issues. Therefore, redesigning queries and sometimes tables may help with improved I/O.\r\n", 362 | "\r\n", 363 | "- **Filter drivers:** The SQL Server I/O response can be severely impacted if file-system filter drivers process heavy I/O traffic. Proper file exclusions from anti-virus scanning and correct filter driver design by software vendors are recommended to prevent impact on I/O performance.\r\n", 364 | "\r\n", 365 | "- **Other application(s):** Another application on the same machine with SQL Server can saturate the I/O path with excessive read or write requests. This situation may push the I/O subsystem beyond capacity limits and cause I/O slowness for SQL Server. Identify the application and tune it or move it elsewhere to eliminate its impact on the I/O stack.\r\n", 366 | "\r\n", 367 | "## Graphical representation of the methodology\r\n", 368 | "\r\n", 369 | "\r\n", 370 | "\r\n", 371 | "![](https://docs.microsoft.com/en-us/troubleshoot/sql/performance/media/troubleshoot-slow-io-sql/slow-disk-io-issues.png)\r\n", 372 | "\r\n", 373 | "## Information on I/O-related wait types\r\n", 374 | "\r\n", 375 | "The following are descriptions of the common wait types observed in SQL Server when disk I/O issues are reported.\r\n", 376 | "\r\n", 377 | "### PAGEIOLATCH_EX\r\n", 378 | "\r\n", 379 | "Occurs when a task is waiting on a latch for a data or index page (buffer) in an I/O request. The latch request is in the Exclusive mode. An Exclusive mode is used when the buffer is being written to disk. Long waits may indicate problems with the disk subsystem.\r\n", 380 | "\r\n", 381 | "### PAGEIOLATCH_SH\r\n", 382 | "\r\n", 383 | "Occurs when a task is waiting on a latch for a data or index page (buffer) in an I/O request. The latch request is in the Shared mode. The Shared mode is used when the buffer is being read from the disk. Long waits may indicate problems with the disk subsystem.\r\n", 384 | "\r\n", 385 | "### PAGEIOLATCH_UP\r\n", 386 | "\r\n", 387 | "Occurs when a task is waiting on a latch for a buffer in an I/O request. The latch request is in the Update mode. Long waits may indicate problems with the disk subsystem.\r\n", 388 | "\r\n", 389 | "### WRITELOG\r\n", 390 | "\r\n", 391 | "Occurs when a task is waiting for a transaction log flush to complete. A flush occurs when the Log Manager writes its temporary contents to disk. Common operations that cause log flushes are transaction commits and checkpoints.\r\n", 392 | "\r\n", 393 | "Common reasons for long waits on `WRITELOG` are:\r\n", 394 | "\r\n", 395 | "- **Transaction log disk latency**: This is the most common cause of `WRITELOG` waits. Generally, the recommendation is to keep the data and log files on separate volumes. Transaction log writes are sequential writes while reading or writing data from a data file is random. Mixing data and log files on one drive volume (especially conventional spinning disk drives) will cause excessive disk head movement.\r\n", 396 | "\r\n", 397 | "- **Too many VLFs**: Too many virtual log files (VLFs) can cause `WRITELOG` waits. Too many VLFs can cause other types of issues, such as long recovery.\r\n", 398 | "\r\n", 399 | "- **Too many small transactions**: While large transactions can lead to blocking, too many small transactions can lead to another set of issues. If you don't explicitly begin a transaction, any insert, delete, or update will result in a transaction (we call this auto transaction). If you do 1,000 inserts in a loop, there will be 1,000 transactions generated. Each transaction in this example needs to commit, which results in a transaction log flush and 1,000 transaction flushes. When possible, group individual update, delete, or insert into a bigger transaction to reduce transaction log flushes and [increase performance](https://docs.microsoft.com/troubleshoot/sql/admin/logging-data-storage-algorithms#increasing-performance). This operation can lead to fewer `WRITELOG` waits.\r\n", 400 | "\r\n", 401 | "- **Scheduling issues cause Log Writer threads to not get scheduled fast enough**: Prior to SQL Server 2016, a single Log Writer thread performed all log writes. If there were issues with thread scheduling (for example, high CPU), both the Log Writer thread and log flushes could get delayed. In SQL Server 2016, up to four Log Writer threads were added to increase the log-writing throughput. See [SQL 2016 - It Just Runs Faster: Multiple Log Writer Workers](https://techcommunity.microsoft.com/t5/sql-server-support/sql-2016-it-just-runs-faster-multiple-log-writer-workers/ba-p/318732). In SQL Server 2019, up to eight Log Writer threads were added, which improves throughput even more. Also, in SQL Server 2019, each regular worker thread can do log writes directly instead of posting to the Log writer thread. With these improvements, `WRITELOG` waits would rarely be triggered by scheduling issues.\r\n", 402 | "\r\n", 403 | "### ASYNC_IO_COMPLETION\r\n", 404 | "\r\n", 405 | "Occurs when some of the following I/O activities happen:\r\n", 406 | "\r\n", 407 | "- The Bulk Insert Provider (\"Insert Bulk\") uses this wait type when performing I/O.\r\n", 408 | "- Reading Undo file in LogShipping and directing Async I/O for Log Shipping.\r\n", 409 | "- Reading the actual data from the data files during a data backup.\r\n", 410 | "\r\n", 411 | "### IO_COMPLETION\r\n", 412 | "\r\n", 413 | "Occurs while waiting for I/O operations to complete. This wait type generally involves I/Os not related to data pages (buffers). Examples include:\r\n", 414 | "\r\n", 415 | "- Reading and writing of sort/hash results from/to disk during a spill (check performance of *tempdb* storage).\r\n", 416 | "- Reading and writing eager spools to disk (check *tempdb* storage).\r\n", 417 | "- Reading log blocks from the transaction log (during any operation that causes the log to be read from disk - for example, recovery).\r\n", 418 | "- Reading a page from disk when database isn't set up yet.\r\n", 419 | "- Copying pages to a database snapshot (Copy-on-Write).\r\n", 420 | "- Closing database file and file uncompression.\r\n", 421 | "\r\n", 422 | "### BACKUPIO\r\n", 423 | "\r\n", 424 | "Occurs when a backup task is waiting for data, or is waiting for a buffer to store data. This type isn't typical, except when a task is waiting for a tape mount." 425 | ], 426 | "metadata": { 427 | "language": "powershell", 428 | "azdata_cell_guid": "395e6e63-af58-4f85-b82f-0707c5d41f2d" 429 | }, 430 | "attachments": {} 431 | } 432 | ] 433 | } --------------------------------------------------------------------------------