diff --git a/receiver/sqlserverreceiver/queries.go b/receiver/sqlserverreceiver/queries.go new file mode 100644 index 0000000000000..1fcb6dce10178 --- /dev/null +++ b/receiver/sqlserverreceiver/queries.go @@ -0,0 +1,64 @@ +// Copyright The OpenTelemetry Authors +// SPDX-License-Identifier: Apache-2.0 + +package sqlserverreceiver // import "github.com/open-telemetry/opentelemetry-collector-contrib/receiver/sqlserverreceiver" + +import ( + "fmt" +) + +// Direct access to queries is not recommended: The receiver allows filtering based on +// instance name, which means the query will change based on configuration. +// Please use getSQLServerDatabaseIOQuery +const sqlServerDatabaseIOQuery = ` +SET DEADLOCK_PRIORITY -10; +IF SERVERPROPERTY('EngineEdition') NOT IN (2,3,4) BEGIN /*NOT IN Standard,Enterprise,Express*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Connection string Server:'+ @@ServerName + ',Database:' + DB_NAME() +' is not a SQL Server Standard,Enterprise or Express. This query is only supported on these editions.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +DECLARE + @SqlStatement AS nvarchar(max) + ,@MajorMinorVersion AS int = CAST(PARSENAME(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar),4) AS int) * 100 + CAST(PARSENAME(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar),3) AS int) + ,@Columns AS nvarchar(max) = '' + ,@Tables AS nvarchar(max) = '' +IF @MajorMinorVersion > 1100 BEGIN + SET @Columns += N' + ,vfs.[io_stall_queued_read_ms] AS [rg_read_stall_ms] + ,vfs.[io_stall_queued_write_ms] AS [rg_write_stall_ms]' +END + +SET @SqlStatement = N' +SELECT + ''sqlserver_database_io'' AS [measurement] + ,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance] + ,HOST_NAME() AS [computer_name] + ,DB_NAME(vfs.[database_id]) AS [database_name] + ,COALESCE(mf.[physical_name],''RBPEX'') AS [physical_filename] --RPBEX = Resilient Buffer Pool Extension + ,COALESCE(mf.[name],''RBPEX'') AS [logical_filename] --RPBEX = Resilient Buffer Pool Extension + ,mf.[type_desc] AS [file_type] + ,vfs.[io_stall_read_ms] AS [read_latency_ms] + ,vfs.[num_of_reads] AS [reads] + ,vfs.[num_of_bytes_read] AS [read_bytes] + ,vfs.[io_stall_write_ms] AS [write_latency_ms] + ,vfs.[num_of_writes] AS [writes] + ,vfs.[num_of_bytes_written] AS [write_bytes]' + + @Columns + N' +FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs +INNER JOIN sys.master_files AS mf WITH (NOLOCK) + ON vfs.[database_id] = mf.[database_id] AND vfs.[file_id] = mf.[file_id] +%s' ++ @Tables; + +EXEC sp_executesql @SqlStatement +` + +func getSQLServerDatabaseIOQuery(instanceName string) string { + if instanceName != "" { + whereClause := fmt.Sprintf("WHERE @@SERVERNAME = ''%s''", instanceName) + return fmt.Sprintf(sqlServerDatabaseIOQuery, whereClause) + } + + return fmt.Sprintf(sqlServerDatabaseIOQuery, "") +} diff --git a/receiver/sqlserverreceiver/queries_test.go b/receiver/sqlserverreceiver/queries_test.go new file mode 100644 index 0000000000000..3fc99f2e794a0 --- /dev/null +++ b/receiver/sqlserverreceiver/queries_test.go @@ -0,0 +1,30 @@ +// Copyright The OpenTelemetry Authors +// SPDX-License-Identifier: Apache-2.0 + +package sqlserverreceiver + +import ( + "os" + "path" + "testing" + + "github.com/stretchr/testify/require" +) + +func TestQueryIODBWithoutInstanceName(t *testing.T) { + expected, err := os.ReadFile(path.Join("./testdata", "databaseIOQueryWithoutInstanceName.txt")) + require.NoError(t, err) + + actual := getSQLServerDatabaseIOQuery("") + + require.Equal(t, string(expected), actual) +} + +func TestQueryIODBWithInstanceName(t *testing.T) { + expected, err := os.ReadFile(path.Join("./testdata", "databaseIOQueryWithInstanceName.txt")) + require.NoError(t, err) + + actual := getSQLServerDatabaseIOQuery("instanceName") + + require.Equal(t, string(expected), actual) +} diff --git a/receiver/sqlserverreceiver/testdata/databaseIOQueryWithInstanceName.txt b/receiver/sqlserverreceiver/testdata/databaseIOQueryWithInstanceName.txt new file mode 100644 index 0000000000000..93f5d3f109e15 --- /dev/null +++ b/receiver/sqlserverreceiver/testdata/databaseIOQueryWithInstanceName.txt @@ -0,0 +1,42 @@ + +SET DEADLOCK_PRIORITY -10; +IF SERVERPROPERTY('EngineEdition') NOT IN (2,3,4) BEGIN /*NOT IN Standard,Enterprise,Express*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Connection string Server:'+ @@ServerName + ',Database:' + DB_NAME() +' is not a SQL Server Standard,Enterprise or Express. This query is only supported on these editions.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +DECLARE + @SqlStatement AS nvarchar(max) + ,@MajorMinorVersion AS int = CAST(PARSENAME(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar),4) AS int) * 100 + CAST(PARSENAME(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar),3) AS int) + ,@Columns AS nvarchar(max) = '' + ,@Tables AS nvarchar(max) = '' +IF @MajorMinorVersion > 1100 BEGIN + SET @Columns += N' + ,vfs.[io_stall_queued_read_ms] AS [rg_read_stall_ms] + ,vfs.[io_stall_queued_write_ms] AS [rg_write_stall_ms]' +END + +SET @SqlStatement = N' +SELECT + ''sqlserver_database_io'' AS [measurement] + ,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance] + ,HOST_NAME() AS [computer_name] + ,DB_NAME(vfs.[database_id]) AS [database_name] + ,COALESCE(mf.[physical_name],''RBPEX'') AS [physical_filename] --RPBEX = Resilient Buffer Pool Extension + ,COALESCE(mf.[name],''RBPEX'') AS [logical_filename] --RPBEX = Resilient Buffer Pool Extension + ,mf.[type_desc] AS [file_type] + ,vfs.[io_stall_read_ms] AS [read_latency_ms] + ,vfs.[num_of_reads] AS [reads] + ,vfs.[num_of_bytes_read] AS [read_bytes] + ,vfs.[io_stall_write_ms] AS [write_latency_ms] + ,vfs.[num_of_writes] AS [writes] + ,vfs.[num_of_bytes_written] AS [write_bytes]' + + @Columns + N' +FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs +INNER JOIN sys.master_files AS mf WITH (NOLOCK) + ON vfs.[database_id] = mf.[database_id] AND vfs.[file_id] = mf.[file_id] +WHERE @@SERVERNAME = ''instanceName''' ++ @Tables; + +EXEC sp_executesql @SqlStatement diff --git a/receiver/sqlserverreceiver/testdata/databaseIOQueryWithoutInstanceName.txt b/receiver/sqlserverreceiver/testdata/databaseIOQueryWithoutInstanceName.txt new file mode 100644 index 0000000000000..8e10ba34d1a1f --- /dev/null +++ b/receiver/sqlserverreceiver/testdata/databaseIOQueryWithoutInstanceName.txt @@ -0,0 +1,42 @@ + +SET DEADLOCK_PRIORITY -10; +IF SERVERPROPERTY('EngineEdition') NOT IN (2,3,4) BEGIN /*NOT IN Standard,Enterprise,Express*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Connection string Server:'+ @@ServerName + ',Database:' + DB_NAME() +' is not a SQL Server Standard,Enterprise or Express. This query is only supported on these editions.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +DECLARE + @SqlStatement AS nvarchar(max) + ,@MajorMinorVersion AS int = CAST(PARSENAME(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar),4) AS int) * 100 + CAST(PARSENAME(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar),3) AS int) + ,@Columns AS nvarchar(max) = '' + ,@Tables AS nvarchar(max) = '' +IF @MajorMinorVersion > 1100 BEGIN + SET @Columns += N' + ,vfs.[io_stall_queued_read_ms] AS [rg_read_stall_ms] + ,vfs.[io_stall_queued_write_ms] AS [rg_write_stall_ms]' +END + +SET @SqlStatement = N' +SELECT + ''sqlserver_database_io'' AS [measurement] + ,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance] + ,HOST_NAME() AS [computer_name] + ,DB_NAME(vfs.[database_id]) AS [database_name] + ,COALESCE(mf.[physical_name],''RBPEX'') AS [physical_filename] --RPBEX = Resilient Buffer Pool Extension + ,COALESCE(mf.[name],''RBPEX'') AS [logical_filename] --RPBEX = Resilient Buffer Pool Extension + ,mf.[type_desc] AS [file_type] + ,vfs.[io_stall_read_ms] AS [read_latency_ms] + ,vfs.[num_of_reads] AS [reads] + ,vfs.[num_of_bytes_read] AS [read_bytes] + ,vfs.[io_stall_write_ms] AS [write_latency_ms] + ,vfs.[num_of_writes] AS [writes] + ,vfs.[num_of_bytes_written] AS [write_bytes]' + + @Columns + N' +FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs +INNER JOIN sys.master_files AS mf WITH (NOLOCK) + ON vfs.[database_id] = mf.[database_id] AND vfs.[file_id] = mf.[file_id] +' ++ @Tables; + +EXEC sp_executesql @SqlStatement