├── .gitattributes ├── .gitignore ├── .vscode ├── extensions.json ├── launch.json ├── settings.json └── tasks.json ├── AutoScaler.cs ├── Autoscaler.csproj ├── CODE_OF_CONDUCT.md ├── LICENSE ├── README.md ├── SQL ├── create-table.sql ├── load-test.sql ├── monitor-autoscaler.sql ├── monitor-resource-usage.sql └── sql-query-stress-config.json └── host.json /.gitattributes: -------------------------------------------------------------------------------- 1 | ############################################################################### 2 | # Set default behavior to automatically normalize line endings. 3 | ############################################################################### 4 | * text=auto 5 | 6 | ############################################################################### 7 | # Set default behavior for command prompt diff. 8 | # 9 | # This is need for earlier builds of msysgit that does not have it on by 10 | # default for csharp files. 11 | # Note: This is only used by command line 12 | ############################################################################### 13 | #*.cs diff=csharp 14 | 15 | ############################################################################### 16 | # Set the merge driver for project and solution files 17 | # 18 | # Merging from the command prompt will add diff markers to the files if there 19 | # are conflicts (Merging from VS is not affected by the settings below, in VS 20 | # the diff markers are never inserted). Diff markers may cause the following 21 | # file extensions to fail to load in VS. An alternative would be to treat 22 | # these files as binary and thus will always conflict and require user 23 | # intervention with every merge. To do so, just uncomment the entries below 24 | ############################################################################### 25 | #*.sln merge=binary 26 | #*.csproj merge=binary 27 | #*.vbproj merge=binary 28 | #*.vcxproj merge=binary 29 | #*.vcproj merge=binary 30 | #*.dbproj merge=binary 31 | #*.fsproj merge=binary 32 | #*.lsproj merge=binary 33 | #*.wixproj merge=binary 34 | #*.modelproj merge=binary 35 | #*.sqlproj merge=binary 36 | #*.wwaproj merge=binary 37 | 38 | ############################################################################### 39 | # behavior for image files 40 | # 41 | # image files are treated as binary by default. 42 | ############################################################################### 43 | #*.jpg binary 44 | #*.png binary 45 | #*.gif binary 46 | 47 | ############################################################################### 48 | # diff behavior for common document formats 49 | # 50 | # Convert binary document formats to text before diffing them. This feature 51 | # is only available from the command line. Turn it on by uncommenting the 52 | # entries below. 53 | ############################################################################### 54 | #*.doc diff=astextplain 55 | #*.DOC diff=astextplain 56 | #*.docx diff=astextplain 57 | #*.DOCX diff=astextplain 58 | #*.dot diff=astextplain 59 | #*.DOT diff=astextplain 60 | #*.pdf diff=astextplain 61 | #*.PDF diff=astextplain 62 | #*.rtf diff=astextplain 63 | #*.RTF diff=astextplain 64 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ## Ignore Visual Studio temporary files, build results, and 2 | ## files generated by popular Visual Studio add-ons. 3 | 4 | # Azure Functions localsettings file 5 | local.settings.json 6 | 7 | # User-specific files 8 | *.suo 9 | *.user 10 | *.userosscache 11 | *.sln.docstates 12 | 13 | # User-specific files (MonoDevelop/Xamarin Studio) 14 | *.userprefs 15 | 16 | # Build results 17 | [Dd]ebug/ 18 | [Dd]ebugPublic/ 19 | [Rr]elease/ 20 | [Rr]eleases/ 21 | x64/ 22 | x86/ 23 | bld/ 24 | [Bb]in/ 25 | [Oo]bj/ 26 | [Ll]og/ 27 | 28 | # Visual Studio 2015 cache/options directory 29 | .vs/ 30 | # Uncomment if you have tasks that create the project's static files in wwwroot 31 | #wwwroot/ 32 | 33 | # MSTest test Results 34 | [Tt]est[Rr]esult*/ 35 | [Bb]uild[Ll]og.* 36 | 37 | # NUNIT 38 | *.VisualState.xml 39 | TestResult.xml 40 | 41 | # Build Results of an ATL Project 42 | [Dd]ebugPS/ 43 | [Rr]eleasePS/ 44 | dlldata.c 45 | 46 | # DNX 47 | project.lock.json 48 | project.fragment.lock.json 49 | artifacts/ 50 | 51 | *_i.c 52 | *_p.c 53 | *_i.h 54 | *.ilk 55 | *.meta 56 | *.obj 57 | *.pch 58 | *.pdb 59 | *.pgc 60 | *.pgd 61 | *.rsp 62 | *.sbr 63 | *.tlb 64 | *.tli 65 | *.tlh 66 | *.tmp 67 | *.tmp_proj 68 | *.log 69 | *.vspscc 70 | *.vssscc 71 | .builds 72 | *.pidb 73 | *.svclog 74 | *.scc 75 | 76 | # Chutzpah Test files 77 | _Chutzpah* 78 | 79 | # Visual C++ cache files 80 | ipch/ 81 | *.aps 82 | *.ncb 83 | *.opendb 84 | *.opensdf 85 | *.sdf 86 | *.cachefile 87 | *.VC.db 88 | *.VC.VC.opendb 89 | 90 | # Visual Studio profiler 91 | *.psess 92 | *.vsp 93 | *.vspx 94 | *.sap 95 | 96 | # TFS 2012 Local Workspace 97 | $tf/ 98 | 99 | # Guidance Automation Toolkit 100 | *.gpState 101 | 102 | # ReSharper is a .NET coding add-in 103 | _ReSharper*/ 104 | *.[Rr]e[Ss]harper 105 | *.DotSettings.user 106 | 107 | # JustCode is a .NET coding add-in 108 | .JustCode 109 | 110 | # TeamCity is a build add-in 111 | _TeamCity* 112 | 113 | # DotCover is a Code Coverage Tool 114 | *.dotCover 115 | 116 | # NCrunch 117 | _NCrunch_* 118 | .*crunch*.local.xml 119 | nCrunchTemp_* 120 | 121 | # MightyMoose 122 | *.mm.* 123 | AutoTest.Net/ 124 | 125 | # Web workbench (sass) 126 | .sass-cache/ 127 | 128 | # Installshield output folder 129 | [Ee]xpress/ 130 | 131 | # DocProject is a documentation generator add-in 132 | DocProject/buildhelp/ 133 | DocProject/Help/*.HxT 134 | DocProject/Help/*.HxC 135 | DocProject/Help/*.hhc 136 | DocProject/Help/*.hhk 137 | DocProject/Help/*.hhp 138 | DocProject/Help/Html2 139 | DocProject/Help/html 140 | 141 | # Click-Once directory 142 | publish/ 143 | 144 | # Publish Web Output 145 | *.[Pp]ublish.xml 146 | *.azurePubxml 147 | # TODO: Comment the next line if you want to checkin your web deploy settings 148 | # but database connection strings (with potential passwords) will be unencrypted 149 | #*.pubxml 150 | *.publishproj 151 | 152 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 153 | # checkin your Azure Web App publish settings, but sensitive information contained 154 | # in these scripts will be unencrypted 155 | PublishScripts/ 156 | 157 | # NuGet Packages 158 | *.nupkg 159 | # The packages folder can be ignored because of Package Restore 160 | **/packages/* 161 | # except build/, which is used as an MSBuild target. 162 | !**/packages/build/ 163 | # Uncomment if necessary however generally it will be regenerated when needed 164 | #!**/packages/repositories.config 165 | # NuGet v3's project.json files produces more ignoreable files 166 | *.nuget.props 167 | *.nuget.targets 168 | 169 | # Microsoft Azure Build Output 170 | csx/ 171 | *.build.csdef 172 | 173 | # Microsoft Azure Emulator 174 | ecf/ 175 | rcf/ 176 | 177 | # Windows Store app package directories and files 178 | AppPackages/ 179 | BundleArtifacts/ 180 | Package.StoreAssociation.xml 181 | _pkginfo.txt 182 | 183 | # Visual Studio cache files 184 | # files ending in .cache can be ignored 185 | *.[Cc]ache 186 | # but keep track of directories ending in .cache 187 | !*.[Cc]ache/ 188 | 189 | # Others 190 | ClientBin/ 191 | ~$* 192 | *~ 193 | *.dbmdl 194 | *.dbproj.schemaview 195 | *.jfm 196 | *.pfx 197 | *.publishsettings 198 | node_modules/ 199 | orleans.codegen.cs 200 | 201 | # Since there are multiple workflows, uncomment next line to ignore bower_components 202 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 203 | #bower_components/ 204 | 205 | # RIA/Silverlight projects 206 | Generated_Code/ 207 | 208 | # Backup & report files from converting an old project file 209 | # to a newer Visual Studio version. Backup files are not needed, 210 | # because we have git ;-) 211 | _UpgradeReport_Files/ 212 | Backup*/ 213 | UpgradeLog*.XML 214 | UpgradeLog*.htm 215 | 216 | # SQL Server files 217 | *.mdf 218 | *.ldf 219 | 220 | # Business Intelligence projects 221 | *.rdl.data 222 | *.bim.layout 223 | *.bim_*.settings 224 | 225 | # Microsoft Fakes 226 | FakesAssemblies/ 227 | 228 | # GhostDoc plugin setting file 229 | *.GhostDoc.xml 230 | 231 | # Node.js Tools for Visual Studio 232 | .ntvs_analysis.dat 233 | 234 | # Visual Studio 6 build log 235 | *.plg 236 | 237 | # Visual Studio 6 workspace options file 238 | *.opt 239 | 240 | # Visual Studio LightSwitch build output 241 | **/*.HTMLClient/GeneratedArtifacts 242 | **/*.DesktopClient/GeneratedArtifacts 243 | **/*.DesktopClient/ModelManifest.xml 244 | **/*.Server/GeneratedArtifacts 245 | **/*.Server/ModelManifest.xml 246 | _Pvt_Extensions 247 | 248 | # Paket dependency manager 249 | .paket/paket.exe 250 | paket-files/ 251 | 252 | # FAKE - F# Make 253 | .fake/ 254 | 255 | # JetBrains Rider 256 | .idea/ 257 | *.sln.iml 258 | 259 | # CodeRush 260 | .cr/ 261 | 262 | # Python Tools for Visual Studio (PTVS) 263 | __pycache__/ 264 | *.pyc 265 | 266 | # Azurite 267 | __blobstorage__/ 268 | __azurite_*.json -------------------------------------------------------------------------------- /.vscode/extensions.json: -------------------------------------------------------------------------------- 1 | { 2 | "recommendations": [ 3 | "ms-azuretools.vscode-azurefunctions" 4 | ] 5 | } 6 | -------------------------------------------------------------------------------- /.vscode/launch.json: -------------------------------------------------------------------------------- 1 | { 2 | "version": "0.2.0", 3 | "configurations": [ 4 | { 5 | "name": "Attach to .NET Functions", 6 | "type": "coreclr", 7 | "request": "attach", 8 | "processId": "${command:azureFunctions.pickProcess}" 9 | } 10 | ] 11 | } -------------------------------------------------------------------------------- /.vscode/settings.json: -------------------------------------------------------------------------------- 1 | { 2 | "azureFunctions.deploySubpath": "bin/Release/netcoreapp3.1/publish", 3 | "azureFunctions.projectLanguage": "C#", 4 | "azureFunctions.projectRuntime": "~3", 5 | "debug.internalConsoleOptions": "neverOpen", 6 | "azureFunctions.preDeployTask": "publish" 7 | } -------------------------------------------------------------------------------- /.vscode/tasks.json: -------------------------------------------------------------------------------- 1 | { 2 | "version": "2.0.0", 3 | "tasks": [ 4 | { 5 | "label": "clean", 6 | "command": "dotnet", 7 | "args": [ 8 | "clean", 9 | "/property:GenerateFullPaths=true", 10 | "/consoleloggerparameters:NoSummary" 11 | ], 12 | "type": "process", 13 | "problemMatcher": "$msCompile" 14 | }, 15 | { 16 | "label": "build", 17 | "command": "dotnet", 18 | "args": [ 19 | "build", 20 | "/property:GenerateFullPaths=true", 21 | "/consoleloggerparameters:NoSummary" 22 | ], 23 | "type": "process", 24 | "dependsOn": "clean", 25 | "group": { 26 | "kind": "build", 27 | "isDefault": true 28 | }, 29 | "problemMatcher": "$msCompile" 30 | }, 31 | { 32 | "label": "clean release", 33 | "command": "dotnet", 34 | "args": [ 35 | "clean", 36 | "--configuration", 37 | "Release", 38 | "/property:GenerateFullPaths=true", 39 | "/consoleloggerparameters:NoSummary" 40 | ], 41 | "type": "process", 42 | "problemMatcher": "$msCompile" 43 | }, 44 | { 45 | "label": "publish", 46 | "command": "dotnet", 47 | "args": [ 48 | "publish", 49 | "--configuration", 50 | "Release", 51 | "/property:GenerateFullPaths=true", 52 | "/consoleloggerparameters:NoSummary" 53 | ], 54 | "type": "process", 55 | "dependsOn": "clean release", 56 | "problemMatcher": "$msCompile" 57 | }, 58 | { 59 | "type": "func", 60 | "dependsOn": "build", 61 | "options": { 62 | "cwd": "${workspaceFolder}/bin/Debug/netcoreapp3.1" 63 | }, 64 | "command": "host start", 65 | "isBackground": true, 66 | "problemMatcher": "$func-watch" 67 | } 68 | ] 69 | } -------------------------------------------------------------------------------- /AutoScaler.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using Microsoft.Azure.WebJobs; 4 | using Microsoft.Azure.WebJobs.Host; 5 | using Microsoft.Extensions.Logging; 6 | using Microsoft.Data.SqlClient; 7 | using Dapper; 8 | using Newtonsoft.Json; 9 | using Newtonsoft.Json.Linq; 10 | 11 | namespace Azure.SQL.DB.Hyperscale.Tools 12 | { 13 | public class HyperScaleTier 14 | { 15 | private readonly string Name = "hs"; 16 | public int Generation = 5; 17 | public int Cores = 2; 18 | 19 | public override string ToString() 20 | { 21 | return $"{Name}_gen{Generation}_{Cores}".ToUpper(); 22 | } 23 | 24 | public override bool Equals(object obj) 25 | { 26 | if (obj is null) 27 | return false; 28 | 29 | if (object.ReferenceEquals(this, obj)) 30 | return true; 31 | 32 | if (this.GetType() != obj.GetType()) 33 | return false; 34 | 35 | return this.ToString() == obj.ToString(); 36 | } 37 | 38 | public override int GetHashCode() 39 | { 40 | return this.ToString().GetHashCode(); 41 | } 42 | 43 | public static bool operator == (HyperScaleTier lhs, HyperScaleTier rhs) 44 | { 45 | if (lhs is null) 46 | { 47 | if (rhs is null) 48 | return true; 49 | 50 | return false; 51 | } 52 | 53 | return lhs.Equals(rhs); 54 | } 55 | 56 | public static bool operator != (HyperScaleTier lhs, HyperScaleTier rhs) 57 | { 58 | return !(lhs == rhs); 59 | } 60 | 61 | public static HyperScaleTier Parse(string tierName) 62 | { 63 | var curName = tierName.ToLower(); 64 | var parts = curName.Split('_'); 65 | 66 | if (parts[0] != "hs") throw new ArgumentException($"'{tierName}' is not an Hyperscale Tier"); 67 | 68 | var result = new HyperScaleTier(); 69 | result.Generation = int.Parse(parts[1].Replace("gen", string.Empty)); 70 | result.Cores = int.Parse(parts[2]); 71 | 72 | return result; 73 | } 74 | } 75 | 76 | public class UsageInfo 77 | { 78 | public DateTime TimeStamp = DateTime.Now; 79 | public String ServiceObjective = String.Empty; 80 | public Decimal AvgCpuPercent = 0; 81 | public Decimal MovingAvgCpuPercent = 0; 82 | public int DataPoints = 0; 83 | } 84 | 85 | public enum SearchDirection 86 | { 87 | Next, 88 | Previous 89 | } 90 | 91 | public class AutoScalerConfiguration 92 | { 93 | public int vCoreMin = int.Parse(Environment.GetEnvironmentVariable("vCoreMin")); 94 | public int vCoreMax = int.Parse(Environment.GetEnvironmentVariable("vCoreMax")); 95 | public decimal HighThreshold = decimal.Parse(Environment.GetEnvironmentVariable("HighThreshold")); 96 | public decimal LowThreshold = decimal.Parse(Environment.GetEnvironmentVariable("LowThreshold")); 97 | public int RequiredDataPoints = int.Parse(Environment.GetEnvironmentVariable("RequiredDataPoints")); 98 | } 99 | 100 | public static class AutoScaler 101 | { 102 | public static readonly List GEN4 = new List() { "hs_gen4_1", "hs_gen4_2", "hs_gen4_3", "hs_gen4_4", "hs_gen4_5", "hs_gen4_6", "hs_gen4_7", "hs_gen4_8", "hs_gen4_9", "hs_gen4_10", "hs_gen4_16", "hs_gen4_24" }; 103 | 104 | public static readonly List GEN5 = new List() { "hs_gen5_2", "hs_gen5_4", "hs_gen5_6", "hs_gen5_8", "hs_gen5_10", "hs_gen5_12", "hs_gen5_14", "hs_gen5_16", "hs_gen5_18", "hs_gen5_20", "hs_gen5_24", "hs_gen5_32", "hs_gen5_40", "hs_gen5_80" }; 105 | 106 | public static Dictionary> HyperscaleSLOs = new Dictionary>(); 107 | 108 | static AutoScaler() 109 | { 110 | HyperscaleSLOs.Add(4, GEN4); 111 | HyperscaleSLOs.Add(5, GEN5); 112 | } 113 | 114 | [FunctionName("AutoScaler")] 115 | public static void Run([TimerTrigger("*/15 * * * * *")]TimerInfo timer, ILogger log) 116 | { 117 | var autoscalerConfig = new AutoScalerConfiguration(); 118 | 119 | string connectionString = Environment.GetEnvironmentVariable("AzureSQLConnection"); 120 | string databaseName = (new SqlConnectionStringBuilder(connectionString)).InitialCatalog; 121 | 122 | using (var conn = new SqlConnection(connectionString)) 123 | { 124 | // Get usage data 125 | var followingRows = autoscalerConfig.RequiredDataPoints - 1; 126 | var usageInfo = conn.QuerySingleOrDefault($@" 127 | select top (1) 128 | [end_time] as [TimeStamp], 129 | databasepropertyex(db_name(), 'ServiceObjective') as ServiceObjective, 130 | [avg_cpu_percent] as AvgCpuPercent, 131 | avg([avg_cpu_percent]) over (order by end_time desc rows between current row and {followingRows} following) as MovingAvgCpuPercent, 132 | count(*) over (order by end_time desc rows between current row and {followingRows} following) as DataPoints 133 | from 134 | sys.dm_db_resource_stats 135 | order by 136 | end_time desc 137 | "); 138 | 139 | // If SLO is happening result could be null 140 | if (usageInfo == null) 141 | { 142 | log.LogInformation("No information received from server."); 143 | return; 144 | } 145 | 146 | // Decode current SLO 147 | var currentSlo = HyperScaleTier.Parse(usageInfo.ServiceObjective); 148 | var targetSlo = currentSlo; 149 | 150 | // At least one minute of historical data is needed 151 | if (usageInfo.DataPoints < autoscalerConfig.RequiredDataPoints) 152 | { 153 | log.LogInformation("Not enough data points."); 154 | WriteMetrics(log, usageInfo, currentSlo, targetSlo); 155 | conn.Execute("INSERT INTO [dbo].[AutoscalerMonitor] (RequestedSLO, UsageInfo) VALUES (NULL, @UsageInfo)", new { UsageInfo = JsonConvert.SerializeObject(usageInfo) }); 156 | return; 157 | } 158 | 159 | // Scale Up 160 | if (usageInfo.MovingAvgCpuPercent > autoscalerConfig.HighThreshold) 161 | { 162 | targetSlo = GetServiceObjective(currentSlo, SearchDirection.Next); 163 | if (targetSlo != null && currentSlo.Cores < autoscalerConfig.vCoreMax && currentSlo != targetSlo) 164 | { 165 | log.LogInformation($"HIGH threshold reached: scaling up to {targetSlo}"); 166 | conn.Execute($"ALTER DATABASE [{databaseName}] MODIFY (SERVICE_OBJECTIVE = '{targetSlo}')"); 167 | } 168 | } 169 | 170 | // Scale Down 171 | if (usageInfo.MovingAvgCpuPercent < autoscalerConfig.LowThreshold) 172 | { 173 | targetSlo = GetServiceObjective(currentSlo, SearchDirection.Previous); 174 | if (targetSlo != null && currentSlo.Cores > autoscalerConfig.vCoreMin && currentSlo != targetSlo) 175 | { 176 | log.LogInformation($"LOW threshold reached: scaling down to {targetSlo}"); 177 | conn.Execute($"ALTER DATABASE [{databaseName}] MODIFY (SERVICE_OBJECTIVE = '{targetSlo}')"); 178 | } 179 | } 180 | 181 | // Write current SLO to monitor table 182 | WriteMetrics(log, usageInfo, currentSlo, targetSlo); 183 | conn.Execute("INSERT INTO [dbo].[AutoscalerMonitor] (RequestedSLO, UsageInfo) VALUES (@RequestedSLO, @UsageInfo)", new { @RequestedSLO = targetSlo.ToString().ToUpper(), UsageInfo = JsonConvert.SerializeObject(usageInfo) }); 184 | } 185 | } 186 | 187 | private static void WriteMetrics(ILogger log, UsageInfo usageInfo, HyperScaleTier currentSlo, HyperScaleTier targetSlo) 188 | { 189 | log.LogMetric("DataPoints", usageInfo.DataPoints); 190 | log.LogMetric("AvgCpuPercent", Convert.ToDouble(usageInfo.AvgCpuPercent)); 191 | log.LogMetric("MovingAvgCpuPercent", Convert.ToDouble(usageInfo.MovingAvgCpuPercent)); 192 | log.LogMetric("CurrentCores", Convert.ToDouble(currentSlo.Cores)); 193 | log.LogMetric("TargetCores", Convert.ToDouble(targetSlo.Cores)); 194 | } 195 | 196 | public static HyperScaleTier GetServiceObjective(HyperScaleTier currentSLO, SearchDirection direction) 197 | { 198 | var targetSLO = currentSLO; 199 | var availableSlos = HyperscaleSLOs[currentSLO.Generation]; 200 | var index = availableSlos.IndexOf(currentSLO.ToString()); 201 | 202 | if (direction == SearchDirection.Next && index < availableSlos.Count) 203 | targetSLO = HyperScaleTier.Parse(availableSlos[index + 1]); 204 | 205 | if (direction == SearchDirection.Previous && index > 0) 206 | targetSLO = HyperScaleTier.Parse(availableSlos[index - 1]); 207 | 208 | return targetSLO; 209 | } 210 | } 211 | } 212 | -------------------------------------------------------------------------------- /Autoscaler.csproj: -------------------------------------------------------------------------------- 1 | 2 | 3 | netcoreapp3.1 4 | v3 5 | Azure.SQL.DB.Hyperscale.Tools 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | PreserveNewest 15 | 16 | 17 | PreserveNewest 18 | Never 19 | 20 | 21 | -------------------------------------------------------------------------------- /CODE_OF_CONDUCT.md: -------------------------------------------------------------------------------- 1 | # Microsoft Open Source Code of Conduct 2 | 3 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). 4 | 5 | Resources: 6 | 7 | - [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/) 8 | - [Microsoft Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) 9 | - Contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with questions or concerns 10 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) Microsoft Corporation. 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 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | --- 2 | page_type: sample 3 | languages: 4 | - tsql 5 | - csharp 6 | - sql 7 | - json 8 | products: 9 | - azure-sql-database 10 | - azure-functions 11 | - dotnet 12 | - azure 13 | description: "Automatically scale up or down Azure SQL Hyperscale depending on active workload" 14 | urlFragment: "azure-sql-hyperscale-autoscaler" 15 | --- 16 | 17 | # Azure SQL Hyperscale Autoscaler 18 | 19 | ![License](https://img.shields.io/badge/license-MIT-green.svg) 20 | 21 | 28 | 29 | This is a sample on how autoscaling of Azure SQL DB Hyperscale can be implemented using Azure Functions. The code just uses a simple moving average on the CPU load for the last minute; if the value is outside minimum or maximum boundaries it will initiate a scale-up or scale-down. 30 | 31 | A detailed article related to this repository is available here: 32 | 33 | [Autoscaling Azure SQL Hyperscale](https://techcommunity.microsoft.com/t5/azure-sql-database/autoscaling-azure-sql-hyperscale/ba-p/1149025) 34 | 35 | Scaling up or down is pretty fast in Hyperscale so responding to workload spikes can be done pretty quickly. 36 | 37 | ## Deploy 38 | 39 | ### Azure SQL 40 | 41 | Azure Function stores autoscaler data right into the monitored database itself, in the `dbo.AutoscalerMonitor` table. This is useful both to understand how and why the autoscaler took some actions, but also if you want to save historical data to create better autoscaling algorithms. Please use the script `./SQL/create-table` to setup the objects in the target database before running the Azure Function. If you plan to use the autoscaler in a production environment, is recommended to use a different database other than the monitored one to store historical autoscaler data. 42 | 43 | The provided script also create a sample `Numbers` table that can be used to execute some load testing to check how the autoscaler works. 44 | 45 | Autoscaler data, as an additional sample, is also sent to [Application Insight](https://docs.microsoft.com/en-us/azure/azure-functions/functions-monitoring#log-custom-telemetry-in-c-functions), so autoscler actions can be monitored directly from Azure Portal dashboard. 46 | 47 | ### Azure Function 48 | 49 | Deploy the solution to an Azure Function and then add the following [application settings](https://docs.microsoft.com/en-us/azure/azure-functions/functions-how-to-use-azure-function-app-settings#settings): 50 | 51 | ```json 52 | "AzureSQLConnection": "...", 53 | "HighThreshold": 70, 54 | "LowThreshold": 20, 55 | "vCoreMin": 2, 56 | "vCoreMax": 8, 57 | "RequiredDataPoints": 5 58 | ``` 59 | 60 | - AzureSQLConnection: Connection string to Azure SQL Hyperscale to monitor. Make sure the user used to login to the database has the [right permission](https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-database-transact-sql?view=azuresqldb-current#permissions-1) to run ALTER DATABASE command. 61 | - HighThreshold, LowThreshold: the minium and maximum threshold values after which scaling up or down will be initiated 62 | - vCoreMax, vCoreMin: the maximum and minimum number of cores you want to use as limits to scale up and down 63 | - RequiredDataPoints: Number of data points that needs to be gathered before initiating any autoscale action 64 | 65 | ## Test 66 | 67 | To the the autoscaler, if you created the `Numbers` test table, you can run the query `./SQL/load-test.sql` to create some workload. It is suggested that you create a new Hyperscale database with 2vCores to run the test. Tool like [SQL Query Stress](https://github.com/ErikEJ/SqlQueryStress) can be used to execute multiple query in parallel. A sample configuration is available in `SQL` folder: just put the correct connection information and when run it will generate a 80% load on a Gen5 2vCore Hyperscale database. This will be enough to initiate a scale-up action. 68 | 69 | ## Notes 70 | 71 | The solution requires Azure Functions 3.0. If you are using Visual Studio 2019 you don't have to do anything special. If you are using Visual Studio code, read here how to make sure you have Azure Function 3.0 installed on your machine: [Develop Azure Functions using .NET Core 3.1 ](https://dev.to/azure/develop-azure-functions-using-net-core-3-0-gcm) 72 | 73 | ## Disclaimer 74 | 75 | This sample is intended to show how to auto-scale Azure SQL Hyperscale Database, and therefore is not intended to be used in production as is. If you want to use it in production, make sure you correctly understand what is the workload pattern of your database and test if the used moving average can handle it nicely. Unless you have a very predictable and stable workload pattern, it is very likely that a different algorithm other than the simple moving average will be better suited to serve your specific workload. Machine learning can also help here, as it provides solution to the "Demand Forecasting" problem. For example: [Auto-train a time-series forecast model](https://docs.microsoft.com/en-us/azure/machine-learning/how-to-auto-train-forecast), or [ARIMA](https://en.wikipedia.org/wiki/Autoregressive_integrated_moving_average) or more in general: [Demand Forecasting](https://en.wikipedia.org/wiki/Demand_forecasting) 76 | 77 | ## How to contribute 78 | 79 | All contributions are more than welcome. Please refert to the [Code Of Conduct](CODE_OF_CONDUCT.md) to learn what are the basic rules to follow and then fork the repo and start to submit your PR. 80 | 81 | -------------------------------------------------------------------------------- /SQL/create-table.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS [dbo].[AutoscalerMonitor] 2 | GO 3 | 4 | CREATE TABLE [dbo].[AutoscalerMonitor] 5 | ( 6 | [Id] INT IDENTITY(1,1) NOT NULL PRIMARY KEY CLUSTERED, 7 | [InsertedAt] DATETIME2(7) NOT NULL DEFAULT (SYSUTCDATETIME()), 8 | [CurrentSLO] NVARCHAR(100) NOT NULL DEFAULT (CAST(DATABASEPROPERTYEX(DB_NAME(DB_ID()),'ServiceObjective') AS NVARCHAR(100))), 9 | [RequestedSLO] NVARCHAR(100) NULL, 10 | [UsageInfo] NVARCHAR(MAX) NULL CHECK(ISJSON([UsageInfo])=1) 11 | ) 12 | GO 13 | 14 | DROP TABLE IF EXISTS [dbo].[Numbers] 15 | GO 16 | 17 | SELECT TOP (1000000) 18 | ROW_NUMBER() OVER (ORDER BY A.[object_id]) AS Number, 19 | RAND(CHECKSUM(NEWID())) AS Random 20 | INTO 21 | [dbo].[Numbers] 22 | FROM 23 | sys.[all_columns] a, sys.[all_columns] b 24 | GO 25 | 26 | CREATE CLUSTERED INDEX ixc ON dbo.[Numbers](Number) 27 | GO -------------------------------------------------------------------------------- /SQL/load-test.sql: -------------------------------------------------------------------------------- 1 | WITH cte AS 2 | ( 3 | SELECT 4 | CASE WHEN ([Number] % 2) = 1 THEN 1 ELSE 0 END AS GroupId, 5 | [Number], 6 | Random 7 | FROM 8 | dbo.[Numbers] 9 | WHERE 10 | [Number] BETWEEN 1 AND 300000 11 | ) 12 | SELECT 13 | GroupId, 14 | COUNT(*), 15 | AVG(Random), 16 | STDEV(Random) 17 | FROM 18 | cte 19 | GROUP BY 20 | GroupId -------------------------------------------------------------------------------- /SQL/monitor-autoscaler.sql: -------------------------------------------------------------------------------- 1 | select 2 | * 3 | from 4 | [dbo].[AutoscalerMonitor] as m 5 | cross apply 6 | openjson(m.UsageInfo) with ( 7 | AvgCpuPercent decimal(9,3), 8 | MovingAvgCpuPercent decimal(9,3), 9 | DataPoints int 10 | ) as u 11 | order by m.InsertedAt desc 12 | -------------------------------------------------------------------------------- /SQL/monitor-resource-usage.sql: -------------------------------------------------------------------------------- 1 | select * from sys.[dm_db_resource_stats] -------------------------------------------------------------------------------- /SQL/sql-query-stress-config.json: -------------------------------------------------------------------------------- 1 | { 2 | "CollectIoStats": true, 3 | "CollectTimeStats": true, 4 | "CommandTimeout": 0, 5 | "ConnectionTimeout": 15, 6 | "DelayBetweenQueries": 50, 7 | "EnableConnectionPooling": true, 8 | "ForceDataRetrieval": false, 9 | "KillQueriesOnCancel": true, 10 | "MainDbConnectionInfo": { 11 | "ApplicationIntent": 0, 12 | "ConnectTimeout": 15, 13 | "Database": "mydatabase", 14 | "EnablePooling": true, 15 | "IntegratedAuth": false, 16 | "Login": "mylogin", 17 | "MaxPoolSize": 2, 18 | "Password": "mypassword", 19 | "Server": "myserver.database.windows.net" 20 | }, 21 | "MainQuery": "WITH cte AS\u000d\u000a(\u000d\u000a\u0009SELECT\u000d\u000a\u0009\u0009CASE WHEN ([Number] % 2) = 1 THEN 1 ELSE 0 END AS GroupId,\u000d\u000a\u0009\u0009[Number],\u000d\u000a\u0009\u0009Random\u000d\u000a\u0009FROM\u000d\u000a\u0009\u0009dbo.[Numbers]\u000d\u000a\u0009WHERE\u000d\u000a\u0009\u0009[Number] BETWEEN 1 AND 300000\u000d\u000a)\u000d\u000aSELECT\u000d\u000a\u0009GroupId,\u000d\u000a\u0009COUNT(*),\u000d\u000a\u0009AVG(Random),\u000d\u000a\u0009STDEV(Random)\u000d\u000aFROM\u000d\u000a\u0009cte\u000d\u000aGROUP BY\u000d\u000a\u0009GroupId", 22 | "NumIterations": 1200, 23 | "NumThreads": 2, 24 | "ParamDbConnectionInfo": { 25 | "ApplicationIntent": 0, 26 | "ConnectTimeout": 0, 27 | "Database": "", 28 | "EnablePooling": true, 29 | "IntegratedAuth": true, 30 | "Login": "", 31 | "MaxPoolSize": 0, 32 | "Password": "", 33 | "Server": "" 34 | }, 35 | "ParamMappings": [], 36 | "ParamQuery": "", 37 | "ShareDbSettings": true 38 | } -------------------------------------------------------------------------------- /host.json: -------------------------------------------------------------------------------- 1 | { 2 | "version": "2.0" 3 | } --------------------------------------------------------------------------------