From 7821b832e6ccf91f65ea24974c2d3368c71dfa82 Mon Sep 17 00:00:00 2001 From: Nick Craver Date: Thu, 20 Oct 2022 18:50:16 -0400 Subject: [PATCH 1/2] Azure: add DTU details --- .../SQLAzureServer.AzureResourceHistory.cs | 77 +++++++++++++++++++ src/Opserver.Core/Data/SQL/SQLAzureServer.cs | 44 +++++++---- src/Opserver.Core/Data/SQL/SQLInstance.cs | 7 ++ .../Controllers/GraphController.Spark.cs | 15 ++++ src/Opserver.Web/Views/SQL/Servers.cshtml | 12 ++- 5 files changed, 140 insertions(+), 15 deletions(-) create mode 100644 src/Opserver.Core/Data/SQL/SQLAzureServer.AzureResourceHistory.cs diff --git a/src/Opserver.Core/Data/SQL/SQLAzureServer.AzureResourceHistory.cs b/src/Opserver.Core/Data/SQL/SQLAzureServer.AzureResourceHistory.cs new file mode 100644 index 000000000..58cef5f2c --- /dev/null +++ b/src/Opserver.Core/Data/SQL/SQLAzureServer.AzureResourceHistory.cs @@ -0,0 +1,77 @@ +using System; +using System.Collections.Generic; +using System.Linq; +using Opserver.Data.Dashboard; + +namespace Opserver.Data.SQL +{ + public partial class SQLInstance + { + private Cache> _azureResourceHistory; + + public Cache> AzureResourceHistory => + _azureResourceHistory ??= GetSqlCache(nameof(AzureResourceHistory), async conn => + { + var sql = GetFetchSQL(); + var result = await conn.QueryAsync(sql); + var lastResult = result.Count > 0 ? result.Last() : null; + CurrentDTUPercent = lastResult?.AvgDTUPercent; + CurrentDTULimit = lastResult?.DTULimit; + return result; + }); + + public double? CurrentDTUPercent { get; set; } + public int? CurrentDTULimit { get; set; } + + public class AzureResourceEvent : ISQLVersioned, IGraphPoint + { + Version IMinVersioned.MinVersion => SQLServerVersions.SQL2012.RTM; + SQLServerEditions ISQLVersioned.SupportedEditions => SQLServerEditions.Azure; + + private long? _dateEpoch; + public long DateEpoch => _dateEpoch ??= EventTime.ToEpochTime(); + public DateTime EventTime { get; internal set; } + public double AvgDTUPercent { get; internal set; } + public double AvgCPUPercent { get; internal set; } + public double AvgDataIOPercent { get; internal set; } + public double AvgLogWritePercent { get; internal set; } + public double AvgMemoryPercent { get; internal set; } + public double XTPStoragePercent { get; internal set; } + public double MaxWorkerPercent { get; internal set; } + public double MaxSessionPercent { get; internal set; } + public double AvgInstanceCPUPercent { get; internal set; } + + public double AvgInstanceMemoryPercent { get; internal set; } + public double AvgLoginRatePercent { get; internal set; } + public double CPULimit { get; internal set; } + public int DTULimit { get; internal set; } + public ReplicaRoleType ReplicaRole { get; internal set; } + + public enum ReplicaRoleType + { + Primary = 0, + ReadOnly = 1, + Forwarder = 2, + } + + public string GetFetchSQL(in SQLServerEngine e) => @" +Select end_time AS EventTime, + (Select Max(v) From (Values (avg_cpu_percent), (avg_data_io_percent), (avg_log_write_percent)) As value(v)) As AvgDTUPercent, + avg_cpu_percent AvgCPUPercent, + avg_data_io_percent AvgDataIOPercent, + avg_log_write_percent AvgLogWritePercent, + avg_memory_usage_percent AvgMemoryPercent, + xtp_storage_percent XTPStoragePercent, + max_worker_percent MaxWorkerPercent, + max_session_percent MaxSessionPercent, + avg_instance_cpu_percent AvgInstanceCPUPercent, + avg_instance_memory_percent AvgInstanceMemoryPercent, + avg_login_rate_percent AvgLoginRatePercent, + cpu_limit CPULimit, + dtu_limit DTULimit, + replica_role ReplicaRole + From sys.dm_db_resource_stats + Cross Join sys.dm_os_sys_info osi;"; + } + } +} diff --git a/src/Opserver.Core/Data/SQL/SQLAzureServer.cs b/src/Opserver.Core/Data/SQL/SQLAzureServer.cs index a29403190..0ffaed07b 100644 --- a/src/Opserver.Core/Data/SQL/SQLAzureServer.cs +++ b/src/Opserver.Core/Data/SQL/SQLAzureServer.cs @@ -16,25 +16,36 @@ public class SQLAzureServer : SQLInstance var instances = new List(); // grab the list of databases in the SQL Azure instance // and generate a SQLInstance for each one - var databases = await conn.QueryAsync("Select name From sys.databases"); + var databases = await conn.QueryAsync(@" +Select db.name Name, + dbso.edition Edition, + dbso.service_objective SKU, + dbso.elastic_pool_name ElasticPoolName + From sys.databases db + Join sys.database_service_objectives dbso On db.database_id = dbso.database_id"); foreach (var database in databases) { // is there an existing instance? - var key = Settings.Name + ":" + database; + var key = Settings.Name + ":" + database.Name; var instance = _instancesByKey.GetOrAdd( key, key => new SQLInstance( - Module, - new SQLSettings.Instance - { - Name = key, - ConnectionString = new SqlConnectionStringBuilder(ConnectionString) + Module, + new SQLSettings.Instance { - InitialCatalog = database - }.ConnectionString, - RefreshIntervalSeconds = Settings.RefreshIntervalSeconds, - } - ) + Name = key, + ConnectionString = new SqlConnectionStringBuilder(ConnectionString) + { + InitialCatalog = database.Name + }.ConnectionString, + RefreshIntervalSeconds = Settings.RefreshIntervalSeconds, + } + ) + { + SKU = database.SKU, + Edition = database.Edition, + ElasticPoolName = database.ElasticPoolName, + } ); instances.Add(instance); @@ -52,9 +63,16 @@ public override IEnumerable DataPollers } } - public SQLAzureServer(SQLModule module, SQLSettings.Instance settings) : base(module, settings) { } + + public class AzureDatabaseInfo + { + public string Name { get; set; } + public string Edition { get; set; } + public string SKU { get; set; } + public string ElasticPoolName { get; set; } + } } } diff --git a/src/Opserver.Core/Data/SQL/SQLInstance.cs b/src/Opserver.Core/Data/SQL/SQLInstance.cs index 7a3e7f0d7..c6a171ac0 100644 --- a/src/Opserver.Core/Data/SQL/SQLInstance.cs +++ b/src/Opserver.Core/Data/SQL/SQLInstance.cs @@ -24,6 +24,11 @@ public partial class SQLInstance : PollNode, ISearchableNode public SQLServerEngine Engine { get; internal set; } = new SQLServerEngine(new Version(), SQLServerEditions.Standard); // default to 0.0 protected SQLSettings.Instance Settings { get; } + // Azure-specific database attributes + public string SKU { get; set; } + public string Edition { get; set; } + public string ElasticPoolName { get; set; } + protected static readonly ConcurrentDictionary, string> QueryLookup = new ConcurrentDictionary, string>(); @@ -77,6 +82,8 @@ public override IEnumerable DataPollers yield return Connections; if (Supports()) yield return ConnectionsSummary; + if (Supports()) + yield return AzureResourceHistory; } } diff --git a/src/Opserver.Web/Controllers/GraphController.Spark.cs b/src/Opserver.Web/Controllers/GraphController.Spark.cs index 0c5b534ad..5bee7593b 100644 --- a/src/Opserver.Web/Controllers/GraphController.Spark.cs +++ b/src/Opserver.Web/Controllers/GraphController.Spark.cs @@ -182,6 +182,21 @@ public ActionResult SQLCPUSpark(string node) return SparkSVG(points, 100, p => p.ProcessUtilization, start); } + [OnlyAllow(SQLRoles.Viewer)] + [ResponseCache(Duration = SparkGraphDuration, VaryByQueryKeys = new string[] { "node" }, Location = ResponseCacheLocation.Client)] + [Route("graph/sql/dtu/spark")] + public ActionResult SQLDTUSpark(string node) + { + var instance = Sql.GetInstance(node); + if (instance == null) return ContentNotFound($"SQLNode not found with name = '{node}'"); + var start = DateTime.UtcNow.AddHours(-1); + var points = instance.AzureResourceHistory.Data?.Where(p => p.EventTime >= start).ToList(); + + if (points == null || points.Count == 0) return EmptySparkSVG(); + + return SparkSVG(points, 100, p => p.AvgDTUPercent, start); + } + public async Task SparkSvgAll(string key, Func>> getPoints, Func, long> getMax, Func getVal) where T : IGraphPoint { const int width = SparkPoints; diff --git a/src/Opserver.Web/Views/SQL/Servers.cshtml b/src/Opserver.Web/Views/SQL/Servers.cshtml index dbec04741..1b2ef966f 100644 --- a/src/Opserver.Web/Views/SQL/Servers.cshtml +++ b/src/Opserver.Web/Views/SQL/Servers.cshtml @@ -85,8 +85,11 @@ Database + SKU CPU (Last Hour) + DTUs + (Last Hour) Memory Conns / Sess Batches/sec @@ -97,7 +100,7 @@ @if (!s.Instances.ContainsData) { - + @@ -105,9 +108,14 @@ @foreach (var i in s.Instances.SafeData(true)) { - @i.IconSpan() @i.Name + @i.IconSpan() @i.Name + @i.SKU @(i.CurrentCPUPercent.HasValue ? i.CurrentCPUPercent.ToString() + "%" : "") SQL CPU for @i.Name Last Hour + + @(i.CurrentDTUPercent.HasValue ? i.CurrentDTUPercent.ToString() + "%" : "") + DTU Usage for @i.Name Last Hour + @ConnectionsCell(i) @(i.BatchesPerSec?.ToComma()) From c3a0371339692d9489d4c5cdef10ddba225c23a9 Mon Sep 17 00:00:00 2001 From: Nick Craver Date: Thu, 20 Oct 2022 19:23:23 -0400 Subject: [PATCH 2/2] Tweak DTU rendering --- src/Opserver.Web/Views/SQL/Servers.cshtml | 5 +++-- 1 file changed, 3 insertions(+), 2 deletions(-) diff --git a/src/Opserver.Web/Views/SQL/Servers.cshtml b/src/Opserver.Web/Views/SQL/Servers.cshtml index 1b2ef966f..d7eb059d2 100644 --- a/src/Opserver.Web/Views/SQL/Servers.cshtml +++ b/src/Opserver.Web/Views/SQL/Servers.cshtml @@ -109,11 +109,12 @@ { @i.IconSpan() @i.Name - @i.SKU + @i.SKU + @(i.CurrentCPUPercent.HasValue ? i.CurrentCPUPercent.ToString() + "%" : "") SQL CPU for @i.Name Last Hour - @(i.CurrentDTUPercent.HasValue ? i.CurrentDTUPercent.ToString() + "%" : "") + @(i.CurrentDTUPercent.HasValue ? i.CurrentDTUPercent.ToString() + "%" : "") DTU Usage for @i.Name Last Hour