├── .gitignore ├── .vscode ├── launch.json └── settings.json ├── CODE_OF_CONDUCT.md ├── LICENSE ├── README.md ├── SECURITY.md ├── app.py ├── azure-deploy.sh ├── requirements.txt ├── sample-usage.md ├── simple-app.py └── sql └── WideWorldImportersUpdates.sql /.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 | *.suo 8 | *.user 9 | *.userosscache 10 | *.sln.docstates 11 | 12 | # User-specific files (MonoDevelop/Xamarin Studio) 13 | *.userprefs 14 | 15 | # Build results 16 | [Dd]ebug/ 17 | [Dd]ebugPublic/ 18 | [Rr]elease/ 19 | [Rr]eleases/ 20 | x64/ 21 | x86/ 22 | bld/ 23 | [Bb]in/ 24 | [Oo]bj/ 25 | [Ll]og/ 26 | 27 | # Visual Studio 2015/2017 cache/options directory 28 | .vs/ 29 | # Uncomment if you have tasks that create the project's static files in wwwroot 30 | #wwwroot/ 31 | 32 | # Visual Studio 2017 auto generated files 33 | Generated\ Files/ 34 | 35 | # MSTest test Results 36 | [Tt]est[Rr]esult*/ 37 | [Bb]uild[Ll]og.* 38 | 39 | # NUNIT 40 | *.VisualState.xml 41 | TestResult.xml 42 | 43 | # Build Results of an ATL Project 44 | [Dd]ebugPS/ 45 | [Rr]eleasePS/ 46 | dlldata.c 47 | 48 | # Benchmark Results 49 | BenchmarkDotNet.Artifacts/ 50 | 51 | # .NET Core 52 | project.lock.json 53 | project.fragment.lock.json 54 | artifacts/ 55 | **/Properties/launchSettings.json 56 | 57 | # StyleCop 58 | StyleCopReport.xml 59 | 60 | # Files built by Visual Studio 61 | *_i.c 62 | *_p.c 63 | *_i.h 64 | *.ilk 65 | *.meta 66 | *.obj 67 | *.iobj 68 | *.pch 69 | *.pdb 70 | *.ipdb 71 | *.pgc 72 | *.pgd 73 | *.rsp 74 | *.sbr 75 | *.tlb 76 | *.tli 77 | *.tlh 78 | *.tmp 79 | *.tmp_proj 80 | *.log 81 | *.vspscc 82 | *.vssscc 83 | .builds 84 | *.pidb 85 | *.svclog 86 | *.scc 87 | 88 | # Chutzpah Test files 89 | _Chutzpah* 90 | 91 | # Visual C++ cache files 92 | ipch/ 93 | *.aps 94 | *.ncb 95 | *.opendb 96 | *.opensdf 97 | *.sdf 98 | *.cachefile 99 | *.VC.db 100 | *.VC.VC.opendb 101 | 102 | # Visual Studio profiler 103 | *.psess 104 | *.vsp 105 | *.vspx 106 | *.sap 107 | 108 | # Visual Studio Trace Files 109 | *.e2e 110 | 111 | # TFS 2012 Local Workspace 112 | $tf/ 113 | 114 | # Guidance Automation Toolkit 115 | *.gpState 116 | 117 | # ReSharper is a .NET coding add-in 118 | _ReSharper*/ 119 | *.[Rr]e[Ss]harper 120 | *.DotSettings.user 121 | 122 | # JustCode is a .NET coding add-in 123 | .JustCode 124 | 125 | # TeamCity is a build add-in 126 | _TeamCity* 127 | 128 | # DotCover is a Code Coverage Tool 129 | *.dotCover 130 | 131 | # AxoCover is a Code Coverage Tool 132 | .axoCover/* 133 | !.axoCover/settings.json 134 | 135 | # Visual Studio code coverage results 136 | *.coverage 137 | *.coveragexml 138 | 139 | # NCrunch 140 | _NCrunch_* 141 | .*crunch*.local.xml 142 | nCrunchTemp_* 143 | 144 | # MightyMoose 145 | *.mm.* 146 | AutoTest.Net/ 147 | 148 | # Web workbench (sass) 149 | .sass-cache/ 150 | 151 | # Installshield output folder 152 | [Ee]xpress/ 153 | 154 | # DocProject is a documentation generator add-in 155 | DocProject/buildhelp/ 156 | DocProject/Help/*.HxT 157 | DocProject/Help/*.HxC 158 | DocProject/Help/*.hhc 159 | DocProject/Help/*.hhk 160 | DocProject/Help/*.hhp 161 | DocProject/Help/Html2 162 | DocProject/Help/html 163 | 164 | # Click-Once directory 165 | publish/ 166 | 167 | # Publish Web Output 168 | *.[Pp]ublish.xml 169 | *.azurePubxml 170 | # Note: Comment the next line if you want to checkin your web deploy settings, 171 | # but database connection strings (with potential passwords) will be unencrypted 172 | *.pubxml 173 | *.publishproj 174 | 175 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 176 | # checkin your Azure Web App publish settings, but sensitive information contained 177 | # in these scripts will be unencrypted 178 | PublishScripts/ 179 | 180 | # NuGet Packages 181 | *.nupkg 182 | # The packages folder can be ignored because of Package Restore 183 | **/[Pp]ackages/* 184 | # except build/, which is used as an MSBuild target. 185 | !**/[Pp]ackages/build/ 186 | # Uncomment if necessary however generally it will be regenerated when needed 187 | #!**/[Pp]ackages/repositories.config 188 | # NuGet v3's project.json files produces more ignorable files 189 | *.nuget.props 190 | *.nuget.targets 191 | 192 | # Microsoft Azure Build Output 193 | csx/ 194 | *.build.csdef 195 | 196 | # Microsoft Azure Emulator 197 | ecf/ 198 | rcf/ 199 | 200 | # Windows Store app package directories and files 201 | AppPackages/ 202 | BundleArtifacts/ 203 | Package.StoreAssociation.xml 204 | _pkginfo.txt 205 | *.appx 206 | 207 | # Visual Studio cache files 208 | # files ending in .cache can be ignored 209 | *.[Cc]ache 210 | # but keep track of directories ending in .cache 211 | !*.[Cc]ache/ 212 | 213 | # Others 214 | ClientBin/ 215 | ~$* 216 | *~ 217 | *.dbmdl 218 | *.dbproj.schemaview 219 | *.jfm 220 | *.pfx 221 | *.publishsettings 222 | orleans.codegen.cs 223 | 224 | # Including strong name files can present a security risk 225 | # (https://github.com/github/gitignore/pull/2483#issue-259490424) 226 | #*.snk 227 | 228 | # Since there are multiple workflows, uncomment next line to ignore bower_components 229 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 230 | #bower_components/ 231 | 232 | # RIA/Silverlight projects 233 | Generated_Code/ 234 | 235 | # Backup & report files from converting an old project file 236 | # to a newer Visual Studio version. Backup files are not needed, 237 | # because we have git ;-) 238 | _UpgradeReport_Files/ 239 | Backup*/ 240 | UpgradeLog*.XML 241 | UpgradeLog*.htm 242 | ServiceFabricBackup/ 243 | *.rptproj.bak 244 | 245 | # SQL Server files 246 | *.mdf 247 | *.ldf 248 | *.ndf 249 | 250 | # Business Intelligence projects 251 | *.rdl.data 252 | *.bim.layout 253 | *.bim_*.settings 254 | *.rptproj.rsuser 255 | 256 | # Microsoft Fakes 257 | FakesAssemblies/ 258 | 259 | # GhostDoc plugin setting file 260 | *.GhostDoc.xml 261 | 262 | # Node.js Tools for Visual Studio 263 | .ntvs_analysis.dat 264 | node_modules/ 265 | 266 | # Visual Studio 6 build log 267 | *.plg 268 | 269 | # Visual Studio 6 workspace options file 270 | *.opt 271 | 272 | # Visual Studio 6 auto-generated workspace file (contains which files were open etc.) 273 | *.vbw 274 | 275 | # Visual Studio LightSwitch build output 276 | **/*.HTMLClient/GeneratedArtifacts 277 | **/*.DesktopClient/GeneratedArtifacts 278 | **/*.DesktopClient/ModelManifest.xml 279 | **/*.Server/GeneratedArtifacts 280 | **/*.Server/ModelManifest.xml 281 | _Pvt_Extensions 282 | 283 | # Paket dependency manager 284 | .paket/paket.exe 285 | paket-files/ 286 | 287 | # FAKE - F# Make 288 | .fake/ 289 | 290 | # JetBrains Rider 291 | .idea/ 292 | *.sln.iml 293 | 294 | # CodeRush 295 | .cr/ 296 | 297 | # Python Tools for Visual Studio (PTVS) 298 | __pycache__/ 299 | *.pyc 300 | 301 | # Cake - Uncomment if you are using it 302 | # tools/** 303 | # !tools/packages.config 304 | 305 | # Tabs Studio 306 | *.tss 307 | 308 | # Telerik's JustMock configuration file 309 | *.jmconfig 310 | 311 | # BizTalk build output 312 | *.btp.cs 313 | *.btm.cs 314 | *.odx.cs 315 | *.xsd.cs 316 | 317 | # OpenCover UI analysis results 318 | OpenCover/ 319 | 320 | # Azure Stream Analytics local run output 321 | ASALocalRun/ 322 | 323 | # MSBuild Binary and Structured Log 324 | *.binlog 325 | 326 | # NVidia Nsight GPU debugger configuration file 327 | *.nvuser 328 | 329 | # MFractors (Xamarin productivity tool) working folder 330 | .mfractor/ 331 | 332 | # Additional Files 333 | venv/ 334 | env/ 335 | env.* 336 | .env -------------------------------------------------------------------------------- /.vscode/launch.json: -------------------------------------------------------------------------------- 1 | { 2 | // Use IntelliSense to learn about possible attributes. 3 | // Hover to view descriptions of existing attributes. 4 | // For more information, visit: https://go.microsoft.com/fwlink/?linkid=830387 5 | "version": "0.2.0", 6 | "configurations": [ 7 | { 8 | "name": "Python: Flask", 9 | "type": "python", 10 | "request": "launch", 11 | "module": "flask", 12 | "env": { 13 | "FLASK_APP": "app.py", 14 | "FLASK_ENV": "development", 15 | "FLASK_DEBUG": "0" 16 | }, 17 | "envFile": "${workspaceFolder}/.env", 18 | "args": [ 19 | "run", 20 | "--no-debugger", 21 | "--no-reload" 22 | ], 23 | "jinja": true 24 | } 25 | ] 26 | } -------------------------------------------------------------------------------- /.vscode/settings.json: -------------------------------------------------------------------------------- 1 | { 2 | "python.pythonPath": "venv\\Scripts\\python.exe", 3 | "cSpell.words": [ 4 | "pyodbc" 5 | ] 6 | } -------------------------------------------------------------------------------- /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 | - python 5 | - tsql 6 | - sql 7 | - json 8 | products: 9 | - azure 10 | - vs-code 11 | - azure-sql-database 12 | - azure-app-service 13 | - azure-app-service-web 14 | description: "Creating a modern REST API with Python and Azure SQL, using Flask and Visual Studio Code" 15 | urlFragment: "azure-sql-db-python-rest-api" 16 | --- 17 | 18 | # Creating a REST API with Python and Azure SQL 19 | 20 | ![License](https://img.shields.io/badge/license-MIT-green.svg) 21 | 22 | 29 | 30 | Thanks to native JSON support, creating a REST API with Azure SQL and Python is really a matter of a few lines of code. Take a look at `app.py` to easy it is! 31 | 32 | Wondering what's the magic behind? The sample uses the well known [Flask](https://flask.palletsprojects.com/en/1.1.x/) micro-framework and the [flask-restful](https://flask-restful.readthedocs.io/en/latest/) package to easily implement REST APIs. Beside that the [native JSON support that Azure SQL provides](https://docs.microsoft.com/en-us/azure/sql-database/sql-database-json-features) does all the heavy lifting so sending data back and forth to the database is as easy as sending a JSON message. 33 | 34 | ## Install Sample Database 35 | 36 | In order to run this sample, the WideWorldImporters database is needed. Install WideWorldImporters sample database: 37 | 38 | [Restore WideWorldImporters Database](https://github.com/yorek/azure-sql-db-samples#restore-wideworldimporters-database) 39 | 40 | ## Add Database Objects 41 | 42 | Once the sample database has been installed, you need to add some stored procedures that will be called from Python. The SQL code is available here: 43 | 44 | `./sql/WideWorldImportersUpdates.sql` 45 | 46 | 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) 47 | 48 | ## Run sample locally 49 | 50 | Make sure you have Python 3.7 installed on your machine. Clone this repo in a directory on our computer and then create a [virtual environment](https://www.youtube.com/watch?v=_eczHOiFMZA&list=PLlrxD0HtieHhS8VzuMCfQD4uJ9yne1mE6&index=34). For example: 51 | 52 | ```bash 53 | virtualenv venv --python C:\Python37\ 54 | ``` 55 | 56 | then activate the created virtual environment. For example, on Windows: 57 | 58 | ```powershell 59 | .\venv\Scripts\activate 60 | ``` 61 | 62 | and then install all the required packages: 63 | 64 | ```bash 65 | pip install -r requirements 66 | ``` 67 | 68 | The connections string is not saved in the python code for security reasons, so you need to assign it to an environment variable in order to run the sample successfully. You also want to enable [development environment](https://flask.palletsprojects.com/en/1.1.x/config/#environment-and-debug-features) for Flask: 69 | 70 | Linux: 71 | 72 | ```bash 73 | export FLASK_ENV="development" 74 | export SQLAZURECONNSTR_WWIF="" 75 | ``` 76 | 77 | Windows: 78 | 79 | ```powershell 80 | $Env:FLASK_ENV="development" 81 | $Env:SQLAZURECONNSTR_WWIF="" 82 | ``` 83 | 84 | Your connection string is something like: 85 | 86 | ``` 87 | DRIVER={ODBC Driver 17 for SQL Server};SERVER=.database.windows.net;DATABASE=;UID=PythonWebApp;PWD=a987REALLY#$%TRONGpa44w0rd 88 | ``` 89 | 90 | Just replace `` and `` with the correct values for your environment. 91 | 92 | To run and test the Python REST API local, just run 93 | 94 | ```bash 95 | flask run 96 | ``` 97 | 98 | Python will start the HTTP server and when everything is up and running you'll see something like 99 | 100 | ```text 101 | * Running on http://127.0.0.1:5000/ (Press CTRL+C to quit) 102 | ``` 103 | 104 | Using a REST Client (like [Insomnia](https://insomnia.rest/), [Postman](https://www.getpostman.com/) or curl), you can now call your API, for example: 105 | 106 | ```bash 107 | curl -X GET http://localhost:5000/customer/123 108 | ``` 109 | 110 | and you'll get info on Customer 123: 111 | 112 | ```json 113 | [ 114 | { 115 | "CustomerID": 123, 116 | "CustomerName": "Tailspin Toys (Roe Park, NY)", 117 | "PhoneNumber": "(212) 555-0100", 118 | "FaxNumber": "(212) 555-0101", 119 | "WebsiteURL": "http://www.tailspintoys.com/RoePark", 120 | "Delivery": { 121 | "AddressLine1": "Shop 219", 122 | "AddressLine2": "528 Persson Road", 123 | "PostalCode": "90775" 124 | } 125 | } 126 | ] 127 | ``` 128 | 129 | Check out more samples to test all implemented verbs here: 130 | 131 | [cUrl Samples](./sample-usage.md) 132 | 133 | ## Debug from Visual Studio Code 134 | 135 | Debugging from Visual Studio Code is fully supported. Make sure you create an `.env` file the look like the following one (making sure you add your connection string) 136 | 137 | ``` 138 | FLASK_ENV="development" 139 | SQLAZURECONNSTR_WWIF="" 140 | ``` 141 | 142 | and you'll be good to go. 143 | 144 | ## Deploy to Azure 145 | 146 | 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: 147 | 148 | - [Deploying Python web apps to Azure App Services](https://medium.com/@GeekTrainer/deploying-python-web-apps-to-azure-app-services-413cc16d4d68) 149 | - [Quickstart: Create a Python app in Azure App Service on Linux](https://docs.microsoft.com/en-us/azure/app-service/containers/quickstart-python?tabs=bash) 150 | 151 | The only thing you have do in addition to what explained in the above articles is to add the connection string to the Azure Web App configuration. Using AZ CLI, for example: 152 | 153 | ```bash 154 | appName="azure-sql-db-python-rest-api" 155 | resourceGroup="my-resource-group" 156 | 157 | az webapp config connection-string set \ 158 | -g $resourceGroup \ 159 | -n $appName \ 160 | --settings WWIF=$SQLAZURECONNSTR_WWIF \ 161 | --connection-string-type=SQLAzure 162 | ``` 163 | 164 | Just make sure you correctly set `$appName` and `$resourceGroup` to match your environment and also that the variable `$SQLAZURECONNSTR_WWIF` as also been set, as mentioned in section "Run sample locally". An example of a full script that deploy the REST API is available here: `azure-deploy.sh`. 165 | 166 | Please note that connection string are accessible as environment variables from Python when running on Azure, *but they are prefixed* as documented here: 167 | 168 | https://docs.microsoft.com/en-us/azure/app-service/configure-common#connection-strings 169 | 170 | That's why the Python code in the sample look for `SQLAZURECONNSTR_WWIF` but the Shell script write the `WWIF` connection string name. 171 | 172 | ## Connection Resiliency 173 | 174 | As per best practices, code implement a retry logic to make sure connections to Azure SQL are resilient and che nicely handle those cases in which the database may not be available. One of these case is when database is being scale up or down. This is usually a pretty fast operation (with Azure SQL Hyperscale it happens in something around 10 seconds), but still graceful management of connection is needed. 175 | 176 | The sample uses the [Tenacity](https://tenacity.readthedocs.io/en/latest/) library to implement a simple retry-logic in case the error "Communication link failure" happens (see [ODBC Error Codes](https://docs.microsoft.com/en-us/sql/odbc/reference/appendixes/appendix-a-odbc-error-codes)). 177 | 178 | If you need more details aside the general error generated by the ODBC call, you can take a look at the detailed errors that Azure SQL will return here: [Troubleshooting connectivity issues and other errors with Microsoft Azure SQL Database](https://docs.microsoft.com/en-us/azure/sql-database/troubleshoot-connectivity-issues-microsoft-azure-sql-database) 179 | 180 | To test connection resiliency you can using testing tools like [Locust.io](https://locust.io/), [K6](https://k6.io/) or [Apache JMeter](https://jmeter.apache.org/). IF you want something really simple to try right away, a while loop will do. For example: 181 | 182 | ```bash 183 | while :; do curl -s -X GET http://localhost:5000/customer/$((RANDOM % 1000)); sleep 1; done 184 | ``` 185 | 186 | ## PyODBC, Linux and Connection Pooling 187 | 188 | To get the best performances, Connection Pooling should be used so that each time the code tries to open and close a connection, it can just take an existing connection from the pool, reset it, and use that one. Using a connection from the pool is way less expensive than creating a new connection, so by using connection pooling performance can be greatly improved. 189 | 190 | Unfortunately as of today (March 2020) ODBC connection pooling in Linux does not work as expected to due an issue in unixODBC library. To work around that, I had to implement a manual technique to pool connection, that you can find in the `ConnectionManager` class. 191 | 192 | Once the issue will be fixed, or if you are using Windows, you can completely remove that part of the code, and just open and close the connection as you would do normally, as connection pooling will be used automatically behind the scenes. 193 | 194 | ## Learn more 195 | 196 | If you're new to Python and want to learn more, there is a full free Python course here: 197 | 198 | - [Python for Beginners - Videos](https://aka.ms/python-for-beginners) 199 | - [Python for Beginners - GitHub Repo](https://github.com/microsoft/c9-python-getting-started) 200 | 201 | It will teach you not only how to use Python, but also how to take advantage the a great editor like Visual Studio Code. 202 | 203 | Flask is a very common (and amazing!) framework. Learn how to use it right from Visual Studio Code with this tutorial: 204 | 205 | [Flask Tutorial in Visual Studio Code](https://code.visualstudio.com/docs/python/tutorial-flask) 206 | 207 | ## Contributing 208 | 209 | This project welcomes contributions and suggestions. Most contributions require you to agree to a 210 | Contributor License Agreement (CLA) declaring that you have the right to, and actually do, grant us 211 | the rights to use your contribution. For details, visit https://cla.opensource.microsoft.com. 212 | 213 | When you submit a pull request, a CLA bot will automatically determine whether you need to provide 214 | a CLA and decorate the PR appropriately (e.g., status check, comment). Simply follow the instructions 215 | provided by the bot. You will only need to do this once across all repos using our CLA. 216 | 217 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). 218 | For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) or 219 | contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments. 220 | -------------------------------------------------------------------------------- /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 | -------------------------------------------------------------------------------- /app.py: -------------------------------------------------------------------------------- 1 | import sys 2 | import os 3 | import json 4 | import pyodbc 5 | import socket 6 | from flask import Flask 7 | from flask_restful import reqparse, abort, Api, Resource 8 | from threading import Lock 9 | from tenacity import * 10 | from opencensus.ext.azure.trace_exporter import AzureExporter 11 | from opencensus.ext.flask.flask_middleware import FlaskMiddleware 12 | from opencensus.trace.samplers import ProbabilitySampler 13 | import logging 14 | 15 | # Initialize Flask 16 | app = Flask(__name__) 17 | 18 | # Setup Azure Monitor 19 | if 'APPINSIGHTS_KEY' in os.environ: 20 | middleware = FlaskMiddleware( 21 | app, 22 | exporter=AzureExporter(connection_string="InstrumentationKey={0}".format(os.environ['APPINSIGHTS_KEY'])), 23 | sampler=ProbabilitySampler(rate=1.0), 24 | ) 25 | 26 | # Setup Flask Restful framework 27 | api = Api(app) 28 | parser = reqparse.RequestParser() 29 | parser.add_argument('customer') 30 | 31 | # Implement singleton to avoid global objects 32 | class ConnectionManager(object): 33 | __instance = None 34 | __connection = None 35 | __lock = Lock() 36 | 37 | def __new__(cls): 38 | if ConnectionManager.__instance is None: 39 | ConnectionManager.__instance = object.__new__(cls) 40 | return ConnectionManager.__instance 41 | 42 | def __getConnection(self): 43 | if (self.__connection == None): 44 | application_name = ";APP={0}".format(socket.gethostname()) 45 | self.__connection = pyodbc.connect(os.environ['SQLAZURECONNSTR_WWIF'] + application_name) 46 | 47 | return self.__connection 48 | 49 | def __removeConnection(self): 50 | self.__connection = None 51 | 52 | @retry(stop=stop_after_attempt(3), wait=wait_fixed(10), retry=retry_if_exception_type(pyodbc.OperationalError), after=after_log(app.logger, logging.DEBUG)) 53 | def executeQueryJSON(self, procedure, payload=None): 54 | result = {} 55 | try: 56 | conn = self.__getConnection() 57 | 58 | cursor = conn.cursor() 59 | 60 | if payload: 61 | cursor.execute(f"EXEC {procedure} ?", json.dumps(payload)) 62 | else: 63 | cursor.execute(f"EXEC {procedure}") 64 | 65 | result = cursor.fetchone() 66 | 67 | if result: 68 | result = json.loads(result[0]) 69 | else: 70 | result = {} 71 | 72 | cursor.commit() 73 | except pyodbc.OperationalError as e: 74 | app.logger.error(f"{e.args[1]}") 75 | if e.args[0] == "08S01": 76 | # If there is a "Communication Link Failure" error, 77 | # then connection must be removed 78 | # as it will be in an invalid state 79 | self.__removeConnection() 80 | raise 81 | finally: 82 | cursor.close() 83 | 84 | return result 85 | 86 | class Queryable(Resource): 87 | def executeQueryJson(self, verb, payload=None): 88 | result = {} 89 | entity = type(self).__name__.lower() 90 | procedure = f"web.{verb}_{entity}" 91 | result = ConnectionManager().executeQueryJSON(procedure, payload) 92 | return result 93 | 94 | # Customer Class 95 | class Customer(Queryable): 96 | def get(self, customer_id): 97 | customer = {} 98 | customer["CustomerID"] = customer_id 99 | result = self.executeQueryJson("get", customer) 100 | return result, 200 101 | 102 | def put(self): 103 | args = parser.parse_args() 104 | customer = json.loads(args['customer']) 105 | result = self.executeQueryJson("put", customer) 106 | return result, 201 107 | 108 | def patch(self, customer_id): 109 | args = parser.parse_args() 110 | customer = json.loads(args['customer']) 111 | customer["CustomerID"] = customer_id 112 | result = self.executeQueryJson("patch", customer) 113 | return result, 202 114 | 115 | def delete(self, customer_id): 116 | customer = {} 117 | customer["CustomerID"] = customer_id 118 | result = self.executeQueryJson("delete", customer) 119 | return result, 202 120 | 121 | # Customers Class 122 | class Customers(Queryable): 123 | def get(self): 124 | result = self.executeQueryJson("get") 125 | return result, 200 126 | 127 | # Create API routes 128 | api.add_resource(Customer, '/customer', '/customer/') 129 | api.add_resource(Customers, '/customers') 130 | -------------------------------------------------------------------------------- /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-01" 7 | appName="dm-api-01" 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-python-rest-api.git" 12 | 13 | # Make sure connection string variable is set 14 | 15 | if [[ -z "${SQLAZURECONNSTR_WWIF:-}" ]]; then 16 | echo "Plase export Azure SQL connection string:"; 17 | echo "export SQLAZURECONNSTR_WWIF=\"your-connection-string-here\""; 18 | exit 1; 19 | fi 20 | 21 | echo "Creating Resource Group..."; 22 | az group create \ 23 | -n $resourceGroup \ 24 | -l $location 25 | 26 | echo "Creating Application Service Plan..."; 27 | az appservice plan create \ 28 | -g $resourceGroup \ 29 | -n "linux-plan" \ 30 | --sku B1 \ 31 | --is-linux 32 | 33 | echo "Creating Application Insight..." 34 | az resource create \ 35 | -g $resourceGroup \ 36 | -n $appName-ai \ 37 | --resource-type "Microsoft.Insights/components" \ 38 | --properties '{"Application_Type":"web"}' 39 | 40 | echo "Reading Application Insight Key..." 41 | aikey=`az resource show -g $resourceGroup -n $appName-ai --resource-type "Microsoft.Insights/components" --query properties.InstrumentationKey -o tsv` 42 | 43 | echo "Creating Web Application..."; 44 | az webapp create \ 45 | -g $resourceGroup \ 46 | -n $appName \ 47 | --plan "linux-plan" \ 48 | --runtime "PYTHON|3.7" \ 49 | --deployment-source-url $gitSource \ 50 | --deployment-source-branch master 51 | 52 | echo "Configuring Connection String..."; 53 | az webapp config connection-string set \ 54 | -g $resourceGroup \ 55 | -n $appName \ 56 | --settings WWIF="$SQLAZURECONNSTR_WWIF" \ 57 | --connection-string-type=SQLAzure 58 | 59 | echo "Configuring Application Insights..."; 60 | az webapp config appsettings set \ 61 | -g $resourceGroup \ 62 | -n $appName \ 63 | --settings APPINSIGHTS_KEY="$aikey" 64 | 65 | echo "Done." -------------------------------------------------------------------------------- /requirements.txt: -------------------------------------------------------------------------------- 1 | pyodbc 2 | flask 3 | flask-restful 4 | opencensus-ext-azure 5 | opencensus-ext-flask 6 | tenacity 7 | python-dotenv -------------------------------------------------------------------------------- /sample-usage.md: -------------------------------------------------------------------------------- 1 | # Sample REST API usage with cUrl 2 | 3 | ## Get a customer 4 | 5 | ```bash 6 | curl -s -X GET http://localhost:5000/customer/123 7 | ``` 8 | 9 | ## Create new customer 10 | 11 | ```bash 12 | curl -s -X PUT http://localhost:5000/customer -d 'customer={"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 -X PATCH http://localhost:5000/customer/123 -d 'customer={"CustomerName": "Jane Dean", "PhoneNumber": "231-778-5678" }' 19 | ``` 20 | 21 | ## Delete a customer 22 | 23 | ```bash 24 | curl -s -X DELETE http://localhost:5000/customer/123 25 | ``` 26 | -------------------------------------------------------------------------------- /simple-app.py: -------------------------------------------------------------------------------- 1 | import sys 2 | import os 3 | from flask import Flask 4 | from flask_restful import reqparse, Api, Resource 5 | import json 6 | import pyodbc 7 | 8 | # This is a simplified example that only support GET request. 9 | # It is meant to help you to get you started if you're new to development 10 | # and to show how simple is using Azure SQL with Python 11 | # A more complete example is in "app.py" 12 | # To run this simplified sample follow the README, but instead of running "flask run" 13 | # just run "python ./simple-app.py" 14 | # Enjoy! 15 | 16 | # Initialize Flask 17 | app = Flask(__name__) 18 | 19 | # Setup Flask Restful framework 20 | api = Api(app) 21 | parser = reqparse.RequestParser() 22 | parser.add_argument('customer') 23 | 24 | # Create connection to Azure SQL 25 | conn = pyodbc.connect(os.environ['SQLAZURECONNSTR_WWIF']) 26 | 27 | # Customer Class 28 | class Customer(Resource): 29 | def get(self, customer_id): 30 | customer = {"CustomerID": customer_id} 31 | cursor = conn.cursor() 32 | cursor.execute("EXEC web.get_customer ?", json.dumps(customer)) 33 | result = json.loads(cursor.fetchone()[0]) 34 | cursor.close() 35 | return result, 200 36 | 37 | # Create API route to defined Customer class 38 | api.add_resource(Customer, '/customer', '/customer/') 39 | 40 | # Start App 41 | if __name__ == '__main__': 42 | app.run() -------------------------------------------------------------------------------- /sql/WideWorldImportersUpdates.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Create schema 3 | */ 4 | IF SCHEMA_ID('web') IS NULL BEGIN 5 | EXECUTE('CREATE SCHEMA [web]'); 6 | END 7 | GO 8 | 9 | /* 10 | Create user to be used in the sample API solution 11 | */ 12 | IF USER_ID('PythonWebApp') IS NULL BEGIN 13 | CREATE USER [PythonWebApp] WITH PASSWORD = 'a987REALLY#$%TRONGpa44w0rd'; 14 | END 15 | 16 | /* 17 | Grant execute permission to created users 18 | */ 19 | GRANT EXECUTE ON SCHEMA::[web] TO [PythonWebApp]; 20 | GO 21 | 22 | /* 23 | Return details on a specific customer 24 | */ 25 | CREATE OR ALTER PROCEDURE web.get_customer 26 | @Json NVARCHAR(MAX) 27 | AS 28 | SET NOCOUNT ON; 29 | DECLARE @CustomerId INT = JSON_VALUE(@Json, '$.CustomerID'); 30 | SELECT 31 | [CustomerID], 32 | [CustomerName], 33 | [PhoneNumber], 34 | [FaxNumber], 35 | [WebsiteURL], 36 | [DeliveryAddressLine1] AS 'Delivery.AddressLine1', 37 | [DeliveryAddressLine2] AS 'Delivery.AddressLine2', 38 | [DeliveryPostalCode] AS 'Delivery.PostalCode' 39 | FROM 40 | [Sales].[Customers] 41 | WHERE 42 | [CustomerID] = @CustomerId 43 | FOR JSON PATH 44 | GO 45 | 46 | /* 47 | Delete a specific customer 48 | */ 49 | CREATE OR ALTER PROCEDURE web.delete_customer 50 | @Json NVARCHAR(MAX) 51 | AS 52 | SET NOCOUNT ON; 53 | DECLARE @CustomerId INT = JSON_VALUE(@Json, '$.CustomerID'); 54 | DELETE FROM [Sales].[Customers] WHERE CustomerId = @CustomerId; 55 | SELECT * FROM (SELECT CustomerID = @CustomerId) D FOR JSON AUTO; 56 | GO 57 | 58 | /* 59 | Update (Patch) a specific customer 60 | */ 61 | CREATE OR ALTER PROCEDURE web.patch_customer 62 | @Json NVARCHAR(MAX) 63 | AS 64 | SET NOCOUNT ON; 65 | DECLARE @CustomerId INT = JSON_VALUE(@Json, '$.CustomerID'); 66 | WITH [source] AS 67 | ( 68 | SELECT * FROM OPENJSON(@Json) WITH ( 69 | [CustomerID] INT, 70 | [CustomerName] NVARCHAR(100), 71 | [PhoneNumber] NVARCHAR(20), 72 | [FaxNumber] NVARCHAR(20), 73 | [WebsiteURL] NVARCHAR(256), 74 | [DeliveryAddressLine1] NVARCHAR(60) '$.Delivery.AddressLine1', 75 | [DeliveryAddressLine2] NVARCHAR(60) '$.Delivery.AddressLine2', 76 | [DeliveryPostalCode] NVARCHAR(10) '$.Delivery.PostalCode' 77 | ) 78 | ) 79 | UPDATE 80 | t 81 | SET 82 | t.[CustomerName] = COALESCE(s.[CustomerName], t.[CustomerName]), 83 | t.[PhoneNumber] = COALESCE(s.[PhoneNumber], t.[PhoneNumber]), 84 | t.[FaxNumber] = COALESCE(s.[FaxNumber], t.[FaxNumber]), 85 | t.[WebsiteURL] = COALESCE(s.[WebsiteURL], t.[WebsiteURL]), 86 | t.[DeliveryAddressLine1] = COALESCE(s.[DeliveryAddressLine1], t.[DeliveryAddressLine1]), 87 | t.[DeliveryAddressLine2] = COALESCE(s.[DeliveryAddressLine2], t.[DeliveryAddressLine2]), 88 | t.[DeliveryPostalCode] = COALESCE(s.[DeliveryPostalCode], t.[DeliveryPostalCode]) 89 | FROM 90 | [Sales].[Customers] t 91 | INNER JOIN 92 | [source] s ON t.[CustomerID] = s.[CustomerID] 93 | WHERE 94 | t.CustomerId = @CustomerId; 95 | 96 | DECLARE @Json2 NVARCHAR(MAX) = N'{"CustomerID": ' + CAST(@CustomerId AS NVARCHAR(9)) + N'}' 97 | EXEC web.get_customer @Json2; 98 | GO 99 | 100 | /* 101 | Create a new customer 102 | */ 103 | 104 | CREATE OR ALTER PROCEDURE web.put_customer 105 | @Json NVARCHAR(MAX) 106 | AS 107 | SET NOCOUNT ON; 108 | DECLARE @CustomerId INT = NEXT VALUE FOR Sequences.CustomerID; 109 | WITH [source] AS 110 | ( 111 | SELECT * FROM OPENJSON(@Json) WITH ( 112 | [CustomerName] NVARCHAR(100), 113 | [PhoneNumber] NVARCHAR(20), 114 | [FaxNumber] NVARCHAR(20), 115 | [WebsiteURL] NVARCHAR(256), 116 | [DeliveryAddressLine1] NVARCHAR(60) '$.Delivery.AddressLine1', 117 | [DeliveryAddressLine2] NVARCHAR(60) '$.Delivery.AddressLine2', 118 | [DeliveryPostalCode] NVARCHAR(10) '$.Delivery.PostalCode' 119 | ) 120 | ) 121 | INSERT INTO [Sales].[Customers] 122 | ( 123 | CustomerID, 124 | CustomerName, 125 | BillToCustomerID, 126 | CustomerCategoryID, 127 | PrimaryContactPersonID, 128 | DeliveryMethodID, 129 | DeliveryCityID, 130 | PostalCityID, 131 | AccountOpenedDate, 132 | StandardDiscountPercentage, 133 | IsStatementSent, 134 | IsOnCreditHold, 135 | PaymentDays, 136 | PhoneNumber, 137 | FaxNumber, 138 | WebsiteURL, 139 | DeliveryAddressLine1, 140 | DeliveryAddressLine2, 141 | DeliveryPostalCode, 142 | PostalAddressLine1, 143 | PostalAddressLine2, 144 | PostalPostalCode, 145 | LastEditedBy 146 | ) 147 | SELECT 148 | @CustomerId, 149 | CustomerName, 150 | @CustomerId, 151 | 5, -- Computer Shop 152 | 1, -- No contact person 153 | 1, -- Post Delivery 154 | 28561, -- Redmond 155 | 28561, -- Redmond 156 | SYSUTCDATETIME(), 157 | 0.00, 158 | 0, 159 | 0, 160 | 30, 161 | PhoneNumber, 162 | FaxNumber, 163 | WebsiteURL, 164 | DeliveryAddressLine1, 165 | DeliveryAddressLine2, 166 | DeliveryPostalCode, 167 | DeliveryAddressLine1, 168 | DeliveryAddressLine2, 169 | DeliveryPostalCode, 170 | 1 171 | FROM 172 | [source] 173 | ; 174 | 175 | DECLARE @Json2 NVARCHAR(MAX) = N'{"CustomerID": ' + CAST(@CustomerId AS NVARCHAR(9)) + N'}' 176 | EXEC web.get_customer @Json2; 177 | GO 178 | 179 | CREATE OR ALTER PROCEDURE web.get_customers 180 | AS 181 | SET NOCOUNT ON; 182 | -- Cast is needed to corretly inform pyodbc of output type is NVARCHAR(MAX) 183 | -- Needed if generated json is bigger then 4000 bytes and thus pyodbc trucates it 184 | -- https://stackoverflow.com/questions/49469301/pyodbc-truncates-the-response-of-a-sql-server-for-json-query 185 | SELECT CAST(( 186 | SELECT 187 | [CustomerID], 188 | [CustomerName] 189 | FROM 190 | [Sales].[Customers] 191 | FOR JSON PATH) AS NVARCHAR(MAX)) AS JsonResult 192 | GO 193 | 194 | --------------------------------------------------------------------------------