Skip to content

Commit

Permalink
[chore][receiver/sqlserver] Add database IO metrics query (open-telem…
Browse files Browse the repository at this point in the history
…etry#32178)

**Description:** <Describe what has changed.>
<!--Ex. Fixing a bug - Describe the bug and how this fixes the issue.
Ex. Adding a feature - Explain what this achieves.-->
Add a query for the database IO metrics that SQL Server exposes. Read
more about available metrics
[here](https://learn.microsoft.com/en-us/sql/relational-databases/system-dynamic-management-views/sys-dm-io-virtual-file-stats-transact-sql?view=sql-server-ver16).
This is a no-op update as this query will not be used until direct
connection to the SQL Server instance is fully implemented. This is
simply part of the effort.

**Note:** This code is currently not reached. This is on purpose.

**Link to tracking Issue:** <Issue number if applicable>
This was originally part of
open-telemetry#31915,
but I'm breaking this out to make the original PR a more manageable
size.


open-telemetry#30297

**Testing:** <Describe what testing was performed and which tests were
added.>
Existing tests and added tests are passing.

**Documentation:** <Describe the documentation added.>
Purposefully none: This is currently dead code until all of open-telemetry#31915 gets
merged, so it shouldn't be used.
  • Loading branch information
crobert-1 authored and rimitchell committed May 8, 2024
1 parent 09ea7b3 commit 23335f7
Show file tree
Hide file tree
Showing 4 changed files with 178 additions and 0 deletions.
64 changes: 64 additions & 0 deletions receiver/sqlserverreceiver/queries.go
Original file line number Diff line number Diff line change
@@ -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, "")
}
30 changes: 30 additions & 0 deletions receiver/sqlserverreceiver/queries_test.go
Original file line number Diff line number Diff line change
@@ -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)
}
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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

0 comments on commit 23335f7

Please sign in to comment.