From 764e40bf85513adf3609b555fd23835c37e9be79 Mon Sep 17 00:00:00 2001 From: Bob Ward Date: Sat, 11 Nov 2023 20:44:53 -0600 Subject: [PATCH] ag demo scripts --- demos/availabilitygroups/ag_sync_health.sql | 24 +++ demos/availabilitygroups/agbasics.sql | 11 ++ demos/availabilitygroups/agcatalogviews.sql | 12 ++ demos/availabilitygroups/backup300dbs.sql | 11 ++ .../changeaghealthdetect.sql | 4 + demos/availabilitygroups/create300dbs.sql | 11 ++ demos/availabilitygroups/createagscript.sql | 183 ++++++++++++++++++ demos/availabilitygroups/ddl.sql | 11 ++ demos/availabilitygroups/ddl_large_table.sql | 14 ++ demos/availabilitygroups/hadrdmvs.sql | 4 + .../availabilitygroups/remove300dbsfromag.sql | 11 ++ demos/availabilitygroups/tracelogblock.sql | 27 +++ demos/availabilitygroups/waiting_requests.sql | 6 + demos/availabilitygroups/workload.cmd | 1 + 14 files changed, 330 insertions(+) create mode 100644 demos/availabilitygroups/ag_sync_health.sql create mode 100644 demos/availabilitygroups/agbasics.sql create mode 100644 demos/availabilitygroups/agcatalogviews.sql create mode 100644 demos/availabilitygroups/backup300dbs.sql create mode 100644 demos/availabilitygroups/changeaghealthdetect.sql create mode 100644 demos/availabilitygroups/create300dbs.sql create mode 100644 demos/availabilitygroups/createagscript.sql create mode 100644 demos/availabilitygroups/ddl.sql create mode 100644 demos/availabilitygroups/ddl_large_table.sql create mode 100644 demos/availabilitygroups/hadrdmvs.sql create mode 100644 demos/availabilitygroups/remove300dbsfromag.sql create mode 100644 demos/availabilitygroups/tracelogblock.sql create mode 100644 demos/availabilitygroups/waiting_requests.sql create mode 100644 demos/availabilitygroups/workload.cmd diff --git a/demos/availabilitygroups/ag_sync_health.sql b/demos/availabilitygroups/ag_sync_health.sql new file mode 100644 index 0000000..6ad2d2f --- /dev/null +++ b/demos/availabilitygroups/ag_sync_health.sql @@ -0,0 +1,24 @@ +SELECT ar.replica_server_name, ag.name, dhars.role_desc, dhars.operational_state, dhars.connected_state_desc, +synchronization_health_desc, last_connect_error_description +FROM sys.dm_hadr_availability_replica_states dhars +JOIN sys.availability_groups ag +ON ag.group_id = dhars.group_id +JOIN sys.availability_replicas ar +ON ar.replica_id = dhars.replica_id; +GO + +SELECT ar.replica_server_name, ag.name, dhdrs.is_primary_replica, dhdrs.synchronization_state_desc, +dhdrs.synchronization_health_desc, dhdrs.is_commit_participant, dhdrs.suspend_reason_desc, +dhdrs.last_sent_lsn, dhdrs.last_sent_time, dhdrs.last_hardened_lsn, dhdrs.last_hardened_time, +dhdrs.last_commit_lsn, dhdrs.last_commit_time +FROM sys.dm_hadr_database_replica_states dhdrs +JOIN sys.availability_groups ag +ON ag.group_id = dhdrs.group_id +JOIN sys.availability_replicas ar +ON ar.replica_id = dhdrs.replica_id +GO + +BACKUP LOG texasrangerswschamps TO DISK = 'texasrangerswschamps_log.bak' WITH INIT; +GO +SELECT name, log_reuse_wait_desc FROM sys.databases where name = 'texasrangerswschamps'; +GO diff --git a/demos/availabilitygroups/agbasics.sql b/demos/availabilitygroups/agbasics.sql new file mode 100644 index 0000000..01e7e3b --- /dev/null +++ b/demos/availabilitygroups/agbasics.sql @@ -0,0 +1,11 @@ +SELECT ag.name, replica_server_name, endpoint_url, availability_mode_desc, failover_mode_desc, session_timeout, create_date, +primary_role_allow_connections_desc, secondary_role_allow_connections_desc +FROM sys.availability_replicas ar +JOIN sys.availability_groups ag +ON ar.group_id = ag.group_id +GO +SELECT aglia.dns_name, aglipa.ip_address, aglipa.network_subnet_ip +FROM sys.availability_group_listeners aglia +JOIN sys.availability_group_listener_ip_addresses aglipa +ON aglia.listener_id = aglipa.listener_id; +GO \ No newline at end of file diff --git a/demos/availabilitygroups/agcatalogviews.sql b/demos/availabilitygroups/agcatalogviews.sql new file mode 100644 index 0000000..27ace28 --- /dev/null +++ b/demos/availabilitygroups/agcatalogviews.sql @@ -0,0 +1,12 @@ +SELECT * FROM sys.availability_databases_cluster; +GO +SELECT * FROM sys.availability_groups; +GO +SELECT * FROM sys.availability_groups_cluster; +GO +SELECT * FROM sys.availability_group_listeners; +GO +SELECT * FROM sys.availability_group_listener_ip_addresses; +GO +SELECT * FROM sys.availability_replicas; +GO \ No newline at end of file diff --git a/demos/availabilitygroups/backup300dbs.sql b/demos/availabilitygroups/backup300dbs.sql new file mode 100644 index 0000000..c807411 --- /dev/null +++ b/demos/availabilitygroups/backup300dbs.sql @@ -0,0 +1,11 @@ +DECLARE @x int; +DECLARE @y varchar(1000); +SET @x = 0; +WHILE (@x < 300) +BEGIN + SET @y = 'BACKUP DATABASE db'+convert(varchar(5), @x)+' TO DISK = '+''''+'db'+convert(varchar(5), @x)+'.bak'+''''; + SET @x = @x + 1; + EXEC (@y); + --PRINT @y; +END +GO \ No newline at end of file diff --git a/demos/availabilitygroups/changeaghealthdetect.sql b/demos/availabilitygroups/changeaghealthdetect.sql new file mode 100644 index 0000000..ca7c8f2 --- /dev/null +++ b/demos/availabilitygroups/changeaghealthdetect.sql @@ -0,0 +1,4 @@ +ALTER AVAILABILITY GROUP texasrangersag SET (FAILURE_CONDITION_LEVEL = 5); +GO +ALTER AVAILABILITY GROUP texasrangersag SET (HEALTH_CHECK_TIMEOUT = 15000); +GO \ No newline at end of file diff --git a/demos/availabilitygroups/create300dbs.sql b/demos/availabilitygroups/create300dbs.sql new file mode 100644 index 0000000..d380777 --- /dev/null +++ b/demos/availabilitygroups/create300dbs.sql @@ -0,0 +1,11 @@ +DECLARE @x int; +DECLARE @y varchar(1000); +SET @x = 0; +WHILE (@x < 300) +BEGIN + SET @y = 'CREATE DATABASE db'+convert(varchar(5), @x)+';' + SET @x = @x + 1; + EXEC (@y); + --PRINT @y; +END +GO \ No newline at end of file diff --git a/demos/availabilitygroups/createagscript.sql b/demos/availabilitygroups/createagscript.sql new file mode 100644 index 0000000..2da29ff --- /dev/null +++ b/demos/availabilitygroups/createagscript.sql @@ -0,0 +1,183 @@ +--- YOU MUST EXECUTE THE FOLLOWING SCRIPT IN SQLCMD MODE. +:Connect SQLVM1 + +USE [master] + +GO + +CREATE ENDPOINT [Hadr_endpoint] + AS TCP (LISTENER_PORT = 5022) + FOR DATA_MIRRORING (ROLE = ALL, ENCRYPTION = REQUIRED ALGORITHM AES) + +GO + +IF (SELECT state FROM sys.endpoints WHERE name = N'Hadr_endpoint') <> 0 +BEGIN + ALTER ENDPOINT [Hadr_endpoint] STATE = STARTED +END + + +GO + +use [master] + +GO + +GRANT CONNECT ON ENDPOINT::[Hadr_endpoint] TO [CORP\Install] + +GO + +:Connect SQLVM1 + +IF EXISTS(SELECT * FROM sys.server_event_sessions WHERE name='AlwaysOn_health') +BEGIN + ALTER EVENT SESSION [AlwaysOn_health] ON SERVER WITH (STARTUP_STATE=ON); +END +IF NOT EXISTS(SELECT * FROM sys.dm_xe_sessions WHERE name='AlwaysOn_health') +BEGIN + ALTER EVENT SESSION [AlwaysOn_health] ON SERVER STATE=START; +END + +GO + +:Connect SQLVM2 + +USE [master] + +GO + +CREATE ENDPOINT [Hadr_endpoint] + AS TCP (LISTENER_PORT = 5022) + FOR DATA_MIRRORING (ROLE = ALL, ENCRYPTION = REQUIRED ALGORITHM AES) + +GO + +IF (SELECT state FROM sys.endpoints WHERE name = N'Hadr_endpoint') <> 0 +BEGIN + ALTER ENDPOINT [Hadr_endpoint] STATE = STARTED +END + + +GO + +use [master] + +GO + +GRANT CONNECT ON ENDPOINT::[Hadr_endpoint] TO [CORP\Install] + +GO + +:Connect SQLVM2 + +IF EXISTS(SELECT * FROM sys.server_event_sessions WHERE name='AlwaysOn_health') +BEGIN + ALTER EVENT SESSION [AlwaysOn_health] ON SERVER WITH (STARTUP_STATE=ON); +END +IF NOT EXISTS(SELECT * FROM sys.dm_xe_sessions WHERE name='AlwaysOn_health') +BEGIN + ALTER EVENT SESSION [AlwaysOn_health] ON SERVER STATE=START; +END + +GO + +:Connect SQLVM3 + +USE [master] + +GO + +CREATE ENDPOINT [Hadr_endpoint] + AS TCP (LISTENER_PORT = 5022) + FOR DATA_MIRRORING (ROLE = ALL, ENCRYPTION = REQUIRED ALGORITHM AES) + +GO + +IF (SELECT state FROM sys.endpoints WHERE name = N'Hadr_endpoint') <> 0 +BEGIN + ALTER ENDPOINT [Hadr_endpoint] STATE = STARTED +END + + +GO + +use [master] + +GO + +GRANT CONNECT ON ENDPOINT::[Hadr_endpoint] TO [CORP\Install] + +GO + +:Connect SQLVM3 + +IF EXISTS(SELECT * FROM sys.server_event_sessions WHERE name='AlwaysOn_health') +BEGIN + ALTER EVENT SESSION [AlwaysOn_health] ON SERVER WITH (STARTUP_STATE=ON); +END +IF NOT EXISTS(SELECT * FROM sys.dm_xe_sessions WHERE name='AlwaysOn_health') +BEGIN + ALTER EVENT SESSION [AlwaysOn_health] ON SERVER STATE=START; +END + +GO + +:Connect SQLVM1 + +USE [master] + +GO + +CREATE AVAILABILITY GROUP [texasrangersag] +WITH (AUTOMATED_BACKUP_PREFERENCE = SECONDARY, +DB_FAILOVER = ON, +DTC_SUPPORT = NONE, +REQUIRED_SYNCHRONIZED_SECONDARIES_TO_COMMIT = 0) +FOR DATABASE [texasrangerswschamps] +REPLICA ON N'sqlvm1' WITH (ENDPOINT_URL = N'TCP://sqlvm1.corp.bwcorp.com:5022', FAILOVER_MODE = AUTOMATIC, AVAILABILITY_MODE = SYNCHRONOUS_COMMIT, BACKUP_PRIORITY = 50, SEEDING_MODE = AUTOMATIC, SECONDARY_ROLE(ALLOW_CONNECTIONS = ALL)), + N'sqlvm2' WITH (ENDPOINT_URL = N'TCP://sqlvm2.corp.bwcorp.com:5022', FAILOVER_MODE = AUTOMATIC, AVAILABILITY_MODE = SYNCHRONOUS_COMMIT, BACKUP_PRIORITY = 50, SEEDING_MODE = AUTOMATIC, SECONDARY_ROLE(ALLOW_CONNECTIONS = ALL)), + N'sqlvm3' WITH (ENDPOINT_URL = N'TCP://sqlvm3.corp.bwcorp.com:5022', FAILOVER_MODE = MANUAL, AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT, BACKUP_PRIORITY = 50, SEEDING_MODE = AUTOMATIC, SECONDARY_ROLE(ALLOW_CONNECTIONS = NO)); + +GO + +:Connect SQLVM1 + +USE [master] + +GO + +ALTER AVAILABILITY GROUP [texasrangersag] +ADD LISTENER N'trangerslisten' ( +WITH IP +((N'10.0.1.11', N'255.255.255.0'), +(N'10.0.2.11', N'255.255.255.0'), +(N'10.0.3.11', N'255.255.255.0') +) +, PORT=1433); + +GO + +:Connect SQLVM2 + +ALTER AVAILABILITY GROUP [texasrangersag] JOIN; + +GO + +ALTER AVAILABILITY GROUP [texasrangersag] GRANT CREATE ANY DATABASE; + +GO + +:Connect SQLVM3 + +ALTER AVAILABILITY GROUP [texasrangersag] JOIN; + +GO + +ALTER AVAILABILITY GROUP [texasrangersag] GRANT CREATE ANY DATABASE; + +GO + + +GO + + diff --git a/demos/availabilitygroups/ddl.sql b/demos/availabilitygroups/ddl.sql new file mode 100644 index 0000000..a8cc701 --- /dev/null +++ b/demos/availabilitygroups/ddl.sql @@ -0,0 +1,11 @@ +USE texasrangerswschamps; +GO +DROP TABLE IF EXISTS wearethechampions; +GO +CREATE TABLE wearethechampions (col1 int, col2 varchar(5000)); +GO + +SELECT @@spid + +INSERT INTO wearethechampions VALUES (1, '...of the world'); +GO diff --git a/demos/availabilitygroups/ddl_large_table.sql b/demos/availabilitygroups/ddl_large_table.sql new file mode 100644 index 0000000..15da78a --- /dev/null +++ b/demos/availabilitygroups/ddl_large_table.sql @@ -0,0 +1,14 @@ +USE texasrangerswschamps; +GO +DROP TABLE IF EXISTS wearethechampions; +GO +CREATE TABLE wearethechampions (col1 int, col2 char(5000) not null); +GO +DECLARE @x int; +SET @x = 0; +WHILE (@x < 100000) +BEGIN + INSERT INTO wearethechampions VALUES (1, '...of the world'); + SET @x = @x + 1; +END +GO diff --git a/demos/availabilitygroups/hadrdmvs.sql b/demos/availabilitygroups/hadrdmvs.sql new file mode 100644 index 0000000..8bafb10 --- /dev/null +++ b/demos/availabilitygroups/hadrdmvs.sql @@ -0,0 +1,4 @@ +SELECT * FROM sys.dm_hadr_ag_threads; +GO +SELECT * FROM sys.dm_hadr_db_threads; +GO diff --git a/demos/availabilitygroups/remove300dbsfromag.sql b/demos/availabilitygroups/remove300dbsfromag.sql new file mode 100644 index 0000000..facddee --- /dev/null +++ b/demos/availabilitygroups/remove300dbsfromag.sql @@ -0,0 +1,11 @@ +DECLARE @x int; +DECLARE @y varchar(1000); +SET @x = 0; +WHILE (@x < 300) +BEGIN + SET @y = 'ALTER AVAILABILITY GROUP texasrangersag REMOVE DATABASE db'+convert(varchar(5), @x)+';' + SET @x = @x + 1; + EXEC (@y); + --PRINT @y; +END +GO \ No newline at end of file diff --git a/demos/availabilitygroups/tracelogblock.sql b/demos/availabilitygroups/tracelogblock.sql new file mode 100644 index 0000000..9021209 --- /dev/null +++ b/demos/availabilitygroups/tracelogblock.sql @@ -0,0 +1,27 @@ +CREATE EVENT SESSION [trace_ag_log_block] ON SERVER +ADD EVENT sqlserver.hadr_capture_log_block( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.hadr_db_commit_mgr_harden( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.hadr_db_commit_mgr_update_harden( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.hadr_log_block_group_commit( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.hadr_log_block_send_complete( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.hadr_receive_harden_lsn_message( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.log_block_pushed_to_logpool( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.log_flush_complete( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.log_flush_start( + ACTION(package0.callstack_rva,sqlserver.session_id)), +ADD EVENT sqlserver.recovery_unit_harden_log_timestamps( + ACTION(package0.callstack_rva,package0.collect_current_thread_id,sqlos.scheduler_id,sqlos.system_thread_id,sqlos.worker_address,sqlserver.is_system,sqlserver.request_id,sqlserver.session_id,sqlserver.sql_text)), +ADD EVENT sqlserver.sql_batch_completed(SET collect_batch_text=(1) + ACTION(sqlserver.session_id)) +WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=ALLOW_SINGLE_EVENT_LOSS,MAX_DISPATCH_LATENCY=30 SECONDS,MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF) +GO + + diff --git a/demos/availabilitygroups/waiting_requests.sql b/demos/availabilitygroups/waiting_requests.sql new file mode 100644 index 0000000..ef9d8f6 --- /dev/null +++ b/demos/availabilitygroups/waiting_requests.sql @@ -0,0 +1,6 @@ +SELECT er.request_id, er.command, er.wait_type, er.last_wait_type, er.wait_time +FROM sys.dm_exec_requests er +JOIN sys.dm_exec_sessions es +ON er.session_id = es.session_id +AND es.is_user_process = 1; +GO \ No newline at end of file diff --git a/demos/availabilitygroups/workload.cmd b/demos/availabilitygroups/workload.cmd new file mode 100644 index 0000000..542160f --- /dev/null +++ b/demos/availabilitygroups/workload.cmd @@ -0,0 +1 @@ +"C:\Program Files\Microsoft Corporation\RMLUtils\ostress" -dtexasrangerswschamps -E -Q"select * from wearethechampions" -r10 -n300 -q -T146 -l0 \ No newline at end of file