├── .gitattributes ├── .gitignore ├── .vscode ├── launch.json └── tasks.json ├── CODE_OF_CONDUCT.md ├── Controllers ├── ControllerQuery.cs ├── CustomerController.cs ├── CustomersController.cs └── NullController.cs ├── LICENSE ├── Program.cs ├── README.md ├── SECURITY.md ├── SQL └── WideWorldImportersUpdates.sql ├── Sample-Usage.md ├── Startup.cs ├── appsettings.json ├── azure-deploy.sh └── azure-sql-db-dotnet-rest-api.csproj /.gitattributes: -------------------------------------------------------------------------------- 1 | * text=auto -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ## Ignore Visual Studio temporary files, build results, and 2 | ## files generated by popular Visual Studio add-ons. 3 | ## 4 | ## Get latest from https://github.com/github/gitignore/blob/master/VisualStudio.gitignore 5 | 6 | # User-specific files 7 | *.rsuser 8 | *.suo 9 | *.user 10 | *.userosscache 11 | *.sln.docstates 12 | 13 | # User-specific files (MonoDevelop/Xamarin Studio) 14 | *.userprefs 15 | 16 | # Mono auto generated files 17 | mono_crash.* 18 | 19 | # Build results 20 | [Dd]ebug/ 21 | [Dd]ebugPublic/ 22 | [Rr]elease/ 23 | [Rr]eleases/ 24 | x64/ 25 | x86/ 26 | [Aa][Rr][Mm]/ 27 | [Aa][Rr][Mm]64/ 28 | bld/ 29 | [Bb]in/ 30 | [Oo]bj/ 31 | [Ll]og/ 32 | [Ll]ogs/ 33 | 34 | # Visual Studio 2015/2017 cache/options directory 35 | .vs/ 36 | # Uncomment if you have tasks that create the project's static files in wwwroot 37 | #wwwroot/ 38 | 39 | # Visual Studio 2017 auto generated files 40 | Generated\ Files/ 41 | 42 | # MSTest test Results 43 | [Tt]est[Rr]esult*/ 44 | [Bb]uild[Ll]og.* 45 | 46 | # NUnit 47 | *.VisualState.xml 48 | TestResult.xml 49 | nunit-*.xml 50 | 51 | # Build Results of an ATL Project 52 | [Dd]ebugPS/ 53 | [Rr]eleasePS/ 54 | dlldata.c 55 | 56 | # Benchmark Results 57 | BenchmarkDotNet.Artifacts/ 58 | 59 | # .NET Core 60 | project.lock.json 61 | project.fragment.lock.json 62 | artifacts/ 63 | 64 | # StyleCop 65 | StyleCopReport.xml 66 | 67 | # Files built by Visual Studio 68 | *_i.c 69 | *_p.c 70 | *_h.h 71 | *.ilk 72 | *.meta 73 | *.obj 74 | *.iobj 75 | *.pch 76 | *.pdb 77 | *.ipdb 78 | *.pgc 79 | *.pgd 80 | *.rsp 81 | *.sbr 82 | *.tlb 83 | *.tli 84 | *.tlh 85 | *.tmp 86 | *.tmp_proj 87 | *_wpftmp.csproj 88 | *.log 89 | *.vspscc 90 | *.vssscc 91 | .builds 92 | *.pidb 93 | *.svclog 94 | *.scc 95 | 96 | # Chutzpah Test files 97 | _Chutzpah* 98 | 99 | # Visual C++ cache files 100 | ipch/ 101 | *.aps 102 | *.ncb 103 | *.opendb 104 | *.opensdf 105 | *.sdf 106 | *.cachefile 107 | *.VC.db 108 | *.VC.VC.opendb 109 | 110 | # Visual Studio profiler 111 | *.psess 112 | *.vsp 113 | *.vspx 114 | *.sap 115 | 116 | # Visual Studio Trace Files 117 | *.e2e 118 | 119 | # TFS 2012 Local Workspace 120 | $tf/ 121 | 122 | # Guidance Automation Toolkit 123 | *.gpState 124 | 125 | # ReSharper is a .NET coding add-in 126 | _ReSharper*/ 127 | *.[Rr]e[Ss]harper 128 | *.DotSettings.user 129 | 130 | # TeamCity is a build add-in 131 | _TeamCity* 132 | 133 | # DotCover is a Code Coverage Tool 134 | *.dotCover 135 | 136 | # AxoCover is a Code Coverage Tool 137 | .axoCover/* 138 | !.axoCover/settings.json 139 | 140 | # Visual Studio code coverage results 141 | *.coverage 142 | *.coveragexml 143 | 144 | # NCrunch 145 | _NCrunch_* 146 | .*crunch*.local.xml 147 | nCrunchTemp_* 148 | 149 | # MightyMoose 150 | *.mm.* 151 | AutoTest.Net/ 152 | 153 | # Web workbench (sass) 154 | .sass-cache/ 155 | 156 | # Installshield output folder 157 | [Ee]xpress/ 158 | 159 | # DocProject is a documentation generator add-in 160 | DocProject/buildhelp/ 161 | DocProject/Help/*.HxT 162 | DocProject/Help/*.HxC 163 | DocProject/Help/*.hhc 164 | DocProject/Help/*.hhk 165 | DocProject/Help/*.hhp 166 | DocProject/Help/Html2 167 | DocProject/Help/html 168 | 169 | # Click-Once directory 170 | publish/ 171 | 172 | # Publish Web Output 173 | *.[Pp]ublish.xml 174 | *.azurePubxml 175 | # Note: Comment the next line if you want to checkin your web deploy settings, 176 | # but database connection strings (with potential passwords) will be unencrypted 177 | *.pubxml 178 | *.publishproj 179 | 180 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 181 | # checkin your Azure Web App publish settings, but sensitive information contained 182 | # in these scripts will be unencrypted 183 | PublishScripts/ 184 | 185 | # NuGet Packages 186 | *.nupkg 187 | # NuGet Symbol Packages 188 | *.snupkg 189 | # The packages folder can be ignored because of Package Restore 190 | **/[Pp]ackages/* 191 | # except build/, which is used as an MSBuild target. 192 | !**/[Pp]ackages/build/ 193 | # Uncomment if necessary however generally it will be regenerated when needed 194 | #!**/[Pp]ackages/repositories.config 195 | # NuGet v3's project.json files produces more ignorable files 196 | *.nuget.props 197 | *.nuget.targets 198 | 199 | # Microsoft Azure Build Output 200 | csx/ 201 | *.build.csdef 202 | 203 | # Microsoft Azure Emulator 204 | ecf/ 205 | rcf/ 206 | 207 | # Windows Store app package directories and files 208 | AppPackages/ 209 | BundleArtifacts/ 210 | Package.StoreAssociation.xml 211 | _pkginfo.txt 212 | *.appx 213 | *.appxbundle 214 | *.appxupload 215 | 216 | # Visual Studio cache files 217 | # files ending in .cache can be ignored 218 | *.[Cc]ache 219 | # but keep track of directories ending in .cache 220 | !?*.[Cc]ache/ 221 | 222 | # Others 223 | ClientBin/ 224 | ~$* 225 | *~ 226 | *.dbmdl 227 | *.dbproj.schemaview 228 | *.jfm 229 | *.pfx 230 | *.publishsettings 231 | orleans.codegen.cs 232 | 233 | # Including strong name files can present a security risk 234 | # (https://github.com/github/gitignore/pull/2483#issue-259490424) 235 | #*.snk 236 | 237 | # Since there are multiple workflows, uncomment next line to ignore bower_components 238 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 239 | #bower_components/ 240 | 241 | # RIA/Silverlight projects 242 | Generated_Code/ 243 | 244 | # Backup & report files from converting an old project file 245 | # to a newer Visual Studio version. Backup files are not needed, 246 | # because we have git ;-) 247 | _UpgradeReport_Files/ 248 | Backup*/ 249 | UpgradeLog*.XML 250 | UpgradeLog*.htm 251 | ServiceFabricBackup/ 252 | *.rptproj.bak 253 | 254 | # SQL Server files 255 | *.mdf 256 | *.ldf 257 | *.ndf 258 | 259 | # Business Intelligence projects 260 | *.rdl.data 261 | *.bim.layout 262 | *.bim_*.settings 263 | *.rptproj.rsuser 264 | *- [Bb]ackup.rdl 265 | *- [Bb]ackup ([0-9]).rdl 266 | *- [Bb]ackup ([0-9][0-9]).rdl 267 | 268 | # Microsoft Fakes 269 | FakesAssemblies/ 270 | 271 | # GhostDoc plugin setting file 272 | *.GhostDoc.xml 273 | 274 | # Node.js Tools for Visual Studio 275 | .ntvs_analysis.dat 276 | node_modules/ 277 | 278 | # Visual Studio 6 build log 279 | *.plg 280 | 281 | # Visual Studio 6 workspace options file 282 | *.opt 283 | 284 | # Visual Studio 6 auto-generated workspace file (contains which files were open etc.) 285 | *.vbw 286 | 287 | # Visual Studio LightSwitch build output 288 | **/*.HTMLClient/GeneratedArtifacts 289 | **/*.DesktopClient/GeneratedArtifacts 290 | **/*.DesktopClient/ModelManifest.xml 291 | **/*.Server/GeneratedArtifacts 292 | **/*.Server/ModelManifest.xml 293 | _Pvt_Extensions 294 | 295 | # Paket dependency manager 296 | .paket/paket.exe 297 | paket-files/ 298 | 299 | # FAKE - F# Make 300 | .fake/ 301 | 302 | # CodeRush personal settings 303 | .cr/personal 304 | 305 | # Python Tools for Visual Studio (PTVS) 306 | __pycache__/ 307 | *.pyc 308 | 309 | # Cake - Uncomment if you are using it 310 | # tools/** 311 | # !tools/packages.config 312 | 313 | # Tabs Studio 314 | *.tss 315 | 316 | # Telerik's JustMock configuration file 317 | *.jmconfig 318 | 319 | # BizTalk build output 320 | *.btp.cs 321 | *.btm.cs 322 | *.odx.cs 323 | *.xsd.cs 324 | 325 | # OpenCover UI analysis results 326 | OpenCover/ 327 | 328 | # Azure Stream Analytics local run output 329 | ASALocalRun/ 330 | 331 | # MSBuild Binary and Structured Log 332 | *.binlog 333 | 334 | # NVidia Nsight GPU debugger configuration file 335 | *.nvuser 336 | 337 | # MFractors (Xamarin productivity tool) working folder 338 | .mfractor/ 339 | 340 | # Local History for Visual Studio 341 | .localhistory/ 342 | 343 | # BeatPulse healthcheck temp database 344 | healthchecksdb 345 | 346 | # Backup folder for Package Reference Convert tool in Visual Studio 2017 347 | MigrationBackup/ 348 | 349 | # Ionide (cross platform F# VS Code tools) working folder 350 | .ionide/ 351 | 352 | # Custom Files 353 | env.ps1 354 | env.sh 355 | appsettings.Development.json 356 | .env -------------------------------------------------------------------------------- /.vscode/launch.json: -------------------------------------------------------------------------------- 1 | { 2 | // Use IntelliSense to find out which attributes exist for C# debugging 3 | // Use hover for the description of the existing attributes 4 | // For further information visit https://github.com/OmniSharp/omnisharp-vscode/blob/master/debugger-launchjson.md 5 | "version": "0.2.0", 6 | "configurations": [ 7 | { 8 | "name": ".NET Core Launch (web)", 9 | "type": "coreclr", 10 | "request": "launch", 11 | "preLaunchTask": "build", 12 | // If you have changed target frameworks, make sure to update the program path. 13 | "program": "${workspaceFolder}/bin/Debug/net6.0/azure-sql-db-dotnet-rest-api.dll", 14 | "args": [], 15 | "cwd": "${workspaceFolder}", 16 | "stopAtEntry": false, 17 | "env": { 18 | "ASPNETCORE_ENVIRONMENT": "Development" 19 | }, 20 | "envFile": "${workspaceFolder}/.env", 21 | "sourceFileMap": { 22 | "/Views": "${workspaceFolder}/Views" 23 | } 24 | }, 25 | { 26 | "name": ".NET Core Attach", 27 | "type": "coreclr", 28 | "request": "attach", 29 | "processId": "${command:pickProcess}" 30 | } 31 | ] 32 | } -------------------------------------------------------------------------------- /.vscode/tasks.json: -------------------------------------------------------------------------------- 1 | { 2 | "version": "2.0.0", 3 | "tasks": [ 4 | { 5 | "label": "build", 6 | "command": "dotnet", 7 | "type": "process", 8 | "args": [ 9 | "build", 10 | "${workspaceFolder}/azure-sql-db-dotnet-rest-api.csproj", 11 | "/property:GenerateFullPaths=true", 12 | "/consoleloggerparameters:NoSummary" 13 | ], 14 | "problemMatcher": "$msCompile" 15 | }, 16 | { 17 | "label": "publish", 18 | "command": "dotnet", 19 | "type": "process", 20 | "args": [ 21 | "publish", 22 | "${workspaceFolder}/azure-sql-db-dotnet-rest-api.csproj", 23 | "/property:GenerateFullPaths=true", 24 | "/consoleloggerparameters:NoSummary" 25 | ], 26 | "problemMatcher": "$msCompile" 27 | }, 28 | { 29 | "label": "watch", 30 | "command": "dotnet", 31 | "type": "process", 32 | "args": [ 33 | "watch", 34 | "run", 35 | "${workspaceFolder}/azure-sql-db-dotnet-rest-api.csproj", 36 | "/property:GenerateFullPaths=true", 37 | "/consoleloggerparameters:NoSummary" 38 | ], 39 | "problemMatcher": "$msCompile" 40 | } 41 | ] 42 | } -------------------------------------------------------------------------------- /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 | -------------------------------------------------------------------------------- /Controllers/ControllerQuery.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Threading.Tasks; 5 | using Microsoft.AspNetCore.Mvc; 6 | using Microsoft.Extensions.Logging; 7 | using System.Text.Json; 8 | using System.Data; 9 | using Microsoft.Data.SqlClient; 10 | using Dapper; 11 | using Microsoft.Extensions.Configuration; 12 | 13 | namespace AzureSamples.AzureSQL.Controllers 14 | { 15 | public class ControllerQuery : ControllerBase 16 | { 17 | private readonly ILogger _logger; 18 | private readonly IConfiguration _config; 19 | 20 | public ControllerQuery(IConfiguration config, ILogger logger) 21 | { 22 | _logger = logger; 23 | _config = config; 24 | } 25 | 26 | protected async Task Query(string verb, Type entity, int? id = null, JsonElement payload = default(JsonElement)) 27 | { 28 | JsonDocument result = null; 29 | 30 | if (!(new string[] {"get", "put", "patch", "delete"}).Contains(verb.ToLower())) 31 | { 32 | throw new ArgumentException($"verb '{verb}' not supported", nameof(verb)); 33 | } 34 | 35 | string entityName = entity.Name.Replace("Controller", string.Empty).ToLower(); 36 | string procedure = $"web.{verb}_{entityName}"; 37 | _logger.LogDebug($"Executing {procedure}"); 38 | 39 | var connectionStringName = verb.ToLower() != "get" ? "ReadWriteConnection" : "ReadOnlyConnection"; 40 | 41 | using(var conn = new SqlConnection(_config.GetConnectionString(connectionStringName))) { 42 | DynamicParameters parameters = new DynamicParameters(); 43 | 44 | if (payload.ValueKind != default(JsonValueKind)) 45 | { 46 | var json = JsonSerializer.Serialize(payload); 47 | parameters.Add("Json", json); 48 | } 49 | 50 | if (id.HasValue) 51 | parameters.Add("Id", id.Value); 52 | 53 | var qr = await conn.ExecuteScalarAsync( 54 | sql: procedure, 55 | param: parameters, 56 | commandType: CommandType.StoredProcedure 57 | ); 58 | 59 | if (qr != null) 60 | result = JsonDocument.Parse(qr); 61 | }; 62 | 63 | if (result == null) 64 | result = JsonDocument.Parse("[]"); 65 | 66 | return result.RootElement; 67 | } 68 | } 69 | } 70 | -------------------------------------------------------------------------------- /Controllers/CustomerController.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Threading.Tasks; 5 | using Microsoft.AspNetCore.Mvc; 6 | using Microsoft.Extensions.Logging; 7 | using System.Text.Json; 8 | using Microsoft.Extensions.Configuration; 9 | 10 | namespace AzureSamples.AzureSQL.Controllers 11 | { 12 | [ApiController] 13 | [Route("[controller]")] 14 | public class CustomerController : ControllerQuery 15 | { 16 | public CustomerController(IConfiguration config, ILogger logger): 17 | base(config, logger) {} 18 | 19 | [HttpGet("{customerId}")] 20 | public async Task Get(int customerId) 21 | { 22 | return await this.Query("get", this.GetType(), customerId); 23 | } 24 | 25 | [HttpPut] 26 | public async Task Put([FromBody]JsonElement payload) 27 | { 28 | return await this.Query("put", this.GetType(), payload: payload); 29 | } 30 | 31 | [HttpPatch("{customerId}")] 32 | public async Task Patch([FromBody]JsonElement payload, int customerId) 33 | { 34 | return await this.Query("patch", this.GetType(), customerId, payload); 35 | } 36 | 37 | [HttpDelete("{customerId}")] 38 | public async Task Delete(int customerId) 39 | { 40 | return await this.Query("delete", this.GetType(), customerId); 41 | } 42 | } 43 | } 44 | -------------------------------------------------------------------------------- /Controllers/CustomersController.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Threading.Tasks; 5 | using Microsoft.AspNetCore.Mvc; 6 | using Microsoft.Extensions.Logging; 7 | using System.Text.Json; 8 | using Microsoft.Extensions.Configuration; 9 | 10 | namespace AzureSamples.AzureSQL.Controllers 11 | { 12 | [ApiController] 13 | [Route("[controller]")] 14 | public class CustomersController : ControllerQuery 15 | { 16 | public CustomersController(IConfiguration config, ILogger logger): 17 | base(config, logger) {} 18 | 19 | [HttpGet] 20 | public async Task Get() 21 | { 22 | return await this.Query("get", this.GetType()); 23 | } 24 | } 25 | } 26 | -------------------------------------------------------------------------------- /Controllers/NullController.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Threading.Tasks; 5 | using Microsoft.AspNetCore.Mvc; 6 | using Microsoft.Extensions.Logging; 7 | using System.Text.Json; 8 | using Microsoft.Extensions.Configuration; 9 | 10 | namespace AzureSamples.AzureSQL.Controllers 11 | { 12 | [ApiController] 13 | [Route("[controller]")] 14 | public class NullController : ControllerBase 15 | { 16 | [HttpGet] 17 | public string Get() 18 | { 19 | var dummy = new { 20 | TimeStamp = DateTime.UtcNow 21 | }; 22 | 23 | return JsonSerializer.Serialize(dummy); 24 | } 25 | } 26 | } 27 | -------------------------------------------------------------------------------- /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 | -------------------------------------------------------------------------------- /Program.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Threading.Tasks; 5 | using Microsoft.AspNetCore.Hosting; 6 | using Microsoft.Extensions.Configuration; 7 | using Microsoft.Extensions.Hosting; 8 | using Microsoft.Extensions.Logging; 9 | 10 | namespace AzureSamples.AzureSQL 11 | { 12 | public class Program 13 | { 14 | public static void Main(string[] args) 15 | { 16 | CreateHostBuilder(args).Build().Run(); 17 | } 18 | 19 | public static IHostBuilder CreateHostBuilder(string[] args) => 20 | Host.CreateDefaultBuilder(args) 21 | .ConfigureWebHostDefaults(webBuilder => 22 | { 23 | webBuilder.UseStartup(); 24 | }); 25 | } 26 | } 27 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | --- 2 | page_type: sample 3 | languages: 4 | - tsql 5 | - sql 6 | - aspx-csharp 7 | - json 8 | products: 9 | - azure 10 | - dotnet 11 | - aspnet 12 | - aspnet-core 13 | - azure-app-service 14 | - vs-code 15 | - azure-sql-database 16 | description: "Creating a modern REST API with .NET Core and Azure SQL, using Dapper and Visual Studio Code" 17 | urlFragment: "azure-sql-db-dotnet-rest-api" 18 | --- 19 | 20 | # Creating a REST API with .NET Core and Azure SQL 21 | 22 | ![License](https://img.shields.io/badge/license-MIT-green.svg) 23 | 24 | 31 | 32 | Thanks to native JSON support, creating a REST API with Azure SQL and .NET Core is really a matter of a few lines of code: 33 | 34 | ```csharp 35 | var qr = await conn.ExecuteScalarAsync( 36 | sql: procedure, 37 | param: parameters, 38 | commandType: CommandType.StoredProcedure 39 | ); 40 | 41 | var result = JsonDocument.Parse(qr); 42 | ``` 43 | 44 | This is possible thanks to [Azure SQL native support to JSON](https://docs.microsoft.com/en-us/azure/sql-database/sql-database-json-features) format and the MicroORM [Dapper](https://medium.com/dapper-net/get-started-with-dapper-net-591592c335aa) that removes all the plumbing code and returns not tables and columns but a fully deserialized object. Object that can be a POCO object or just JSON for maximum flexibilty. 45 | 46 | ## Install Sample Database 47 | 48 | In order to run this sample, the WideWorldImporters database is needed. Install WideWorldImporters sample database: 49 | 50 | [Restore WideWorldImporters Database](https://github.com/yorek/azure-sql-db-samples#restore-wideworldimporters-database) 51 | 52 | ## Add Database Objects 53 | 54 | Once the sample database has been installed, you need to add some stored procedures that will be called from .NET. The SQL code is available here: 55 | 56 | `./SQL/WideWorldImportersUpdates.sql` 57 | 58 | If you need any help in executing the SQL script, you can find a Quickstart here: [Quickstart: Use Azure Data Studio to connect and query Azure SQL database](https://docs.microsoft.com/en-us/sql/azure-data-studio/quickstart-sql-database) 59 | 60 | ## Run sample locally 61 | 62 | Make sure you have [.NET Core 6.0](https://dotnet.microsoft.com/download) SDK installed on your machine. Clone this repo in a directory on your computer and then configure the connection string in `appsettings.json`. 63 | 64 | If you don't want to save the connection string in the `appsettings.json` file for security reasons, you can just set it using an environment variable: 65 | 66 | Linux: 67 | 68 | ```bash 69 | export ConnectionStrings__DefaultConnection="" 70 | ``` 71 | 72 | Windows (Powershell): 73 | 74 | ```powershell 75 | $Env:ConnectionStrings__DefaultConnection="" 76 | ``` 77 | 78 | Your connection string is something like: 79 | 80 | ```text 81 | SERVER=.database.windows.net;DATABASE=;UID=DotNetWebApp;PWD=a987REALLY#$%TRONGpa44w0rd! 82 | ``` 83 | 84 | Just replace `` and `` with the correct values for your environment. 85 | 86 | To run and test the REST API locally, just run 87 | 88 | ```bash 89 | dotnet run 90 | ``` 91 | 92 | .NET will start the HTTP server and when everything is up and running you'll see something like 93 | 94 | ```text 95 | Now listening on: https://localhost:5001 96 | ``` 97 | 98 | Using a REST Client (such as [Visual Studio](https://learn.microsoft.com/aspnet/core/test/http-files), [Insomnia](https://insomnia.rest/), [Curl](https://curl.se/docs/httpscripting.html) or PowerShell's [Invoke-RestMethod](https://learn.microsoft.com/powershell/module/microsoft.powershell.utility/invoke-restmethod)), you can now call your API, for example: 99 | 100 | ```bash 101 | curl -k -X GET https://localhost:5001/customer/123 102 | ``` 103 | 104 | and you'll get info on Customer 123: 105 | 106 | ```json 107 | [ 108 | { 109 | "CustomerID": 123, 110 | "CustomerName": "Tailspin Toys (Roe Park, NY)", 111 | "PhoneNumber": "(212) 555-0100", 112 | "FaxNumber": "(212) 555-0101", 113 | "WebsiteURL": "http://www.tailspintoys.com/RoePark", 114 | "Delivery": { 115 | "AddressLine1": "Shop 219", 116 | "AddressLine2": "528 Persson Road", 117 | "PostalCode": "90775" 118 | } 119 | } 120 | ] 121 | ``` 122 | 123 | Check out more samples to test all implemented verbs here: 124 | 125 | [cUrl Samples](./Sample-Usage.md) 126 | 127 | ## Deploy to Azure 128 | 129 | Now that your REST API solution is ready, it's time to deploy it on Azure so that anyone can take advantage of it. A detailed article on how you can that that is here: 130 | 131 | - [Create an ASP.NET Core app in App Service on Linux](https://docs.microsoft.com/en-us/azure/app-service/containers/quickstart-dotnetcore) 132 | 133 | The only thing you have do in addition to what explained in the above article is to add the connection string to the Azure Web App configuration. Using AZ CLI, for example: 134 | 135 | ```bash 136 | appName="azure-sql-db-dotnet-rest-api" 137 | resourceGroup="my-resource-group" 138 | 139 | az webapp config connection-string set \ 140 | -g $resourceGroup \ 141 | -n $appName \ 142 | --settings DefaultConnection=$ConnectionStrings__DefaultConnection \ 143 | --connection-string-type=SQLAzure 144 | ``` 145 | 146 | Just make sure you correctly set `$appName` and `$resourceGroup` to match your environment and also that the variable `$ConnectionStrings__DefaultConnection` as also been set, as mentioned in section "Run sample locally". 147 | 148 | An example of a full script that deploys the REST API is available here: `azure-deploy.sh`. 149 | 150 | ## Learn more 151 | 152 | If you're new to .NET and want to learn more, there are a lot of tutorial available on the [Microsoft Learn](https://docs.microsoft.com/en-us/learn/browse/?products=dotnet) platform. You can start from here, for example: 153 | 154 | - https://docs.microsoft.com/en-us/learn/modules/build-web-api-net-core/?view=aspnetcore-3.1 155 | 156 | If you also want to learn more about Visual Studio Code, here's another resource: 157 | 158 | [Using .NET Core in Visual Studio Code](https://code.visualstudio.com/docs/languages/dotnet) 159 | 160 | ## Contributing 161 | 162 | This project welcomes contributions and suggestions. Most contributions require you to agree to a 163 | Contributor License Agreement (CLA) declaring that you have the right to, and actually do, grant us 164 | the rights to use your contribution. For details, visit https://cla.opensource.microsoft.com. 165 | 166 | When you submit a pull request, a CLA bot will automatically determine whether you need to provide 167 | a CLA and decorate the PR appropriately (e.g., status check, comment). Simply follow the instructions 168 | provided by the bot. You will only need to do this once across all repos using our CLA. 169 | 170 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). 171 | For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) or 172 | contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments. 173 | -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | ## Security 4 | 5 | Microsoft takes the security of our software products and services seriously, which includes all source code repositories managed through our GitHub organizations, which include [Microsoft](https://github.com/Microsoft), [Azure](https://github.com/Azure), [DotNet](https://github.com/dotnet), [AspNet](https://github.com/aspnet), [Xamarin](https://github.com/xamarin), and [our GitHub organizations](https://opensource.microsoft.com/). 6 | 7 | If you believe you have found a security vulnerability in any Microsoft-owned repository that meets Microsoft's [Microsoft's definition of a security vulnerability](https://docs.microsoft.com/en-us/previous-versions/tn-archive/cc751383(v=technet.10)) of a security vulnerability, please report it to us as described below. 8 | 9 | ## Reporting Security Issues 10 | 11 | **Please do not report security vulnerabilities through public GitHub issues.** 12 | 13 | Instead, please report them to the Microsoft Security Response Center (MSRC) at [https://msrc.microsoft.com/create-report](https://msrc.microsoft.com/create-report). 14 | 15 | If you prefer to submit without logging in, send email to [secure@microsoft.com](mailto:secure@microsoft.com). If possible, encrypt your message with our PGP key; please download it from the the [Microsoft Security Response Center PGP Key page](https://www.microsoft.com/en-us/msrc/pgp-key-msrc). 16 | 17 | You should receive a response within 24 hours. If for some reason you do not, please follow up via email to ensure we received your original message. Additional information can be found at [microsoft.com/msrc](https://www.microsoft.com/msrc). 18 | 19 | Please include the requested information listed below (as much as you can provide) to help us better understand the nature and scope of the possible issue: 20 | 21 | * Type of issue (e.g. buffer overflow, SQL injection, cross-site scripting, etc.) 22 | * Full paths of source file(s) related to the manifestation of the issue 23 | * The location of the affected source code (tag/branch/commit or direct URL) 24 | * Any special configuration required to reproduce the issue 25 | * Step-by-step instructions to reproduce the issue 26 | * Proof-of-concept or exploit code (if possible) 27 | * Impact of the issue, including how an attacker might exploit the issue 28 | 29 | This information will help us triage your report more quickly. 30 | 31 | If you are reporting for a bug bounty, more complete reports can contribute to a higher bounty award. Please visit our [Microsoft Bug Bounty Program](https://microsoft.com/msrc/bounty) page for more details about our active programs. 32 | 33 | ## Preferred Languages 34 | 35 | We prefer all communications to be in English. 36 | 37 | ## Policy 38 | 39 | Microsoft follows the principle of [Coordinated Vulnerability Disclosure](https://www.microsoft.com/en-us/msrc/cvd). 40 | 41 | 42 | -------------------------------------------------------------------------------- /SQL/WideWorldImportersUpdates.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Create schema 3 | */ 4 | IF SCHEMA_ID('web') IS NULL BEGIN 5 | EXECUTE('CREATE SCHEMA [web] AUTHORIZATION [dbo]'); 6 | END 7 | GO 8 | 9 | /* 10 | Create user to be used in the sample API solution 11 | */ 12 | IF USER_ID('DotNetWebApp') IS NULL BEGIN 13 | CREATE USER [DotNetWebApp] WITH PASSWORD = 'a987REALLY#$%TRONGpa44w0rd!'; 14 | END 15 | 16 | /* 17 | Grant execute permission to created users 18 | */ 19 | GRANT EXECUTE ON SCHEMA::[web] TO [DotNetWebApp]; 20 | GO 21 | 22 | /* 23 | Return details on a specific customer 24 | */ 25 | CREATE OR ALTER PROCEDURE web.get_customer 26 | @Id INT 27 | AS 28 | SET NOCOUNT ON; 29 | SELECT 30 | [CustomerID], 31 | [CustomerName], 32 | [PhoneNumber], 33 | [FaxNumber], 34 | [WebsiteURL], 35 | [DeliveryAddressLine1] AS 'Delivery.AddressLine1', 36 | [DeliveryAddressLine2] AS 'Delivery.AddressLine2', 37 | [DeliveryPostalCode] AS 'Delivery.PostalCode' 38 | FROM 39 | [Sales].[Customers] 40 | WHERE 41 | [CustomerID] = @Id 42 | FOR JSON PATH 43 | GO 44 | 45 | /* 46 | Delete a specific customer 47 | */ 48 | CREATE OR ALTER PROCEDURE web.delete_customer 49 | @Id INT 50 | AS 51 | SET NOCOUNT ON; 52 | DELETE FROM [Sales].[Customers] WHERE CustomerId = @Id; 53 | SELECT * FROM (SELECT CustomerID = @Id) D FOR JSON AUTO; 54 | GO 55 | 56 | /* 57 | Update (Patch) a specific customer 58 | */ 59 | CREATE OR ALTER PROCEDURE web.patch_customer 60 | @Id INT, 61 | @Json NVARCHAR(MAX) 62 | AS 63 | SET NOCOUNT ON; 64 | WITH [source] AS 65 | ( 66 | SELECT * FROM OPENJSON(@Json) WITH ( 67 | [CustomerID] INT, 68 | [CustomerName] NVARCHAR(100), 69 | [PhoneNumber] NVARCHAR(20), 70 | [FaxNumber] NVARCHAR(20), 71 | [WebsiteURL] NVARCHAR(256), 72 | [DeliveryAddressLine1] NVARCHAR(60) '$.Delivery.AddressLine1', 73 | [DeliveryAddressLine2] NVARCHAR(60) '$.Delivery.AddressLine2', 74 | [DeliveryPostalCode] NVARCHAR(10) '$.Delivery.PostalCode' 75 | ) 76 | ) 77 | UPDATE 78 | t 79 | SET 80 | t.[CustomerName] = COALESCE(s.[CustomerName], t.[CustomerName]), 81 | t.[PhoneNumber] = COALESCE(s.[PhoneNumber], t.[PhoneNumber]), 82 | t.[FaxNumber] = COALESCE(s.[FaxNumber], t.[FaxNumber]), 83 | t.[WebsiteURL] = COALESCE(s.[WebsiteURL], t.[WebsiteURL]), 84 | t.[DeliveryAddressLine1] = COALESCE(s.[DeliveryAddressLine1], t.[DeliveryAddressLine1]), 85 | t.[DeliveryAddressLine2] = COALESCE(s.[DeliveryAddressLine2], t.[DeliveryAddressLine2]), 86 | t.[DeliveryPostalCode] = COALESCE(s.[DeliveryPostalCode], t.[DeliveryPostalCode]) 87 | FROM 88 | [Sales].[Customers] t 89 | INNER JOIN 90 | [source] s ON t.[CustomerID] = s.[CustomerID] 91 | WHERE 92 | t.CustomerId = @Id; 93 | 94 | EXEC web.get_customer @Id; 95 | GO 96 | 97 | /* 98 | Create a new customer 99 | */ 100 | 101 | CREATE OR ALTER PROCEDURE web.put_customer 102 | @Json NVARCHAR(MAX) 103 | AS 104 | SET NOCOUNT ON; 105 | DECLARE @CustomerId INT = NEXT VALUE FOR Sequences.CustomerID; 106 | WITH [source] AS 107 | ( 108 | SELECT @CustomerId AS CustomerID, * FROM OPENJSON(@Json) WITH ( 109 | [CustomerName] NVARCHAR(100), 110 | [PhoneNumber] NVARCHAR(20), 111 | [FaxNumber] NVARCHAR(20), 112 | [WebsiteURL] NVARCHAR(256), 113 | [DeliveryAddressLine1] NVARCHAR(60) '$.Delivery.AddressLine1', 114 | [DeliveryAddressLine2] NVARCHAR(60) '$.Delivery.AddressLine2', 115 | [DeliveryPostalCode] NVARCHAR(10) '$.Delivery.PostalCode' 116 | ) 117 | ) 118 | INSERT INTO [Sales].[Customers] 119 | ( 120 | CustomerID, 121 | CustomerName, 122 | BillToCustomerID, 123 | CustomerCategoryID, 124 | PrimaryContactPersonID, 125 | DeliveryMethodID, 126 | DeliveryCityID, 127 | PostalCityID, 128 | AccountOpenedDate, 129 | StandardDiscountPercentage, 130 | IsStatementSent, 131 | IsOnCreditHold, 132 | PaymentDays, 133 | PhoneNumber, 134 | FaxNumber, 135 | WebsiteURL, 136 | DeliveryAddressLine1, 137 | DeliveryAddressLine2, 138 | DeliveryPostalCode, 139 | PostalAddressLine1, 140 | PostalAddressLine2, 141 | PostalPostalCode, 142 | LastEditedBy 143 | ) 144 | SELECT 145 | @CustomerId, 146 | CustomerName, 147 | @CustomerId, 148 | 5, -- Computer Shop 149 | 1, -- No contact person 150 | 1, -- Post Delivery 151 | 28561, -- Redmond 152 | 28561, -- Redmond 153 | SYSUTCDATETIME(), 154 | 0.00, 155 | 0, 156 | 0, 157 | 30, 158 | PhoneNumber, 159 | FaxNumber, 160 | WebsiteURL, 161 | DeliveryAddressLine1, 162 | DeliveryAddressLine2, 163 | DeliveryPostalCode, 164 | DeliveryAddressLine1, 165 | DeliveryAddressLine2, 166 | DeliveryPostalCode, 167 | 1 168 | FROM 169 | [source] 170 | ; 171 | 172 | EXEC web.get_customer @CustomerId; 173 | GO 174 | 175 | CREATE OR ALTER PROCEDURE web.get_customers 176 | AS 177 | SET NOCOUNT ON; 178 | -- Cast is needed to corretly inform the driver 179 | -- that output type is NVARCHAR(MAX) 180 | -- to make sure it won't be truncated 181 | SELECT CAST(( 182 | SELECT 183 | [CustomerID], 184 | [CustomerName] 185 | FROM 186 | [Sales].[Customers] 187 | FOR JSON PATH) AS NVARCHAR(MAX)) AS JsonResult 188 | GO 189 | -------------------------------------------------------------------------------- /Sample-Usage.md: -------------------------------------------------------------------------------- 1 | # Sample REST API usage with cUrl 2 | 3 | ## Get a customer 4 | 5 | ```bash 6 | curl -s -k -X GET https://localhost:5001/customer/121 7 | ``` 8 | 9 | ## Create new customer 10 | 11 | ```bash 12 | curl -s -k -H "Content-Type: application/json" -X PUT https://localhost:5001/customer -d '{"CustomerName": "John Doe", "PhoneNumber": "123-234-5678", "FaxNumber": "123-234-5678", "WebsiteURL": "http://www.something.com", "Delivery": { "AddressLine1": "One Microsoft Way", "PostalCode": 98052 }}' 13 | ``` 14 | 15 | ## Update customer 16 | 17 | ```bash 18 | curl -s -k -H "Content-Type: application/json" -X PATCH http://localhost:5000/customer/123 -d '{"CustomerName": "Jane Dean", "PhoneNumber": "231-778-5678" }' 19 | ``` 20 | 21 | ## Delete a customer 22 | 23 | ```bash 24 | curl -s -k -X DELETE http://localhost:5000/customer/123 25 | ``` 26 | -------------------------------------------------------------------------------- /Startup.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Threading.Tasks; 5 | using Microsoft.AspNetCore.Builder; 6 | using Microsoft.AspNetCore.Hosting; 7 | using Microsoft.AspNetCore.HttpsPolicy; 8 | using Microsoft.AspNetCore.Mvc; 9 | using Microsoft.Extensions.Configuration; 10 | using Microsoft.Extensions.DependencyInjection; 11 | using Microsoft.Extensions.Hosting; 12 | using Microsoft.Extensions.Logging; 13 | 14 | namespace AzureSamples.AzureSQL 15 | { 16 | public class Startup 17 | { 18 | public Startup(IConfiguration configuration) 19 | { 20 | Configuration = configuration; 21 | } 22 | 23 | public IConfiguration Configuration { get; } 24 | 25 | // This method gets called by the runtime. Use this method to add services to the container. 26 | public void ConfigureServices(IServiceCollection services) 27 | { 28 | services.AddControllers(); 29 | } 30 | 31 | // This method gets called by the runtime. Use this method to configure the HTTP request pipeline. 32 | public void Configure(IApplicationBuilder app, IWebHostEnvironment env) 33 | { 34 | if (env.IsDevelopment()) 35 | { 36 | app.UseDeveloperExceptionPage(); 37 | } 38 | 39 | app.UseHttpsRedirection(); 40 | 41 | app.UseRouting(); 42 | 43 | app.UseAuthorization(); 44 | 45 | app.UseEndpoints(endpoints => 46 | { 47 | endpoints.MapControllers(); 48 | }); 49 | } 50 | } 51 | } 52 | -------------------------------------------------------------------------------- /appsettings.json: -------------------------------------------------------------------------------- 1 | { 2 | "Logging": { 3 | "LogLevel": { 4 | "Default": "Information", 5 | "Microsoft": "Warning", 6 | "Microsoft.Hosting.Lifetime": "Information" 7 | } 8 | }, 9 | "AllowedHosts": "*", 10 | "ConnectionStrings": { 11 | "ReadWriteConnection": "Server=.database.windows.net;Database=;UID=;PWD=", 12 | "ReadOnlyConnection": "Server=.database.windows.net;Database=;UID=;PWD=" 13 | } 14 | } 15 | -------------------------------------------------------------------------------- /azure-deploy.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | set -euo pipefail 4 | 5 | # Make sure these values are correct for your environment 6 | resourceGroup="dm-api-02" 7 | appName="dm-api-02" 8 | location="WestUS2" 9 | 10 | # Change this if you are using your own github repository 11 | gitSource="https://github.com/Azure-Samples/azure-sql-db-dotnet-rest-api.git" 12 | 13 | 14 | # Azure configuration 15 | FILE=".env" 16 | if [[ -f $FILE ]]; then 17 | echo "loading from .env" 18 | export $(egrep . $FILE | xargs -n1) 19 | else 20 | cat << EOF > .env 21 | ConnectionStrings__ReadWriteConnection="Server=.database.windows.net;Database=;UID=;PWD=" 22 | ConnectionStrings__ReadOnlyConnection="Server=.database.windows.net;Database=;UID=;PWD=" 23 | EOF 24 | echo "Enviroment file not detected." 25 | echo "Please configure values for your environment in the created .env file" 26 | echo "and run the script again." 27 | echo "ConnectionStrings__ReadWriteConnection: Azure SQL Connection String used for Read/Write workloads" 28 | echo "ConnectionStrings__ReadOnlyConnection: Azure SQL Connection String used for Read-Only workloads" 29 | exit 1 30 | fi 31 | 32 | # Make sure connection string variable is set 33 | if [[ -z "${ConnectionStrings__ReadWriteConnection:-}" ]]; then 34 | echo "ConnectionStrings__ReadWriteConnection not found." 35 | exit 1; 36 | fi 37 | 38 | if [[ -z "${ConnectionStrings__ReadOnlyConnection:-}" ]]; then 39 | echo "ConnectionStrings__ReadOnlyConnection not found." 40 | exit 1; 41 | fi 42 | 43 | echo "Creating Resource Group..."; 44 | az group create \ 45 | -n $resourceGroup \ 46 | -l $location 47 | 48 | echo "Creating Application Service Plan..."; 49 | az appservice plan create \ 50 | -g $resourceGroup \ 51 | -n "windows-plan" \ 52 | --sku B1 53 | 54 | echo "Creating Web Application..."; 55 | az webapp create \ 56 | -g $resourceGroup \ 57 | -n $appName \ 58 | --plan "windows-plan" \ 59 | --deployment-source-url $gitSource \ 60 | --deployment-source-branch perftest 61 | 62 | echo "Configuring Connection String..."; 63 | az webapp config connection-string set \ 64 | -g $resourceGroup \ 65 | -n $appName \ 66 | --settings ReadWriteConnection=$ConnectionStrings__ReadWriteConnection \ 67 | --connection-string-type=SQLAzure 68 | 69 | az webapp config connection-string set \ 70 | -g $resourceGroup \ 71 | -n $appName \ 72 | --settings ReadOnlyConnection=$ConnectionStrings__ReadOnlyConnection \ 73 | --connection-string-type=SQLAzure 74 | 75 | echo "Done." -------------------------------------------------------------------------------- /azure-sql-db-dotnet-rest-api.csproj: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | net6.0 5 | AzureSamples.AzureSQL 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | --------------------------------------------------------------------------------