├── .gitignore ├── .vs ├── ASDWPrecon │ └── v15 │ │ └── .suo └── slnx.sqlite ├── CodeExamples ├── 001.ServiceArchitecture.MD ├── 002.DesigningTables.md ├── 003.DataLoadingPerformance.md ├── 004.QueryingData.md ├── 005.ExtendingTheDataWarehouse.md └── README.md ├── Demos ├── LongPolybaseLoad.dsql ├── OptimiseMovement.DSQL ├── Partitioning.dsql ├── PerformanceDMVs.DSQL ├── Redistribution.DSQL └── Skew.dsql ├── LICENSE ├── Labs ├── BuildAutomation │ ├── MagicWorks.InitialBuildScript.sql │ ├── MagicWorks.ResetBuildScript.sql │ ├── RunAll.sql │ ├── dbo.Lab002_PopulateFIS.sql │ └── vTableSizes.sql ├── LAB_00 │ ├── CreateANewInstanceOfAzureSQLDataWarehouse.ps1 │ └── README.md ├── LAB_01 │ └── README.md ├── LAB_02 │ ├── README.md │ ├── dbo.Lab002_PopulateFIS.sql │ └── vTableSizes.sql ├── LAB_03 │ └── README.md ├── LAB_04 │ └── README.md ├── LAB_05 │ └── README.md └── LAB_06 │ └── README.md ├── MagicWorks ├── Abracadabra_PersonPerson.sql ├── Abracadabra_Product.sql ├── Abracadabra_ProductCategory.sql ├── Abracadabra_ProductSubCategory.sql ├── AdatisFramework.BuildAnAzureDataWarehouse.ps1 ├── AdatisFramework.Cleardown.sql ├── AdatisFramework.CreateMultipleInstancesOfAzureSQLDW.ps1 ├── AdatisFramework.Metadata.sql ├── BCPTablesFrom SQLToFileOLAP.sql ├── BCPTablesFrom SQLToFileOLTP.sql ├── BCPTablesFrom SQLToFilesql.sql ├── DeploymentTemplates │ ├── AzureSQLDWCreateLoginAgainstAzureSQLDW.txt │ └── AzureSQLDWCreateLoginAgainstMaster.txt ├── MagicWorks.InitialBuildScript.sql ├── MagicWorks_SampleQueries.sql ├── Microsoft.RestoreAzureSQLDataWareouse.ps1 ├── NormalToMagicConversion.xlsx └── Polybase Generation │ ├── AdatisFramewor.DeploySQLToAzureSQLDW.ps1 │ ├── AdatisFramework.GenerateDeploymentSQL.ps1 │ ├── AdatisFramework.GenerateDeplymentSQL.ps1 │ ├── Config.json │ ├── MagicWorksDWMetadata.csv │ ├── MagicWorksMetadata.csv │ ├── SQLToBeDeployed │ ├── AdatisFramework.CombineAllSQLFiles.ps1 │ ├── External.AWBuildVersion.dsql │ ├── External.Address.dsql │ ├── External.AddressType.dsql │ ├── External.AdventureWorksDWBuildVersion.dsql │ ├── External.AuditLog.dsql │ ├── External.BillOfMaterials.dsql │ ├── External.BusinessEntity.dsql │ ├── External.BusinessEntityAddress.dsql │ ├── External.BusinessEntityContact.dsql │ ├── External.ContactType.dsql │ ├── External.CountryRegion.dsql │ ├── External.CountryRegionCurrency.dsql │ ├── External.CreditCard.dsql │ ├── External.Culture.dsql │ ├── External.Currency.dsql │ ├── External.CurrencyRate.dsql │ ├── External.Customer.dsql │ ├── External.DatabaseLog.dsql │ ├── External.Department.dsql │ ├── External.DimAccount.dsql │ ├── External.DimCurrency.dsql │ ├── External.DimCustomer.dsql │ ├── External.DimDate.dsql │ ├── External.DimDepartmentGroup.dsql │ ├── External.DimEmployee.dsql │ ├── External.DimGeography.dsql │ ├── External.DimOrganization.dsql │ ├── External.DimProduct.dsql │ ├── External.DimProductCategory.dsql │ ├── External.DimProductSubcategory.dsql │ ├── External.DimPromotion.dsql │ ├── External.DimReseller.dsql │ ├── External.DimSalesReason.dsql │ ├── External.DimSalesTerritory.dsql │ ├── External.DimScenario.dsql │ ├── External.Document.dsql │ ├── External.EmailAddress.dsql │ ├── External.Employee.dsql │ ├── External.EmployeeDepartmentHistory.dsql │ ├── External.EmployeePayHistory.dsql │ ├── External.ErrorLog.dsql │ ├── External.FactCallCenter.dsql │ ├── External.FactCurrencyRate.dsql │ ├── External.FactFinance.dsql │ ├── External.FactInternetSales.dsql │ ├── External.FactInternetSalesReason.dsql │ ├── External.FactProductInventory.dsql │ ├── External.FactResellerSales.dsql │ ├── External.FactSalesQuota.dsql │ ├── External.FactSurveyResponse.dsql │ ├── External.Illustration.dsql │ ├── External.JobCandidate.dsql │ ├── External.Location.dsql │ ├── External.Password.dsql │ ├── External.Person.dsql │ ├── External.PersonCreditCard.dsql │ ├── External.PersonPhone.dsql │ ├── External.PhoneNumberType.dsql │ ├── External.Product.dsql │ ├── External.ProductCategory.dsql │ ├── External.ProductCostHistory.dsql │ ├── External.ProductDescription.dsql │ ├── External.ProductDocument.dsql │ ├── External.ProductInventory.dsql │ ├── External.ProductListPriceHistory.dsql │ ├── External.ProductModel.dsql │ ├── External.ProductModelIllustration.dsql │ ├── External.ProductPhoto.dsql │ ├── External.ProductProductPhoto.dsql │ ├── External.ProductReview.dsql │ ├── External.ProductSubcategory.dsql │ ├── External.ProductVendor.dsql │ ├── External.ProspectiveBuyer.dsql │ ├── External.PurchaseOrderDetail.dsql │ ├── External.PurchaseOrderHeader.dsql │ ├── External.SalesOrderDetail.dsql │ ├── External.SalesOrderHeader.dsql │ ├── External.SalesOrderHeaderSalesReason.dsql │ ├── External.SalesPerson.dsql │ ├── External.SalesPersonQuotaHistory.dsql │ ├── External.SalesReason.dsql │ ├── External.SalesTaxRate.dsql │ ├── External.SalesTerritory.dsql │ ├── External.SalesTerritoryHistory.dsql │ ├── External.ScrapReason.dsql │ ├── External.Shift.dsql │ ├── External.ShipMethod.dsql │ ├── External.ShoppingCartItem.dsql │ ├── External.SpecialOffer.dsql │ ├── External.SpecialOfferProduct.dsql │ ├── External.StateProvince.dsql │ ├── External.Store.dsql │ ├── External.TransactionHistory.dsql │ ├── External.TransactionHistoryArchive.dsql │ ├── External.UnitMeasure.dsql │ ├── External.Vendor.dsql │ ├── External.WorkOrder.dsql │ ├── External.WorkOrderRouting.dsql │ └── External.sysdiagrams.dsql │ └── Template-ExternalTable.Blob.dsql ├── README.md ├── SQLDW Manager ├── .vs │ └── ADW Manager │ │ └── v15 │ │ └── .suo ├── ADW Manager.sln ├── ADW Manager │ ├── ADW Manager.rptproj │ ├── ADW Manager.rptproj.bak │ ├── ADW Manager.rptproj.rsuser │ ├── ADW.rds │ ├── ActivityMonitor.rdl │ ├── ActivityMonitor.rdl.data │ ├── DWSize.rsd │ ├── DistributionDetails.rdl │ ├── ExecutionExplorer.rdl │ ├── Overview.rdl │ ├── Overview.rdl.data │ ├── PolybaseReader.rdl │ ├── TableDetails.rdl │ ├── TableManager.rdl │ └── subExecutionSteps.rdl └── README.md ├── Slides ├── 000.Intro.pdf ├── 001.Service Architecture.pdf ├── 002.Designing Tables.pdf ├── 003.Data Loading Performance.pdf ├── 004.Querying data.pdf └── 005.Extending the data warehouse.pdf ├── asdwprecon_settings.json └── images ├── ActivityMonitor.png ├── AzureSQLDW.png ├── AzureSQLDW_Config.png ├── AzureSQLDW_Config2.png ├── AzureSQLDW_Config3.png ├── AzureSQLDW_Config4.png ├── Overview Report.png ├── PolybaseLoader.png ├── Table Details.png └── usersanddesks.png /.gitignore: -------------------------------------------------------------------------------- 1 | ################################################################################ 2 | # This .gitignore file was automatically created by Microsoft(R) Visual Studio. 3 | ################################################################################ 4 | 5 | /SQLDW Manager/ADW Manager/bin/Debug 6 | /.vs/VSWorkspaceState.json 7 | /.vs/ProjectSettings.json 8 | -------------------------------------------------------------------------------- /.vs/ASDWPrecon/v15/.suo: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/.vs/ASDWPrecon/v15/.suo -------------------------------------------------------------------------------- /.vs/slnx.sqlite: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/.vs/slnx.sqlite -------------------------------------------------------------------------------- /CodeExamples/001.ServiceArchitecture.MD: -------------------------------------------------------------------------------- 1 | # Examples from Slide Decl 001 2 | 3 | To find all nodes you can run the following TSQL in SSMS. 4 | ```sql 5 | SELECT [pdw_node_id] AS node_id 6 | , [type] AS node_type 7 | , [name] AS node_name 8 | FROM sys.[dm_pdw_nodes] 9 | ; 10 | ``` 11 | 12 | To find all distributions, you can fun the following TSQL in SSMS: 13 | ```sql 14 | SELECT [distribution_id] AS dist_id 15 | , [pdw_node_id] AS node_id 16 | , [name] AS dist_name 17 | , [position] AS dist_position 18 | FROM sys.[pdw_distributions] 19 | ; 20 | ``` 21 | 22 | To check the current service objective, you can run the following TSQL in SSMS: 23 | ```sql 24 | SELECT db.[name] AS [db_name] 25 | , ds.[edition] AS [db_edition] 26 | , ds.[service_objective] AS [db_slo] 27 | FROM sys.[database_service_objectives] AS ds 28 | JOIN sys.[databases] AS db 29 | ON ds.[database_id] = db.[database_id] 30 | WHERE ds.[edition] = 'DataWarehouse' 31 | ; 32 | ``` 33 | 34 | To amend the current Service objective level, you can run the following Powershell in the Powershell ISE 35 | If this is your first time using PowerShell, you may need to run "Set-ExecutionPolicy Unrestricted" and also "Install-Module -Name AzureRM -AllowClobber" 36 | ```powershell 37 | Set-AzureRmSqlDatabase 38 | -DatabaseName “Database" 39 | -ServerName “Server" 40 | -RequestedServiceObjectiveName "DW1000" 41 | ``` 42 | 43 | To suspend Azure SQL Data Warehouse, you can run the following PowerShell in the Powershell ISE. 44 | ```powershell 45 | Suspend-AzureRmSqlDatabase 46 | –ResourceGroupName "ResourceGroup" 47 | –ServerName "Server" 48 | –DatabaseName "Database" 49 | ``` 50 | 51 | To Resume Azure SQL Data Warehouse, you can run the following PowerShell in the Powershell ISE. 52 | ```powershell 53 | Resume-AzureRmSqlDatabase 54 | –ResourceGroupName "ResourceGroup" 55 | –ServerName "Server" 56 | –DatabaseName "Database" 57 | 58 | ``` 59 | 60 | To collect infromation about SnapShots you can run the following TSQL in SSMS: 61 | ```sql 62 | SELECT [run_id] AS bkup_run_id 63 | , [session_id] AS session_id 64 | , [request_id] AS request_id 65 | , [name] AS bkup_name 66 | , [submit_time] AS bkup_submit_time 67 | , [start_time] AS bkup_start_time 68 | , [end_time] AS bkup_end_time 69 | , [total_elapsed_time] AS bkup_duration_ms 70 | , [total_elapsed_time]/1000.0 AS bkup_duration_sec 71 | FROM sys.pdw_loader_backup_runs 72 | ; 73 | ``` 74 | 75 | To create a user in Azure SQL Data Warehouse there are 2 plpaces the users needs to be created. 76 | 1. At the server level 77 | 2. At the database level 78 | 79 | ```sql 80 | -- Pre-req 81 | CREATE USER data_loader FOR LOGIN data_loader 82 | ; 83 | ``` 84 | 85 | ```sql 86 | -- Add user to static rc 87 | EXEC sp_addrolemember 'staticrc40','data_loader' 88 | ; 89 | ``` 90 | 91 | ```sql 92 | -- Remove user from static rc 93 | EXEC sp_droprolemember 'staticrc40','data_loader' 94 | ; 95 | ``` 96 | 97 | That is all the code examples from the first deck. -------------------------------------------------------------------------------- /CodeExamples/002.DesigningTables.md: -------------------------------------------------------------------------------- 1 | Code Examples: 2 | 3 | Create a table with a round-robin distribution 4 | ```sql 5 | CREATE TABLE [dbo].[DimStore] 6 | ( 7 | [StoreKey] int NOT NULL 8 | , [GeographyKey] int NOT NULL 9 | , [StoreName] nvarchar(100) NOT NULL 10 | , [StoreType] nvarchar(15) NULL 11 | , [StoreDescription] nvarchar(300) NOT NULL 12 | , [Status] nvarchar(20) NOT NULL 13 | , [OpenDate] datetime NOT NULL 14 | , [CloseDate] datetime NULL 15 | , [ETLLoadID] int NULL 16 | , [LoadDate] datetime NULL 17 | , [UpdateDate] datetime NULL 18 | ) 19 | WITH 20 | ( CLUSTERED INDEX([StoreKey]) 21 | , DISTRIBUTION = ROUND_ROBIN 22 | ) 23 | ; 24 | ``` 25 | 26 | 27 | ```sql 28 | CREATE TABLE [dbo].[FactOnlineSales] 29 | ( 30 | [OnlineSalesKey] int NOT NULL 31 | , [DateKey] datetime NOT NULL 32 | , [StoreKey] int NOT NULL 33 | , [ProductKey] int NOT NULL 34 | , [PromotionKey] int NOT NULL 35 | , [CurrencyKey] int NOT NULL 36 | , [CustomerKey] int NOT NULL 37 | , [SalesOrderNumber] nvarchar(20) NOT NULL 38 | , [SalesOrderLineNumber] int NULL 39 | , [SalesQuantity] int NOT NULL 40 | , [SalesAmount] money NOT NULL 41 | ) 42 | WITH 43 | ( CLUSTERED COLUMNSTORE INDEX 44 | , DISTRIBUTION = HASH([ProductKey]) 45 | ) 46 | ; 47 | 48 | ``` 49 | 50 | ```sql 51 | DBCC PDW_SHOWSPACEUSED 52 | ``` 53 | 54 | ```sql 55 | SELECT * FROM sys.dm_pdw_nodes_db_partition_stats 56 | ``` 57 | 58 | ```sql 59 | SELECT [distribution_id] 60 | , SUM([row_count]) AS [total_distribution_row_count] 61 | FROM [dbo].[vTableSizes] 62 | WHERE [schema_name] = 'Fact' 63 | AND [table_name] = 'Flights' 64 | GROUP BY [distribution_id] 65 | ORDER BY [total_distribution_row_count] 66 | ; 67 | ``` 68 | 69 | In the slides this is REPLICATED, this is a typo. 70 | ```sql 71 | CREATE TABLE dbo.DimCustomer 72 | ( CustomerKey int NOT NULL 73 | , GeographyKey int NULL 74 | , CustomerAlternateKey nvarchar(15) NOT NULL 75 | , Title nvarchar(8) NULL 76 | , FirstName nvarchar(50) NULL 77 | , LastName nvarchar(50) NULL 78 | , BirthDate date NULL 79 | , Gender nvarchar(1) NULL 80 | , EmailAddress nvarchar(50) NULL 81 | , YearlyIncome money NULL 82 | , DateFirstPurchase date NULL 83 | ) 84 | WITH 85 | ( CLUSTERED COLUMNSTORE INDEX 86 | , DISTRIBUTION = REPLICATE 87 | ) 88 | ; 89 | 90 | ``` 91 | 92 | ```sql 93 | SELECT t.[name] AS Table_Name 94 | , c.[state] AS Cache_State 95 | , p.[distribution_policy_desc] AS Dist_Type 96 | FROM sys.[tables] AS t 97 | JOIN sys.[pdw_replicated_table_cache_state] AS c 98 | ON c.[object_id] = t.[object_id] 99 | JOIN sys.pdw_table_distribution_properties AS p 100 | ON p.[object_id] = t.[object_id] 101 | ; 102 | ``` 103 | 104 | ```sql 105 | 106 | 107 | CREATE EXTERNAL DATA SOURCE WASBStor 108 | WITH (TYPE = Hadoop, 109 | LOCATION = 'wasbs://@.blob.core.windows.net', 110 | Credential = ) 111 | ; 112 | CREATE EXTERNAL FILE FORMAT TextFile 113 | WITH ( FORMAT_TYPE = DELIMITEDTEXT, 114 | DATA_COMPRESSION = 'org.apache.hadoop.io.compress.GzipCodec', 115 | FORMAT_OPTIONS (FIELD_TERMINATOR ='|', USE_TYPE_DEFAULT = TRUE) 116 | ) 117 | ; 118 | 119 | CREATE EXTERNAL TABLE [dbo].[Customer_import] ( 120 | [SensorKey] int NOT NULL, 121 | [CustomerKey] int NOT NULL, 122 | [Speed] float NOT NULL 123 | ) 124 | WITH (LOCATION='/Dimensions/customer', 125 | DATA_SOURCE = WASBStor, 126 | FILE_FORMAT = TextFile 127 | ) 128 | ; 129 | 130 | 131 | 132 | CREATE TABLE [dbo].[Customer] 133 | WITH 134 | ( Distribution = ROUND_ROBIN 135 | , Clustered Index (customerid) 136 | ) 137 | AS 138 | SELECT * FROM [dbo].[Customer_import] 139 | 140 | 141 | INSERT INTO [dbo].[Customer] 142 | SELECT * FROM [dbo].[Customer_import] 143 | 144 | ``` 145 | 146 | ```sql 147 | 148 | ``` 149 | 150 | ```sql 151 | 152 | ``` -------------------------------------------------------------------------------- /CodeExamples/003.DataLoadingPerformance.md: -------------------------------------------------------------------------------- 1 | Code examples from deck 003. 2 | 3 | Using the IDENTITY property 4 | ```sql 5 | CREATE TABLE dbo.Dim1 6 | (C1 INT IDENTITY(1,1) 7 | ,C2 INT 8 | ) 9 | WITH 10 | (DISTRIBUTION = HASH(C2) 11 | ,CLUSTERED COLUMNSTORE INDEX 12 | ) 13 | ; 14 | ``` 15 | 16 | Data vault key: Use HASHBYTES 17 | ```sql 18 | DECLARE @i VARCHAR(8000) = REPLICATE('X',8000) 19 |   20 | SELECT LOWER(CONVERT(CHAR(32),HASHBYTES('MD5',@i),2)) 21 | ; 22 | SELECT 23 | LOWER(CONVERT(BIGINT,HASHBYTES('MD5',@i),2)) 24 | ; 25 | ``` 26 | 27 | CREATE TABLE with partitions 28 | ```sql 29 | CREATE TABLE [dbo].[FactOnlineSales_PTN] 30 | ( [OnlineSalesKey] int NOT NULL 31 | , [DateKey] datetime NOT NULL 32 | , [StoreKey] int NOT NULL 33 | , [ProductKey] int NOT NULL 34 | , [CurrencyKey] int NOT NULL 35 | , [SalesQuantity] int NOT NULL 36 | , [SalesAmount] money NOT NULL 37 | , [UnitPrice] money NULL 38 | ) 39 | WITH 40 | ( CLUSTERED COLUMNSTORE INDEX 41 | , DISTRIBUTION = HASH([ProductKey]) 42 | , PARTITION 43 | ( 44 | [DateKey] RANGE RIGHT FOR VALUES 45 | ( 46 | '2007-01-01 00:00:00.000','2008-01-01 00:00:00.000' 47 | , '2009-01-01 00:00:00.000','2010-01-01 00:00:00.000' 48 | ) 49 | ) 50 | ) 51 | ; 52 | ``` 53 | 54 | Creating a partitioned table with CTAS 55 | ```sql 56 | CREATE TABLE [dbo].FactOnlineSales_PTN 57 | WITH 58 | ( CLUSTERED COLUMNSTORE INDEX 59 | , DISTRIBUTION = HASH([ProductKey]) 60 | , PARTITION 61 | ( 62 | [DateKey] RANGE RIGHT FOR VALUES 63 | ( 64 | '2007-01-01 00:00:00.000','2008-01-01 00:00:00.000' 65 | , '2009-01-01 00:00:00.000','2010-01-01 00:00:00.000' 66 | ) 67 | ) 68 | ) 69 | AS 70 | SELECT * 71 | FROM [dbo].[FactOnlineSales] 72 | ; 73 | ``` 74 | 75 | Create a numbers table using the Itzik method. This is a 0 IO operation! It is pretty sweet. 76 | ```sql 77 | CREATE TABLE #Nums 78 | WITH (DISTRIBUTION=REPLICATE,LOCATION=USER_DB) 79 | AS 80 | WITH L0 AS (SELECT 1 AS c UNION ALL SELECT 1) 81 | , L1 AS (SELECT 1 AS c FROM L0 AS A, L0 AS B) 82 | , L2 AS (SELECT 1 AS c FROM L1 AS A, L1 AS B) 83 | , L3 AS (SELECT 1 AS c FROM L2 AS A, L2 AS B) 84 | , L4 AS (SELECT 1 AS c FROM L3 AS A, L3 AS B) 85 | , L5 AS (SELECT 1 AS c FROM L4 AS A, L4 AS B) 86 | , Nums AS (SELECT ROW_NUMBER() OVER(ORDER BY c) AS n FROM L5) 87 | SELECT CAST(n AS BIGINT) as Number 88 | FROM Nums 89 | WHERE n BETWEEN @num_Start AND @num_End 90 | OPTION (LABEL='fn_nums : #nums create') 91 | ; 92 | ``` 93 | 94 | UPSERTing data with CTAS 95 | ```sql 96 | CREATE TABLE [tmp].[DimProduct] 97 | WITH (DISTRIBUTION = ROUND_ROBIN) 98 | AS -- New rows and new versions of rows 99 | SELECT s.[ProductKey] 100 | , s.[ProductName] 101 | , s.[ColorName] 102 | FROM [src].[DimProduct] s 103 | UNION ALL --Keep rows that are not being updated 104 | SELECT p.[ProductKey] 105 | , p.[ProductName] 106 | , p.[ColorName] 107 | FROM [dbo].[DimProduct] p 108 | WHERE NOT EXISTS 109 | ( SELECT * 110 | FROM [src].[DimProduct] s 111 | WHERE s.[ProductKey] = p.[ProductKey] 112 | ) 113 | ; 114 | ``` 115 | 116 | CTAS – Create partition for switch out 117 | ```sql 118 | CREATE TABLE [dbo].[FactOnlineSales_out] 119 | WITH 120 | ( DISTRIBUTION=HASH ([ProductKey]) 121 | , CLUSTERED COLUMNSTORE INDEX 122 | , PARTITION ([DateKey] 123 | RANGE RIGHT FOR VALUES ('2007-01-01 00:00:00.000' 124 | ,'2008-01-01 00:00:00.000' 125 | ) 126 | ) 127 | ) 128 | AS 129 | SELECT * 130 | FROM [dbo].[FactOnlineSales] 131 | WHERE 1=2; 132 | ``` 133 | 134 | CTAS – Create Partition for Switch In 135 | ```sql 136 | CREATE TABLE [dbo].[FactOnlineSales_in] 137 | WITH 138 | ( DISTRIBUTION=HASH ([ProductKey]) 139 | , CLUSTERED COLUMNSTORE INDEX 140 | , PARTITION ([DateKey] 141 | RANGE RIGHT FOR VALUES ('2007-01-01 00:00:00.000','2008-01-01 00:00:00.000' 142 | ) 143 | ) 144 | ) 145 | AS 146 | SELECT * 147 | FROM [dbo].[FactOnlineSales_ptn] tgt 148 | WHERE tgt.[DateKey] >= '2007-01-01 00:00:00.000' 149 | AND tgt.[DateKey] < '2008-01-01 00:00:00.000' 150 | UNION ALL 151 | SELECT * 152 | FROM [dbo].[FactOnlineSales] stg 153 | WHERE stg.[DateKey] >= '2007-01-01 00:00:00.000' 154 | AND stg.[DateKey] < '2008-01-01 00:00:00.000' 155 | ; 156 | 157 | ``` 158 | 159 | Perform the switches 160 | ```sql 161 | ALTER TABLE [dbo].[FactOnlineSales_ptn] 162 | SWITCH PARTITION 2 163 | TO [dbo].[FactOnlineSales_out] PARTITION 2 164 | ; 165 | ALTER TABLE [dbo].[FactOnlineSales_in] 166 | SWITCH PARTITION 2 167 | TO [dbo].[FactOnlineSales_ptn] PARTITION 2 168 | ; 169 | 170 | ``` 171 | 172 | Upsert Logic – CTAS optimised 173 | ```sql 174 | CREATE TABLE tmp.DimProduct 175 | WITH (DISTRIBUTION = ROUND_ROBIN) 176 | AS -- New rows and new versions of rows 177 | SELECT s.ProductKey 178 | , s.ProductName 179 | , s.ColorName 180 | FROM [src].[DimProduct] s 181 | WHERE s.Operation IN ('I','U') 182 | UNION ALL --Keep rows that are not being updated 183 | SELECT p.ProductKey 184 | , p.ProductName 185 | , p.ColorName 186 | FROM [dbo].[DimProduct] p 187 | WHERE NOT EXISTS 188 | ( SELECT * 189 | FROM [src].[DimProduct] s 190 | WHERE s.ProductKey = p.ProductKey 191 | ); 192 | 193 | ``` 194 | 195 | -------------------------------------------------------------------------------- /CodeExamples/004.QueryingData.md: -------------------------------------------------------------------------------- 1 | Examples from deck 004. 2 | 3 | Examples of aggregation compatibility 4 | ```sql 5 | -- FactInternetSales distributed on ProductKey 6 | SELECT COUNT_BIG(*) 7 | FROM [ext].[FactResellerSales] 8 | GROUP BY [ProductKey] 9 | ; 10 | SELECT COUNT_BIG(DISTINCT ([ProductKey])) 11 | FROM [ext].[FactResellerSales] 12 | ; 13 | 14 | ``` 15 | 16 | Examples of aggregation incompatibility 17 | ```sql 18 | -- FactInternetSales distributed on ProductKey 19 | SELECT COUNT_BIG(*) 20 | FROM [ext].[FactResellerSales] 21 | GROUP BY [StoreKey] 22 | ; 23 | SELECT COUNT_BIG(DISTINCT [DateKey]) 24 | FROM [ext].[FactResellerSales] 25 | ; 26 | 27 | ``` 28 | 29 | Re-distribution example 30 | ```sql 31 | --EXPLAIN 32 | CREATE TABLE [dbo].[DimEmployee] 33 | WITH (DISTRIBUTION = Hash(EmployeeKey)) 34 | AS 35 | SELECT * 36 | FROM [ext].[DimEmployee] 37 | OPTION (LABEL = 'CTAS : Redistribution') 38 | ; 39 | ``` 40 | 41 | COUNT DISTINCT examples 42 | ```sql 43 | --EXPLAIN 44 | SELECT COUNT_BIG(DISTINCT [DateKey]) 45 | FROM [ext].[FactInternetSales] 46 | OPTION (LABEL = 'COUNT DISTINCT incompatible dist key') 47 | ; 48 | --EXPLAIN 49 | SELECT COUNT_BIG(DISTINCT ([ProductKey])) 50 | FROM [ext].[FactInternetSales] 51 | OPTION (LABEL = 'COUNT DISTINCT compatible dist key') 52 | ; 53 | 54 | ``` 55 | 56 | OVER() examples 57 | ```sql 58 | --EXPLAIN 59 | SELECT SUM([SalesAmount]) OVER(PARTITION BY [DateKey]) 60 | FROM [ext].[FactInternetSales] 61 | OPTION (LABEL = 'OVER() incompatible dist key') 62 | ; 63 | --EXPLAIN 64 | SELECT SUM([SalesAmount]) OVER(ORDER BY [ProductKey]) 65 | FROM [dbo].[FactInternetSales] 66 | OPTION (LABEL = 'OVER() incompatible no partition key') 67 | ; 68 | --EXPLAIN 69 | SELECT SUM([SalesAmount]) OVER(PARTITION BY [ProductKey]) 70 | FROM [dbo].[FactInternetSales] 71 | OPTION (LABEL = 'OVER() compatible dist key') 72 | ; 73 | 74 | ``` 75 | 76 | -------------------------------------------------------------------------------- /CodeExamples/005.ExtendingTheDataWarehouse.md: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/CodeExamples/005.ExtendingTheDataWarehouse.md -------------------------------------------------------------------------------- /CodeExamples/README.md: -------------------------------------------------------------------------------- 1 | # Code examples 2 | There are a lot of code examples in the slides. To save you copying this from the slides, we have included all the code here. 3 | 4 | - [001 - Service Architecture](https://github.com/SQLShark/ASDWPrecon/blob/master/CodeExamples/001.ServiceArchitecture.MD) 5 | - [002 - Designing Tables](https://github.com/SQLShark/ASDWPrecon/blob/master/CodeExamples/002.DesigningTables.md) 6 | - [003 - Data Loading Performance](https://github.com/SQLShark/ASDWPrecon/blob/master/CodeExamples/003.DataLoadingPerformance.md) 7 | - [004 - Querying Data](https://github.com/SQLShark/ASDWPrecon/blob/master/CodeExamples/004.QueryingData.md) 8 | - [005 - Extending the data warehouse and patterns](https://github.com/SQLShark/ASDWPrecon/blob/master/CodeExamples/005.ExtendingTheDataWarehouse.md) 9 | 10 | Feel free to follow along. -------------------------------------------------------------------------------- /Demos/LongPolybaseLoad.dsql: -------------------------------------------------------------------------------- 1 | SELECT count(*) FROM [ext].[FactProductInventory] 2 | UNION 3 | SELECT count(*) FROM [ext].[FactProductInventory] 4 | UNION 5 | SELECT count(*) FROM [ext].[FactProductInventory] 6 | UNION 7 | SELECT count(*) FROM [ext].[FactProductInventory] 8 | UNION 9 | SELECT count(*) FROM [ext].[FactProductInventory] 10 | UNION 11 | SELECT count(*) FROM [ext].[FactProductInventory] 12 | UNION 13 | SELECT count(*) FROM [ext].[FactProductInventory] 14 | UNION 15 | SELECT count(*) FROM [ext].[FactProductInventory] 16 | UNION 17 | SELECT count(*) FROM [ext].[FactProductInventory] 18 | UNION 19 | SELECT count(*) FROM [ext].[FactProductInventory] 20 | UNION 21 | SELECT count(*) FROM [ext].[FactProductInventory] 22 | UNION 23 | SELECT count(*) FROM [ext].[FactProductInventory] 24 | -------------------------------------------------------------------------------- /Demos/OptimiseMovement.DSQL: -------------------------------------------------------------------------------- 1 | 2 | --Clean up from previous demo 3 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='SalesOrderHeader') 4 | BEGIN 5 | DROP TABLE dbo.SalesOrderHeader 6 | END 7 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='Customer') 8 | BEGIN 9 | DROP TABLE dbo.Customer 10 | END 11 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='SalesOrderDetail') 12 | BEGIN 13 | DROP TABLE dbo.SalesOrderDetail 14 | END 15 | 16 | 17 | --Bring Data in from external tables 18 | CREATE TABLE dbo.SalesOrderHeader 19 | WITH 20 | ( 21 | CLUSTERED COLUMNSTORE INDEX, 22 | DISTRIBUTION = HASH(SalesOrderID) 23 | ) 24 | AS 25 | SELECT * 26 | FROM [ext].SalesOrderHeader 27 | 28 | CREATE TABLE dbo.Customer 29 | WITH 30 | ( 31 | CLUSTERED COLUMNSTORE INDEX, 32 | DISTRIBUTION = HASH(CustomerID) 33 | ) 34 | AS 35 | SELECT * 36 | FROM [ext].Customer 37 | 38 | CREATE TABLE dbo.SalesOrderDetail 39 | WITH 40 | ( 41 | CLUSTERED COLUMNSTORE INDEX, 42 | DISTRIBUTION = HASH(SalesOrderID) 43 | ) 44 | AS 45 | SELECT * 46 | FROM [ext].SalesOrderDetail 47 | 48 | 49 | --Query to Review 50 | EXPLAIN 51 | SELECT 52 | C.[CustomerID], 53 | SUM(CAST([LineTotal] as money)) TotalSales 54 | FROM 55 | dbo.Customer C 56 | INNER JOIN dbo.SalesOrderHeader SOH ON C.CustomerID = SOH.CustomerID 57 | INNER JOIN dbo.SalesOrderDetail SOD ON SOH.SalesOrderID = SOD.SalesOrderID 58 | GROUP BY C.[CustomerID] 59 | OPTION (LABEL = 'This is the query we are interested in') 60 | -------------------------------------------------------------------------------- /Demos/Partitioning.dsql: -------------------------------------------------------------------------------- 1 | --Clean up from previous demo runs 2 | DROP TABLE dbo.FactInternetSales_Part 3 | DROP TABLE dbo.FactInternetSales_P20040101 4 | 5 | --Create copy of table to perform upsert on 6 | CREATE TABLE [dbo].[FactInternetSales_Part] 7 | WITH 8 | ( 9 | DISTRIBUTION = HASH ( [ProductKey] ), 10 | CLUSTERED COLUMNSTORE INDEX, 11 | PARTITION 12 | ( 13 | [OrderDateKey] RANGE RIGHT FOR VALUES (20000101, 20010101, 20020101, 20030101, 20040101, 20050101, 20060101, 20070101, 20080101, 20090101, 20100101, 20110101, 20120101, 20130101, 20140101, 20150101, 20160101, 20170101, 20180101, 20190101, 20200101, 20210101, 20220101, 20230101, 20240101, 20250101, 20260101, 20270101, 20280101, 20290101) 14 | ) 15 | ) 16 | AS 17 | SELECT * FROM dbo.FactInternetSales 18 | 19 | --Create delta records table with amended values 20 | CREATE TABLE dbo.FactInternetSales_P20040101 21 | WITH 22 | ( 23 | DISTRIBUTION = HASH ( [ProductKey] ), 24 | CLUSTERED COLUMNSTORE INDEX, 25 | PARTITION 26 | ( 27 | [OrderDateKey] RANGE RIGHT FOR VALUES (20030101, 20040101, 20050101) 28 | ) 29 | ) 30 | AS 31 | SELECT 32 | [ProductKey], 33 | [OrderDateKey], 34 | [DueDateKey], 35 | [ShipDateKey], 36 | [CustomerKey], 37 | [PromotionKey], 38 | [CurrencyKey], 39 | [SalesTerritoryKey], 40 | [SalesOrderNumber], 41 | [SalesOrderLineNumber], 42 | [RevisionNumber], 43 | [OrderQuantity], 44 | [UnitPrice], 45 | [ExtendedAmount], 46 | [UnitPriceDiscountPct], 47 | [DiscountAmount], 48 | [ProductStandardCost], 49 | [TotalProductCost], 50 | ISNULL(CAST([SalesAmount] * 20.4 AS MONEY),0) [SalesAmount], 51 | [TaxAmt], 52 | [Freight], 53 | [CarrierTrackingNumber], 54 | [CustomerPONumber] 55 | FROM [dbo].[FactInternetSales] 56 | WHERE OrderDateKey > 20040101 AND OrderDateKey < 20050101 57 | 58 | --Check current row counts for Target table 59 | SELECT LEFT(OrderDateKey,4), 60 | SUM(SalesAmount) 61 | FROM dbo.FactInternetSales_Part 62 | GROUP BY LEFT(OrderDateKey,4) 63 | 64 | --Check current row counts for Delta table 65 | SELECT LEFT(OrderDateKey,4), 66 | SUM(SalesAmount) 67 | FROM dbo.FactInternetSales_P20040101 68 | GROUP BY LEFT(OrderDateKey,4) 69 | 70 | --Perform table switch in, with TRUNCATE_TARGET switch 71 | ALTER TABLE [dbo].FactInternetSales_P20040101 72 | SWITCH PARTITION 3 73 | TO [dbo].[FactInternetSales_Part] PARTITION 6 WITH (TRUNCATE_TARGET = ON) 74 | 75 | 76 | --Check current row counts for Target table 77 | SELECT LEFT(OrderDateKey,4), 78 | SUM(SalesAmount) 79 | FROM dbo.FactInternetSales_Part 80 | GROUP BY LEFT(OrderDateKey,4) 81 | 82 | --Check current row counts for Delta table 83 | SELECT LEFT(OrderDateKey,4), 84 | SUM(SalesAmount) 85 | FROM dbo.FactInternetSales_P20040101 86 | GROUP BY LEFT(OrderDateKey,4) 87 | 88 | 89 | select * from sys.partition_range_values -------------------------------------------------------------------------------- /Demos/PerformanceDMVs.DSQL: -------------------------------------------------------------------------------- 1 | 2 | --Clean up from previous demo 3 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='SalesOrderHeader') 4 | BEGIN 5 | DROP TABLE dbo.SalesOrderHeader 6 | END 7 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='Customer') 8 | BEGIN 9 | DROP TABLE dbo.Customer 10 | END 11 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='SalesOrderDetail') 12 | BEGIN 13 | DROP TABLE dbo.SalesOrderDetail 14 | END 15 | 16 | 17 | --Bring Data in from external tables 18 | CREATE TABLE dbo.SalesOrderHeader 19 | WITH 20 | ( 21 | CLUSTERED COLUMNSTORE INDEX, 22 | DISTRIBUTION = ROUND_ROBIN 23 | ) 24 | AS 25 | SELECT * 26 | FROM [ext].SalesOrderHeader 27 | 28 | CREATE TABLE dbo.Customer 29 | WITH 30 | ( 31 | CLUSTERED COLUMNSTORE INDEX, 32 | DISTRIBUTION = ROUND_ROBIN 33 | ) 34 | AS 35 | SELECT * 36 | FROM [ext].Customer 37 | 38 | CREATE TABLE dbo.SalesOrderDetail 39 | WITH 40 | ( 41 | CLUSTERED COLUMNSTORE INDEX, 42 | DISTRIBUTION = ROUND_ROBIN 43 | ) 44 | AS 45 | SELECT * 46 | FROM [ext].SalesOrderDetail 47 | 48 | 49 | --Query to Review 50 | EXPLAIN 51 | SELECT 52 | C.[CustomerID], 53 | SUM(CAST([LineTotal] as money)) TotalSales 54 | FROM 55 | dbo.Customer C 56 | INNER JOIN dbo.SalesOrderHeader SOH ON C.CustomerID = SOH.CustomerID 57 | INNER JOIN dbo.SalesOrderDetail SOD ON SOH.SalesOrderID = SOD.SalesOrderID 58 | GROUP BY C.[CustomerID] 59 | OPTION (LABEL = 'This is the query we are interested in') 60 | 61 | --Performance DMVs 62 | SELECT * 63 | FROM sys.dm_pdw_exec_requests 64 | 65 | SELECT * 66 | FROM sys.dm_pdw_request_steps 67 | WHERE request_id = 68 | 69 | SELECT * 70 | FROM sys.dm_pdw_sql_requests 71 | WHERE request_id = AND step_index = 72 | -------------------------------------------------------------------------------- /Demos/Redistribution.DSQL: -------------------------------------------------------------------------------- 1 | --Clean up from previous demo 2 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='FactInternetSales') 3 | BEGIN 4 | DROP TABLE dbo.FactInternetSales 5 | END 6 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='FactInternetSalesPH') 7 | BEGIN 8 | DROP TABLE dbo.FactInternetSalesPH 9 | END 10 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='FactInternetSalesPH_Bad') 11 | BEGIN 12 | DROP TABLE dbo.FactInternetSalesPH_Bad 13 | END 14 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='FactInternetSalesREP') 15 | BEGIN 16 | DROP TABLE dbo.FactInternetSalesREP 17 | END 18 | IF EXISTS (SELECT * FROM SYSOBJECTS WHERE NAME='FactInternetSalesRR') 19 | BEGIN 20 | DROP TABLE dbo.FactInternetSalesRR 21 | END 22 | 23 | --Bring Data in from external tables 24 | CREATE TABLE dbo.FactInternetSales 25 | WITH 26 | ( 27 | CLUSTERED COLUMNSTORE INDEX, 28 | DISTRIBUTION = ROUND_ROBIN 29 | ) 30 | AS 31 | SELECT * 32 | FROM [ext].[FactInternetSales] 33 | 34 | 35 | 36 | --Create Hash Distributed table on Product Key 37 | CREATE TABLE dbo.FactInternetSalesPH 38 | WITH 39 | ( 40 | CLUSTERED COLUMNSTORE INDEX, 41 | DISTRIBUTION = HASH(ProductKey) 42 | ) 43 | AS 44 | SELECT * 45 | FROM [dbo].[FactInternetSales] 46 | 47 | 48 | --Create Hash Distributed table on CurrencyKey 49 | CREATE TABLE dbo.FactInternetSalesPH_Bad 50 | WITH 51 | ( 52 | CLUSTERED COLUMNSTORE INDEX, 53 | DISTRIBUTION = HASH(CurrencyKey) 54 | ) 55 | AS 56 | SELECT * 57 | FROM [dbo].[FactInternetSales] 58 | 59 | --Create Replicated Table 60 | CREATE TABLE dbo.FactInternetSalesREP 61 | WITH 62 | ( 63 | CLUSTERED COLUMNSTORE INDEX, 64 | DISTRIBUTION = REPLICATE 65 | ) 66 | AS 67 | SELECT * 68 | FROM [dbo].[FactInternetSales] 69 | 70 | --Example of renaming switcheroo 71 | RENAME OBJECT [dbo].[FactInternetSales] to [FactInternetSalesRR] 72 | RENAME OBJECT [dbo].[FactInternetSalesPH] to [FactInternetSales] 73 | -------------------------------------------------------------------------------- /Demos/Skew.dsql: -------------------------------------------------------------------------------- 1 | --Return distribution usage 2 | DBCC PDW_SHOWSPACEUSED 3 | 4 | --Return ALL table across ALL distributions 5 | SELECT 6 | ps.pdw_node_id 7 | , ps.distribution_id 8 | , ps.object_id AS 'physical_object_id' 9 | , ps.index_id 10 | , ps.partition_number 11 | , ps.row_count 12 | , ps.used_page_count 13 | FROM 14 | sys.dm_pdw_nodes_db_partition_stats AS ps; 15 | 16 | --Formatted view, good for exploring distribution skew 17 | SELECT * 18 | FROM [dbo].[vTableSizes] 19 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Terry McCann 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 | -------------------------------------------------------------------------------- /Labs/BuildAutomation/MagicWorks.InitialBuildScript.sql: -------------------------------------------------------------------------------- 1 | -- ####################################################################################################################################### 2 | -- Create a Master Key 3 | -- ####################################################################################################################################### 4 | BEGIN TRY 5 | CREATE MASTER KEY; 6 | END TRY 7 | BEGIN CATCH 8 | PRINT 'No Need' 9 | END CATCH; 10 | GO 11 | 12 | -- ####################################################################################################################################### 13 | -- Create a Scoped Credential 14 | -- ####################################################################################################################################### 15 | BEGIN TRY 16 | CREATE DATABASE SCOPED CREDENTIAL AzureStorageCredential 17 | WITH 18 | IDENTITY = 'user', 19 | SECRET = 'WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA==' 20 | END TRY 21 | BEGIN CATCH 22 | PRINT 'No Need' 23 | END CATCH; 24 | GO 25 | 26 | -- ####################################################################################################################################### 27 | --Create a File format 28 | -- ####################################################################################################################################### 29 | 30 | BEGIN TRY 31 | DROP EXTERNAL FILE FORMAT TextFile 32 | END TRY 33 | BEGIN CATCH 34 | PRINT 'No Need' 35 | END CATCH; 36 | GO 37 | 38 | BEGIN TRY 39 | CREATE EXTERNAL FILE FORMAT TextFile 40 | WITH ( 41 | FORMAT_TYPE = DelimitedText, 42 | FORMAT_OPTIONS (FIELD_TERMINATOR = ',', STRING_DELIMITER= '"') 43 | ) 44 | END TRY 45 | BEGIN CATCH 46 | PRINT 'No Need' 47 | END CATCH; 48 | GO 49 | 50 | 51 | -- ####################################################################################################################################### 52 | -- Create a schema 53 | -- ####################################################################################################################################### 54 | 55 | IF (NOT EXISTS (SELECT * FROM sys.schemas WHERE name = 'ext')) 56 | BEGIN 57 | EXEC ('CREATE SCHEMA [ext] AUTHORIZATION [dbo]') 58 | END 59 | 60 | IF (NOT EXISTS (SELECT * FROM sys.schemas WHERE name = 'oltp')) 61 | BEGIN 62 | EXEC ('CREATE SCHEMA [oltp] AUTHORIZATION [dbo]') 63 | END 64 | 65 | IF (NOT EXISTS (SELECT * FROM sys.schemas WHERE name = 'olap')) 66 | BEGIN 67 | EXEC ('CREATE SCHEMA [olap] AUTHORIZATION [dbo]') 68 | END -------------------------------------------------------------------------------- /Labs/BuildAutomation/MagicWorks.ResetBuildScript.sql: -------------------------------------------------------------------------------- 1 | -- ####################################################################################################################################### 2 | --Create a File format 3 | -- ####################################################################################################################################### 4 | 5 | BEGIN TRY 6 | DROP PROCEDURE dbo.ResetBuildScript 7 | END TRY 8 | BEGIN CATCH 9 | PRINT 'No Need' 10 | END CATCH; 11 | GO 12 | 13 | CREATE PROCEDURE dbo.ResetBuildScript AS 14 | BEGIN 15 | 16 | BEGIN TRY DROP EXTERNAL TABLE [ext].[PersonPhone] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 17 | BEGIN TRY DROP EXTERNAL TABLE [ext].[PhoneNumberType] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 18 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Product] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 19 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductCategory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 20 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductCostHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 21 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductDescription] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 22 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductDocument] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 23 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductInventory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 24 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductListPriceHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 25 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductModel] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 26 | BEGIN TRY DROP EXTERNAL TABLE [ext].[CountryRegionCurrency] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 27 | BEGIN TRY DROP EXTERNAL TABLE [ext].[CreditCard] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 28 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Culture] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 29 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Currency] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 30 | BEGIN TRY DROP EXTERNAL TABLE [ext].[CurrencyRate] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 31 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Customer] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 32 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DatabaseLog] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 33 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Department] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 34 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimAccount] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 35 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimCurrency] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 36 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimCustomer] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 37 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimDepartmentGroup] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 38 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimEmployee] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 39 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimGeography] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 40 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimOrganization] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 41 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimProductCategory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 42 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimProductSubcategory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 43 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimPromotion] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 44 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimReseller] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 45 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimSalesReason] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 46 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimSalesTerritory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 47 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimScenario] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 48 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Document] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 49 | BEGIN TRY DROP EXTERNAL TABLE [ext].[EmailAddress] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 50 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Employee] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 51 | BEGIN TRY DROP EXTERNAL TABLE [ext].[EmployeeDepartmentHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 52 | BEGIN TRY DROP EXTERNAL TABLE [ext].[EmployeePayHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 53 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ErrorLog] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 54 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactCallCenter] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 55 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactCurrencyRate] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 56 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactFinance] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 57 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactInternetSales] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 58 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactInternetSalesReason] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 59 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactProductInventory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 60 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactResellerSales] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 61 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactSalesQuota] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 62 | BEGIN TRY DROP EXTERNAL TABLE [ext].[FactSurveyResponse] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 63 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Illustration] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 64 | BEGIN TRY DROP EXTERNAL TABLE [ext].[JobCandidate] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 65 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Location] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 66 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Password] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 67 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Person] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 68 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductModelIllustration] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 69 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductPhoto] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 70 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductProductPhoto] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 71 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductReview] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 72 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductSubcategory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 73 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProductVendor] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 74 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ProspectiveBuyer] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 75 | BEGIN TRY DROP EXTERNAL TABLE [ext].[PurchaseOrderDetail] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 76 | BEGIN TRY DROP EXTERNAL TABLE [ext].[PurchaseOrderHeader] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 77 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesOrderDetail] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 78 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesOrderHeader] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 79 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesOrderHeaderSalesReason] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 80 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesPerson] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 81 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Address] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 82 | BEGIN TRY DROP EXTERNAL TABLE [ext].[AddressType] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 83 | BEGIN TRY DROP EXTERNAL TABLE [ext].[AdventureWorksDWBuildVersion] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 84 | BEGIN TRY DROP EXTERNAL TABLE [ext].[AuditLog] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 85 | BEGIN TRY DROP EXTERNAL TABLE [ext].[AWBuildVersion] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 86 | BEGIN TRY DROP EXTERNAL TABLE [ext].[BillOfMaterials] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 87 | BEGIN TRY DROP EXTERNAL TABLE [ext].[BusinessEntity] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 88 | BEGIN TRY DROP EXTERNAL TABLE [ext].[BusinessEntityAddress] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 89 | BEGIN TRY DROP EXTERNAL TABLE [ext].[BusinessEntityContact] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 90 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ContactType] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 91 | BEGIN TRY DROP EXTERNAL TABLE [ext].[CountryRegion] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 92 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesPersonQuotaHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 93 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesReason] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 94 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesTaxRate] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 95 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesTerritory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 96 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SalesTerritoryHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 97 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ScrapReason] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 98 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Shift] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 99 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ShipMethod] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 100 | BEGIN TRY DROP EXTERNAL TABLE [ext].[ShoppingCartItem] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 101 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SpecialOffer] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 102 | BEGIN TRY DROP EXTERNAL TABLE [ext].[SpecialOfferProduct] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 103 | BEGIN TRY DROP EXTERNAL TABLE [ext].[StateProvince] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 104 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Store] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 105 | BEGIN TRY DROP EXTERNAL TABLE [ext].[sysdiagrams] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 106 | BEGIN TRY DROP EXTERNAL TABLE [ext].[TransactionHistory] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 107 | BEGIN TRY DROP EXTERNAL TABLE [ext].[TransactionHistoryArchive] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 108 | BEGIN TRY DROP EXTERNAL TABLE [ext].[UnitMeasure] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 109 | BEGIN TRY DROP EXTERNAL TABLE [ext].[Vendor] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 110 | BEGIN TRY DROP EXTERNAL TABLE [ext].[WorkOrder] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 111 | BEGIN TRY DROP EXTERNAL TABLE [ext].[WorkOrderRouting] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 112 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimProduct] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 113 | BEGIN TRY DROP EXTERNAL TABLE [ext].[DimDate] END TRY BEGIN CATCH PRINT 'No Need' END CATCH 114 | 115 | BEGIN TRY 116 | DROP EXTERNAL FILE FORMAT TextFile 117 | END TRY 118 | BEGIN CATCH 119 | PRINT 'No Need' 120 | END CATCH; 121 | 122 | -- ####################################################################################################################################### 123 | -- Create a Scoped Credential 124 | -- ####################################################################################################################################### 125 | BEGIN TRY 126 | DROP DATABASE SCOPED CREDENTIAL AzureStorageCredential 127 | END TRY 128 | BEGIN CATCH 129 | PRINT 'No Need' 130 | END CATCH; 131 | 132 | -- ####################################################################################################################################### 133 | -- Create a Master Key 134 | -- ####################################################################################################################################### 135 | BEGIN TRY 136 | DROP MASTER KEY 137 | END TRY 138 | BEGIN CATCH 139 | PRINT 'No Need' 140 | END CATCH 141 | 142 | END -------------------------------------------------------------------------------- /Labs/BuildAutomation/RunAll.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Labs/BuildAutomation/RunAll.sql -------------------------------------------------------------------------------- /Labs/BuildAutomation/dbo.Lab002_PopulateFIS.sql: -------------------------------------------------------------------------------- 1 | -- ####################################################################################################################################### 2 | -- Create a sample procedure 3 | -- ####################################################################################################################################### 4 | 5 | BEGIN TRY 6 | DROP PROC dbo.Lab002_PopulateFIS 7 | END TRY 8 | BEGIN CATCH 9 | PRINT 'No Need' 10 | END CATCH; 11 | GO 12 | 13 | CREATE PROC dbo.Lab002_PopulateFIS AS 14 | BEGIN 15 | 16 | BEGIN TRY 17 | DROP TABLE [olap].[FactInternetSales_new] 18 | END TRY 19 | BEGIN CATCH 20 | PRINT 'No Need' 21 | END CATCH 22 | 23 | 24 | CREATE TABLE [olap].[FactInternetSales_new] 25 | WITH 26 | ( 27 | DISTRIBUTION = ROUND_ROBIN 28 | , CLUSTERED COLUMNSTORE INDEX 29 | ) 30 | AS 31 | SELECT * 32 | FROM [ext].[FactInternetSales] 33 | 34 | END; 35 | GO 36 | -------------------------------------------------------------------------------- /Labs/BuildAutomation/vTableSizes.sql: -------------------------------------------------------------------------------- 1 | -- ####################################################################################################################################### 2 | -- Add vTableSizes 3 | -- ####################################################################################################################################### 4 | 5 | BEGIN TRY 6 | DROP VIEW dbo.vTableSizes 7 | END TRY 8 | BEGIN CATCH 9 | PRINT 'No Need' 10 | END CATCH; 11 | GO 12 | 13 | CREATE VIEW dbo.vTableSizes 14 | AS 15 | WITH base 16 | AS 17 | ( 18 | SELECT 19 | GETDATE() AS [execution_time] 20 | , DB_NAME() AS [database_name] 21 | , s.name AS [schema_name] 22 | , t.name AS [table_name] 23 | , QUOTENAME(s.name)+'.'+QUOTENAME(t.name) AS [two_part_name] 24 | , nt.[name] AS [node_table_name] 25 | , ROW_NUMBER() OVER(PARTITION BY nt.[name] ORDER BY (SELECT NULL)) AS [node_table_name_seq] 26 | , tp.[distribution_policy_desc] AS [distribution_policy_name] 27 | , c.[name] AS [distribution_column] 28 | , nt.[distribution_id] AS [distribution_id] 29 | , i.[type] AS [index_type] 30 | , i.[type_desc] AS [index_type_desc] 31 | , nt.[pdw_node_id] AS [pdw_node_id] 32 | , pn.[type] AS [pdw_node_type] 33 | , pn.[name] AS [pdw_node_name] 34 | , di.name AS [dist_name] 35 | , di.position AS [dist_position] 36 | , nps.[partition_number] AS [partition_nmbr] 37 | , nps.[reserved_page_count] AS [reserved_space_page_count] 38 | , nps.[reserved_page_count] - nps.[used_page_count] AS [unused_space_page_count] 39 | , nps.[in_row_data_page_count] 40 | + nps.[row_overflow_used_page_count] 41 | + nps.[lob_used_page_count] AS [data_space_page_count] 42 | , nps.[reserved_page_count] 43 | - (nps.[reserved_page_count] - nps.[used_page_count]) 44 | - ([in_row_data_page_count] 45 | + [row_overflow_used_page_count]+[lob_used_page_count]) AS [index_space_page_count] 46 | , nps.[row_count] AS [row_count] 47 | from 48 | sys.schemas s 49 | INNER JOIN sys.tables t 50 | ON s.[schema_id] = t.[schema_id] 51 | INNER JOIN sys.indexes i 52 | ON t.[object_id] = i.[object_id] 53 | AND i.[index_id] <= 1 54 | INNER JOIN sys.pdw_table_distribution_properties tp 55 | ON t.[object_id] = tp.[object_id] 56 | INNER JOIN sys.pdw_table_mappings tm 57 | ON t.[object_id] = tm.[object_id] 58 | INNER JOIN sys.pdw_nodes_tables nt 59 | ON tm.[physical_name] = nt.[name] 60 | INNER JOIN sys.dm_pdw_nodes pn 61 | ON nt.[pdw_node_id] = pn.[pdw_node_id] 62 | INNER JOIN sys.pdw_distributions di 63 | ON nt.[distribution_id] = di.[distribution_id] 64 | INNER JOIN sys.dm_pdw_nodes_db_partition_stats nps 65 | ON nt.[object_id] = nps.[object_id] 66 | AND nt.[pdw_node_id] = nps.[pdw_node_id] 67 | AND nt.[distribution_id] = nps.[distribution_id] 68 | LEFT OUTER JOIN (select * from sys.pdw_column_distribution_properties where distribution_ordinal = 1) cdp 69 | ON t.[object_id] = cdp.[object_id] 70 | LEFT OUTER JOIN sys.columns c 71 | ON cdp.[object_id] = c.[object_id] 72 | AND cdp.[column_id] = c.[column_id] 73 | ) 74 | , size 75 | AS 76 | ( 77 | SELECT 78 | [execution_time] 79 | , [database_name] 80 | , [schema_name] 81 | , [table_name] 82 | , [two_part_name] 83 | , [node_table_name] 84 | , [node_table_name_seq] 85 | , [distribution_policy_name] 86 | , [distribution_column] 87 | , [distribution_id] 88 | , [index_type] 89 | , [index_type_desc] 90 | , [pdw_node_id] 91 | , [pdw_node_type] 92 | , [pdw_node_name] 93 | , [dist_name] 94 | , [dist_position] 95 | , [partition_nmbr] 96 | , [reserved_space_page_count] 97 | , [unused_space_page_count] 98 | , [data_space_page_count] 99 | , [index_space_page_count] 100 | , [row_count] 101 | , ([reserved_space_page_count] * 8.0) AS [reserved_space_KB] 102 | , ([reserved_space_page_count] * 8.0)/1000 AS [reserved_space_MB] 103 | , ([reserved_space_page_count] * 8.0)/1000000 AS [reserved_space_GB] 104 | , ([reserved_space_page_count] * 8.0)/1000000000 AS [reserved_space_TB] 105 | , ([unused_space_page_count] * 8.0) AS [unused_space_KB] 106 | , ([unused_space_page_count] * 8.0)/1000 AS [unused_space_MB] 107 | , ([unused_space_page_count] * 8.0)/1000000 AS [unused_space_GB] 108 | , ([unused_space_page_count] * 8.0)/1000000000 AS [unused_space_TB] 109 | , ([data_space_page_count] * 8.0) AS [data_space_KB] 110 | , ([data_space_page_count] * 8.0)/1000 AS [data_space_MB] 111 | , ([data_space_page_count] * 8.0)/1000000 AS [data_space_GB] 112 | , ([data_space_page_count] * 8.0)/1000000000 AS [data_space_TB] 113 | , ([index_space_page_count] * 8.0) AS [index_space_KB] 114 | , ([index_space_page_count] * 8.0)/1000 AS [index_space_MB] 115 | , ([index_space_page_count] * 8.0)/1000000 AS [index_space_GB] 116 | , ([index_space_page_count] * 8.0)/1000000000 AS [index_space_TB] 117 | FROM base 118 | ) 119 | SELECT * 120 | FROM size 121 | ; -------------------------------------------------------------------------------- /Labs/LAB_00/CreateANewInstanceOfAzureSQLDataWarehouse.ps1: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Labs/LAB_00/CreateANewInstanceOfAzureSQLDataWarehouse.ps1 -------------------------------------------------------------------------------- /Labs/LAB_00/README.md: -------------------------------------------------------------------------------- 1 | # LAB - 00. Setup lab 2 | The following lab is everything that is required to get you up and running. 3 | 4 | ------------------------------------------------------------------ 5 | To get connected via SSMS you will need the following address: 6 | 7 | ```sql 8 | Address: magicadventure.database.windows.net 9 | Username : gandalf 10 | Password: Password1234! 11 | ``` 12 | 13 | ![GitHub Logo](/images/usersanddesks.png) 14 | 15 | Once connected, please use your instance. We will give you each a number. 16 | If you are in seat 1, then you will connect to SQLBits2018User1 17 | 18 | There are 70 instances so there is enough for everyone. 19 | 20 | 21 | 22 | ------------------------------------------------------------------- 23 | 24 | 1 - Create a SQL Datawarehouse 25 | 26 | Click New, then on "Databases" 27 | 28 | ![GitHub Logo](/images/AzureSQLDW.png) 29 | 30 | SQL Server - in Azure you create a logical server to collect databases together - this isn't a real server but acts as a way of grouping your resources. You can perform some basic logging and server management from the logical server. 31 | 32 | Complete the creation blade. The SQL Server can either be an existing one or created here. 33 | 34 | 35 | 36 | In this case, we've selected Sample. This will prepopulate the warehouse with the tables and data from the Adventureworks example! 37 | 38 | By default, new servers don't allow anyone to access them. You need to amend the firewall rules and create an exception for your current connection. From your new SQLDW, click on the server name to open the server blade. 39 | 40 | ![GitHub Logo](/images/AzureSQLDW_Config2.png) 41 | 42 | 43 | There are two links to the Firewall area from the server overview: 44 | 45 | ![GitHub Logo](/images/AzureSQLDW_Config3.png) 46 | 47 | 48 | One the firewall properties are open, click the "Add Client IP" button then "Save". This will add an explicit exception for your current connection. 49 | 50 | It's best practice to clear this down when you are done. Customer instances should have clean firewall rules! 51 | 52 | 53 | 54 | You can now connect through management studio! If you log in with admin access to the SQL Server, you'll see the top level "master" database here too: 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | -------------------------------------------------------------------------------- /Labs/LAB_01/README.md: -------------------------------------------------------------------------------- 1 | # LAB-001 | Connect to Azure SQL Data Warehouse, check nodes and distributions 2 | In this lab we will be validating that you can connect, then we will be looking at the number of Nodes and Distributions. 3 | 4 | 1. Connect to the Azure SQL Data Warehouse 5 | 2. Analyse the number of nodes 6 | 3. Analyse the number of distributions 7 | 8 | Open Management studio. Hopefully you are running the latest version of SSMS (17.5). 9 | Login to Azure SQL Data Warehouse. 10 | 11 | ```sql 12 | Server: magicadventure.database.windows.net 13 | UserName: gandalf 14 | Password: Password1234! 15 | ``` 16 | 17 | Once logged in, change you connection to your instance of Azure SQL Data Warehouse. 18 | 19 | ## Analyse the number of nodes 20 | Running the following query in SSMS will return the number of Nodes currently in use. 21 | ```sql 22 | SELECT [pdw_node_id] AS node_id 23 | , [type] AS node_type 24 | , [name] AS node_name 25 | FROM sys.[dm_pdw_nodes] 26 | ; 27 | ``` 28 | 29 | ## Analyse the number of distributions 30 | Running the following query in SSMS will return the number of Distributions currently in use. 31 | ```sql 32 | SELECT [distribution_id] AS dist_id 33 | , [pdw_node_id] AS node_id 34 | , [name] AS dist_name 35 | , [position] AS dist_position 36 | FROM sys.[pdw_distributions] 37 | ; 38 | ``` -------------------------------------------------------------------------------- /Labs/LAB_02/README.md: -------------------------------------------------------------------------------- 1 | # Distributions 2 | In this demo we are looking to create a table and load it with some data. We will introduce creating and loading tables later in the day. So for now we have simplified this in to a stored procedure. 3 | 4 | To complete this lab you will need to do the following 5 | 1. Execute a stored procedure to populate a table 6 | 2. Run a Select * FROM [olap].[FactInternetSales_new] 7 | 3. Query DBCC PDW_SHOWSPACEUSED 8 | 4. Query sys.dm_pdw_nodes_db_partition_stats 9 | 5. Query vTableSizes 10 | 11 | 12 | ## Execute a stored procedure to populate a table 13 | Running this will be a 14 | ```sql 15 | EXEC dbo.Lab002_PopulateFIS 16 | ``` 17 | 18 | ## Run a Select * FROM [olap].[FactInternetSales_new] 19 | This table has been completed using a round robin distribution. This might not mean a lot at this point. 20 | We will come back to this. For now just run the example code. 21 | ```sql 22 | SELECT * FROM [olap].[FactInternetSales_new] 23 | ``` 24 | 25 | Next you want to run DBCC PDW_SHOWSPACEUSED. The purpose of this is to see how your data has been distributed across our distributions. 26 | ```sql 27 | DBCC PDW_SHOWSPACEUSED 28 | ``` 29 | 30 | By default this returns all allocations for the distributions, but you can filter it down to just the table you're after. 31 | 32 | ```sql 33 | DBCC PDW_SHOWSPACEUSED('[olap].[FactInternetSales_new]') 34 | ``` 35 | 36 | Then you will want to see how your data has been partitioned across distributions. 37 | ```sql 38 | SELECT 39 | ps.pdw_node_id 40 | , ps.distribution_id 41 | , ps.object_id AS 'physical_object_id' 42 | , ps.index_id 43 | , ps.partition_number 44 | , ps.row_count 45 | , ps.used_page_count 46 | FROM 47 | sys.dm_pdw_nodes_db_partition_stats AS ps; 48 | ``` 49 | 50 | Finally Microsoft produce a great view called vTableSizes. This has been pre-loaded in to the database you're using. 51 | Run the following query and take a look at how FactInternetSales_new has been distributed across nodes. 52 | This is a great view to have installed on all of your instances of Azure SQL Data Warehouse. 53 | ```sql 54 | SELECT * FROM dbo.vTableSizes WHERE two_part_name = '[olap].[FactInternetSales_new]' 55 | ``` 56 | 57 | ## Additional queries you might want to have a look at: 58 | ### Table space summary 59 | This query returns the rows and space by table. It allows you to see which tables are your largest tables and whether they are round-robin, replicated, or hash -distributed. For hash-distributed tables, the query shows the distribution column. 60 | 61 | ```sql 62 | SELECT 63 | database_name 64 | , schema_name 65 | , table_name 66 | , distribution_policy_name 67 | , distribution_column 68 | , index_type_desc 69 | , COUNT(distinct partition_nmbr) as nbr_partitions 70 | , SUM(row_count) as table_row_count 71 | , SUM(reserved_space_GB) as table_reserved_space_GB 72 | , SUM(data_space_GB) as table_data_space_GB 73 | , SUM(index_space_GB) as table_index_space_GB 74 | , SUM(unused_space_GB) as table_unused_space_GB 75 | FROM 76 | dbo.vTableSizes 77 | GROUP BY 78 | database_name 79 | , schema_name 80 | , table_name 81 | , distribution_policy_name 82 | , distribution_column 83 | , index_type_desc 84 | ORDER BY 85 | table_reserved_space_GB desc 86 | ; 87 | ``` 88 | 89 | ### Table space by distribution type 90 | ```sql 91 | SELECT 92 | distribution_policy_name 93 | , SUM(row_count) as table_type_row_count 94 | , SUM(reserved_space_GB) as table_type_reserved_space_GB 95 | , SUM(data_space_GB) as table_type_data_space_GB 96 | , SUM(index_space_GB) as table_type_index_space_GB 97 | , SUM(unused_space_GB) as table_type_unused_space_GB 98 | FROM dbo.vTableSizes 99 | GROUP BY distribution_policy_name 100 | ; 101 | ``` 102 | 103 | ### Table space by index type 104 | ```sql 105 | SELECT 106 | index_type_desc 107 | , SUM(row_count) as table_type_row_count 108 | , SUM(reserved_space_GB) as table_type_reserved_space_GB 109 | , SUM(data_space_GB) as table_type_data_space_GB 110 | , SUM(index_space_GB) as table_type_index_space_GB 111 | , SUM(unused_space_GB) as table_type_unused_space_GB 112 | FROM dbo.vTableSizes 113 | GROUP BY index_type_desc 114 | ; 115 | ``` 116 | 117 | ### Distribution space summary 118 | ```sql 119 | SELECT 120 | distribution_id 121 | , SUM(row_count) as total_node_distribution_row_count 122 | , SUM(reserved_space_MB) as total_node_distribution_reserved_space_MB 123 | , SUM(data_space_MB) as total_node_distribution_data_space_MB 124 | , SUM(index_space_MB) as total_node_distribution_index_space_MB 125 | , SUM(unused_space_MB) as total_node_distribution_unused_space_MB 126 | FROM dbo.vTableSizes 127 | GROUP BY distribution_id 128 | ORDER BY distribution_id 129 | ; 130 | ``` 131 | 132 | Lab complete. -------------------------------------------------------------------------------- /Labs/LAB_02/dbo.Lab002_PopulateFIS.sql: -------------------------------------------------------------------------------- 1 | -- ####################################################################################################################################### 2 | -- Create a sample procedure 3 | -- ####################################################################################################################################### 4 | 5 | BEGIN TRY 6 | DROP PROC dbo.Lab002_PopulateFIS 7 | END TRY 8 | BEGIN CATCH 9 | PRINT 'No Need' 10 | END CATCH; 11 | GO 12 | 13 | CREATE PROC dbo.Lab002_PopulateFIS AS 14 | BEGIN 15 | 16 | BEGIN TRY 17 | DROP TABLE [olap].[FactInternetSales_new] 18 | END TRY 19 | BEGIN CATCH 20 | PRINT 'No Need' 21 | END CATCH 22 | 23 | 24 | CREATE TABLE [olap].[FactInternetSales_new] 25 | WITH 26 | ( 27 | DISTRIBUTION = ROUND_ROBIN 28 | , CLUSTERED COLUMNSTORE INDEX 29 | ) 30 | AS 31 | SELECT * 32 | FROM [ext].[FactInternetSales] 33 | 34 | END; 35 | GO 36 | -------------------------------------------------------------------------------- /Labs/LAB_02/vTableSizes.sql: -------------------------------------------------------------------------------- 1 | CREATE VIEW dbo.vTableSizes 2 | AS 3 | WITH base 4 | AS 5 | ( 6 | SELECT 7 | GETDATE() AS [execution_time] 8 | , DB_NAME() AS [database_name] 9 | , s.name AS [schema_name] 10 | , t.name AS [table_name] 11 | , QUOTENAME(s.name)+'.'+QUOTENAME(t.name) AS [two_part_name] 12 | , nt.[name] AS [node_table_name] 13 | , ROW_NUMBER() OVER(PARTITION BY nt.[name] ORDER BY (SELECT NULL)) AS [node_table_name_seq] 14 | , tp.[distribution_policy_desc] AS [distribution_policy_name] 15 | , c.[name] AS [distribution_column] 16 | , nt.[distribution_id] AS [distribution_id] 17 | , i.[type] AS [index_type] 18 | , i.[type_desc] AS [index_type_desc] 19 | , nt.[pdw_node_id] AS [pdw_node_id] 20 | , pn.[type] AS [pdw_node_type] 21 | , pn.[name] AS [pdw_node_name] 22 | , di.name AS [dist_name] 23 | , di.position AS [dist_position] 24 | , nps.[partition_number] AS [partition_nmbr] 25 | , nps.[reserved_page_count] AS [reserved_space_page_count] 26 | , nps.[reserved_page_count] - nps.[used_page_count] AS [unused_space_page_count] 27 | , nps.[in_row_data_page_count] 28 | + nps.[row_overflow_used_page_count] 29 | + nps.[lob_used_page_count] AS [data_space_page_count] 30 | , nps.[reserved_page_count] 31 | - (nps.[reserved_page_count] - nps.[used_page_count]) 32 | - ([in_row_data_page_count] 33 | + [row_overflow_used_page_count]+[lob_used_page_count]) AS [index_space_page_count] 34 | , nps.[row_count] AS [row_count] 35 | from 36 | sys.schemas s 37 | INNER JOIN sys.tables t 38 | ON s.[schema_id] = t.[schema_id] 39 | INNER JOIN sys.indexes i 40 | ON t.[object_id] = i.[object_id] 41 | AND i.[index_id] <= 1 42 | INNER JOIN sys.pdw_table_distribution_properties tp 43 | ON t.[object_id] = tp.[object_id] 44 | INNER JOIN sys.pdw_table_mappings tm 45 | ON t.[object_id] = tm.[object_id] 46 | INNER JOIN sys.pdw_nodes_tables nt 47 | ON tm.[physical_name] = nt.[name] 48 | INNER JOIN sys.dm_pdw_nodes pn 49 | ON nt.[pdw_node_id] = pn.[pdw_node_id] 50 | INNER JOIN sys.pdw_distributions di 51 | ON nt.[distribution_id] = di.[distribution_id] 52 | INNER JOIN sys.dm_pdw_nodes_db_partition_stats nps 53 | ON nt.[object_id] = nps.[object_id] 54 | AND nt.[pdw_node_id] = nps.[pdw_node_id] 55 | AND nt.[distribution_id] = nps.[distribution_id] 56 | LEFT OUTER JOIN (select * from sys.pdw_column_distribution_properties where distribution_ordinal = 1) cdp 57 | ON t.[object_id] = cdp.[object_id] 58 | LEFT OUTER JOIN sys.columns c 59 | ON cdp.[object_id] = c.[object_id] 60 | AND cdp.[column_id] = c.[column_id] 61 | ) 62 | , size 63 | AS 64 | ( 65 | SELECT 66 | [execution_time] 67 | , [database_name] 68 | , [schema_name] 69 | , [table_name] 70 | , [two_part_name] 71 | , [node_table_name] 72 | , [node_table_name_seq] 73 | , [distribution_policy_name] 74 | , [distribution_column] 75 | , [distribution_id] 76 | , [index_type] 77 | , [index_type_desc] 78 | , [pdw_node_id] 79 | , [pdw_node_type] 80 | , [pdw_node_name] 81 | , [dist_name] 82 | , [dist_position] 83 | , [partition_nmbr] 84 | , [reserved_space_page_count] 85 | , [unused_space_page_count] 86 | , [data_space_page_count] 87 | , [index_space_page_count] 88 | , [row_count] 89 | , ([reserved_space_page_count] * 8.0) AS [reserved_space_KB] 90 | , ([reserved_space_page_count] * 8.0)/1000 AS [reserved_space_MB] 91 | , ([reserved_space_page_count] * 8.0)/1000000 AS [reserved_space_GB] 92 | , ([reserved_space_page_count] * 8.0)/1000000000 AS [reserved_space_TB] 93 | , ([unused_space_page_count] * 8.0) AS [unused_space_KB] 94 | , ([unused_space_page_count] * 8.0)/1000 AS [unused_space_MB] 95 | , ([unused_space_page_count] * 8.0)/1000000 AS [unused_space_GB] 96 | , ([unused_space_page_count] * 8.0)/1000000000 AS [unused_space_TB] 97 | , ([data_space_page_count] * 8.0) AS [data_space_KB] 98 | , ([data_space_page_count] * 8.0)/1000 AS [data_space_MB] 99 | , ([data_space_page_count] * 8.0)/1000000 AS [data_space_GB] 100 | , ([data_space_page_count] * 8.0)/1000000000 AS [data_space_TB] 101 | , ([index_space_page_count] * 8.0) AS [index_space_KB] 102 | , ([index_space_page_count] * 8.0)/1000 AS [index_space_MB] 103 | , ([index_space_page_count] * 8.0)/1000000 AS [index_space_GB] 104 | , ([index_space_page_count] * 8.0)/1000000000 AS [index_space_TB] 105 | FROM base 106 | ) 107 | SELECT * 108 | FROM size 109 | ; -------------------------------------------------------------------------------- /Labs/LAB_03/README.md: -------------------------------------------------------------------------------- 1 | # Distributions 2 | 3 | This lab aims to introduce you to the idea of redistributing data within tables. This is a common technique when exploring performance issues and working on the initial design of your data model. Don't be afraid to try several different distributions - the data movement service is very efficient, the overhead of trying it out isn't too great! 4 | 5 | In this lab we will: 6 | 1. Create a table using round robin distribution 7 | 2. Redistribute using a poor key choice 8 | 3. Redistribute using a good key choice 9 | 4. Redistribute as a replicated table 10 | 5. Use your skew tools to review your new tables 11 | 12 | ## Setting up your initial table 13 | 14 | First, we need to bring in some data we can work with, run the following script to select records from one of our external tables and store it as a local table using the distributions. 15 | 16 | ```sql 17 | CREATE TABLE dbo.FactInternetSales 18 | WITH 19 | ( 20 | CLUSTERED COLUMNSTORE INDEX, 21 | DISTRIBUTION = ROUND_ROBIN 22 | ) 23 | AS 24 | SELECT * 25 | FROM [ext].[FactInternetSales] 26 | ``` 27 | 28 | This creates our first table - let's take a look at how it's been distributed across the distributions using vTableSizes: 29 | 30 | ```sql 31 | SELECT two_part_name, distribution_id, row_count 32 | FROM [dbo].[vTableSizes] 33 | WHERE two_part_name = '[dbo].[FactInternetSales]' 34 | ``` 35 | 36 | This should have a fairly even (not exact!) spread across the various distributions. 37 | 38 | ## Redistribute as a badly distributed HASH() 39 | 40 | Now let's create a copy of the table using a HASH distribution. We can pick a column and distribute it out. Run the following script to create our table using something that perhaps isn't the best choice - maybe it doesn't have many values, maybe one of the values has way more records than others. We've picked CurrencyKey, but feel free to choose your own! 41 | 42 | ```sql 43 | CREATE TABLE dbo.FactInternetSalesPH_Bad 44 | WITH 45 | ( 46 | CLUSTERED COLUMNSTORE INDEX, 47 | DISTRIBUTION = HASH(CurrencyKey) 48 | ) 49 | AS 50 | SELECT * 51 | FROM [dbo].[FactInternetSales] 52 | ``` 53 | 54 | This creates a new table and distributes the data from the select statement. Let's take a look at how that distributed: 55 | 56 | ```sql 57 | SELECT two_part_name, distribution_id, row_count 58 | FROM [dbo].[vTableSizes] 59 | WHERE two_part_name = '[dbo].[FactInternetSalesPH_Bad]' 60 | ``` 61 | 62 | If you've picked poorly then you should be seeing a huge disparity in record distribution. For CurrencyKey, many distributions won't have any records at all as there are not enough unique values to cover all distributions. 63 | 64 | ## Redistribute as a well distributed HASH() 65 | 66 | Let's try again with a better column to distribute on. We often join to the table using the ProductKey so that is a fair candidate for our distribution. 67 | 68 | ```sql 69 | CREATE TABLE dbo.FactInternetSalesPH 70 | WITH 71 | ( 72 | CLUSTERED COLUMNSTORE INDEX, 73 | DISTRIBUTION = HASH(ProductKey) 74 | ) 75 | AS 76 | SELECT * 77 | FROM [dbo].[FactInternetSales] 78 | ``` 79 | 80 | Once again, let's see how that looks: 81 | 82 | ```sql 83 | SELECT two_part_name, distribution_id, row_count 84 | FROM [dbo].[vTableSizes] 85 | WHERE two_part_name = '[dbo].[FactInternetSalesPH]' 86 | ``` 87 | 88 | Not perfect, but a lot better! It's very rare to find a table that does have a very well distributed key that also meets are other criteria. 89 | 90 | ## Rebuild as a Replicated Table 91 | 92 | Our final replication type is our Replicated table. This works differently in that queries do not hit all distributions at all but a copy is pushed on to the compute nodes themselves which is used in those queries. 93 | 94 | ```sql 95 | CREATE TABLE dbo.FactInternetSalesREP 96 | WITH 97 | ( 98 | CLUSTERED COLUMNSTORE INDEX, 99 | DISTRIBUTION = REPLICATE 100 | ) 101 | AS 102 | SELECT * 103 | FROM [dbo].[FactInternetSales] 104 | ``` 105 | 106 | ## Review Skew 107 | 108 | You can use the skew analysis views to decide which of your tables would be best in this scenario. 109 | 110 | ```sql 111 | --Return distribution usage 112 | DBCC PDW_SHOWSPACEUSED 113 | 114 | --Return ALL table across ALL distributions 115 | SELECT 116 | ps.pdw_node_id 117 | , ps.distribution_id 118 | , ps.object_id AS 'physical_object_id' 119 | , ps.index_id 120 | , ps.partition_number 121 | , ps.row_count 122 | , ps.used_page_count 123 | FROM 124 | sys.dm_pdw_nodes_db_partition_stats AS ps; 125 | 126 | --Formatted view, good for exploring distribution skew 127 | SELECT * 128 | FROM [dbo].[vTableSizes] 129 | ``` -------------------------------------------------------------------------------- /Labs/LAB_04/README.md: -------------------------------------------------------------------------------- 1 | # Lab 004 - Loading data in to Azure SQL Data Warehouse. [Polybase] 2 | 3 | In this lab you are a Magic Works Consultant. You're responsible for developing Magic works new data warehouse in Azure SQL Data Warehouse. Magic works have done some of the work for you, they have loaded all their data in to an Azure blob storage account. 4 | 5 | The connection details you need for this storage account are as follows: 6 | ```sql 7 | Users 1-10: 8 | Blob Account: magicworksblob 9 | Blob Key: WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA== 10 | 11 | Users 11-20: 12 | Blob Account: magicworksblob2 13 | Blob Key: iPKgnuG5oI6sl9lplkTl2v9KGboJthwMNm1BDurW5NkOU1r0qaUSXNlSZxZGCC6PjGqv2mB+8ABMtVcvlVWSgg== 14 | 15 | Users 21-30: 16 | Blob Account: magicworksblob3 17 | Blob Key: //xPuuJEovTStG3YqxpzlCyyDWcojaf0iK3LuuJxrFWfwVpc8MNJg69sTUitdT/a08/aYoIzYbKD9v7kNYGSaA== 18 | 19 | Users 31-40: 20 | Blob Account: magicworksblob4 21 | Blob Key: hvLzIESMiRANksNoP4Jv5ZTfsvLKaGkAvAOrf5Cl9RUzx46zktO1wa87ssNQSFwKBLJnz1d3aMVJuuUTsBswWQ== 22 | 23 | Users 41-50: 24 | Blob Account: magicworksblob5 25 | Blob Key: 7NDJoZdV1459ZB8wUzDEBt/qUZnxzeEBvS+LHH4sZPTVFugMnC12c2as2M1d9FZbKn3EYmOpL2cu7Yb0xjmOpA== 26 | 27 | Users 51-60: 28 | Blob Account: magicworksblob6 29 | Blob Key: qsgGBy85YqL6//M4BJ8OMCdEGnwS8Soj44W9oi0RcydNMWQNIbQtNi+7NUQ65A3b6mSKZzMPHqQ2WSPDIVda0A== 30 | 31 | Users 61-70: 32 | Blob Account: magicworksblob7 33 | Blob Key: dpUqFYVTcV8SCVf/sV/qX76sRGpEi/PQVlvdg/xiR8PJALPiYuJXNBn/HLbV4mQ5kX5aAurYVoBXQo4kjNCxGA== 34 | ``` 35 | 36 | To view the data you can install Azure storage explorer. You can download this 37 | [here](https://azure.microsoft.com/en-gb/features/storage-explorer/) 38 | 39 | Azure storage explorer also now works with Azure Data Lake - which is nice! 40 | 41 | In this lab you will need to complete the folloing actions. 42 | 43 | 1. Log in to SSMS 44 | 2. Connect to your instance (or an instance we have proved you) of Azure SQL Data Warehouse. 45 | 3. Create a Master Key 46 | 4. Create a Database scoped credential 47 | 5. Create an external data source 48 | 6. Create a textfile format 49 | 7. Create an external table 50 | 8. Query that table 51 | 52 | Below is a snippt that you can copy and amend. If this does not work, you will find the commpleted example code at the bottom of this document. 53 | 54 | ### Login and connect to the database. 55 | You should be able to do this now. If you cannot, then please let us know, either in-person or on Slack. 56 | Please refer to LAB 00 for details on connecting to an instance Of Azure SQLDW. 57 | 58 | ***PLEASE MAKE SURE YOU'RE CONNECTED TO YOUR INSTANCE*** 59 | 60 | ### Run the following clean up script 61 | This ensures that the version of the data warehouse you're working with is fresh. 62 | ```sql 63 | EXEC dbo.ResetBuildScript 64 | ``` 65 | 66 | ### Create a Master Key and Scoped credential 67 | We need to create a master key, only necessary if one does not exist already. 68 | ```sql 69 | CREATE MASTER KEY; 70 | ``` 71 | 72 | ### Create a scoped credential 73 | IDENTITY: Provide any string, it is not used for authentication to Azure storage. 74 | SECRET: Provide your Azure storage account key. Grab this from above. 75 | ```sql 76 | CREATE DATABASE SCOPED CREDENTIAL AzureStorageCredential 77 | WITH 78 | IDENTITY = 'user', 79 | SECRET = '' 80 | ; 81 | ``` 82 | 83 | ### Create an External Data Source 84 | Next we need to create an external data source. You will need to amend 'blob_container_name' and 'azure_storage_account_name', you can find both of these at the top of this document. Key points here are that we are making a connection to a HADOOP type data source. BLOB storage runs on HDFS, the Hadoop file system. 85 | blob_container_name: product 86 | azure_storage_account_name: magicworksblob 87 | ```sql 88 | CREATE EXTERNAL DATA SOURCE AzureStorage 89 | WITH ( 90 | TYPE = HADOOP, 91 | LOCATION = 'wasbs://@.blob.core.windows.net', 92 | CREDENTIAL = AzureStorageCredential 93 | ); 94 | ``` 95 | 96 | ### Create a textfile format 97 | You only need to create this part once, per type of data you're consuming. If you're consuming a pipe delimted file, you would need a slightly different textfile format. 98 | ```sql 99 | CREATE EXTERNAL FILE FORMAT TextFile 100 | WITH ( 101 | FORMAT_TYPE = DelimitedText, 102 | FORMAT_OPTIONS (FIELD_TERMINATOR = ',', STRING_DELIMITER= '"') 103 | ); 104 | 105 | ``` 106 | 107 | ### Create an external table 108 | This is schema on read so we need to state what the expected data should be as it is read. 109 | Polybase has some quirks, but as long as we have structured data we will be fine. If you need to clean the data to conform with Polybase's quirks, we recommend custom functions in Data Factory or to use Data Lake Analytics. 110 | 111 | You will need to amend the following. 112 | ```sql 113 | CREATE EXTERNAL DATA SOURCE Blob_product 114 | WITH (TYPE = HADOOP, 115 | LOCATION = 'wasbs://product@magicworksblob.blob.core.windows.net', 116 | CREDENTIAL = AzureStorageCredential); 117 | ``` 118 | 119 | ```sql 120 | CREATE EXTERNAL TABLE Ext.Product( 121 | [ProductID] NVARCHAR(50) , [Name] NVARCHAR(500) , [ProductNumber] NVARCHAR(500) , [MakeFlag] NVARCHAR(500) , [FinishedGoodsFlag] NVARCHAR(500) , [Color] NVARCHAR(500) , [SafetyStockLevel] NVARCHAR(500) , [ReorderPoint] NVARCHAR(500) , [StandardCost] NVARCHAR(500) , [ListPrice] NVARCHAR(500) , [Size] NVARCHAR(500) , [SizeUnitMeasureCode] NVARCHAR(500) , [WeightUnitMeasureCode] NVARCHAR(500) , [Weight] NVARCHAR(50) , [DaysToManufacture] NVARCHAR(50) , [ProductLine] NVARCHAR(500) , [Class] NVARCHAR(500) , [Style] NVARCHAR(500) , [ProductSubcategoryID] NVARCHAR(50) , [ProductModelID] NVARCHAR(50) , [SellStartDate] NVARCHAR(50) , [SellEndDate] NVARCHAR(50) , [DiscontinuedDate] NVARCHAR(50) , [rowguid] NVARCHAR(500) , [ModifiedDate] NVARCHAR(50) 122 | ) 123 | WITH (LOCATION='./', 124 | DATA_SOURCE = Blob_product, 125 | FILE_FORMAT = TextFile, 126 | REJECT_TYPE = VALUE, 127 | REJECT_VALUE = 0); 128 | ``` 129 | 130 | ### Query that table 131 | If all the elements above have worked you will now be able to query the data in Blob storage. 132 | Remember. This is not a table in the data warehouse. This is a connection via a MapReduce function to Azure Blob Storage. 133 | ```sql 134 | SELECT * FROM Ext.Product 135 | ``` 136 | 137 | 138 | 139 | ## Completed example 140 | ```sql 141 | BEGIN TRY 142 | CREATE MASTER KEY; 143 | END TRY 144 | BEGIN CATCH 145 | PRINT 'No Need' 146 | END CATCH; 147 | GO 148 | 149 | BEGIN TRY 150 | CREATE DATABASE SCOPED CREDENTIAL AzureStorageCredential 151 | WITH 152 | IDENTITY = 'user', 153 | SECRET = 'WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA==' 154 | END TRY 155 | BEGIN CATCH 156 | PRINT 'No Need' 157 | END CATCH; 158 | GO 159 | 160 | 161 | BEGIN TRY 162 | CREATE EXTERNAL FILE FORMAT TextFile 163 | WITH ( 164 | FORMAT_TYPE = DelimitedText, 165 | FORMAT_OPTIONS (FIELD_TERMINATOR = ',', STRING_DELIMITER= '"') 166 | ) 167 | END TRY 168 | BEGIN CATCH 169 | PRINT 'No Need' 170 | END CATCH; 171 | GO 172 | 173 | BEGIN TRY 174 | DROP EXTERNAL TABLE Ext.Product; 175 | END TRY 176 | BEGIN CATCH 177 | PRINT 'DNGN' 178 | END CATCH 179 | 180 | BEGIN TRY 181 | DROP EXTERNAL DATA SOURCE Blob_product; 182 | END TRY 183 | BEGIN CATCH 184 | PRINT 'DNGN' 185 | END CATCH 186 | 187 | 188 | CREATE EXTERNAL DATA SOURCE Blob_product 189 | WITH (TYPE = HADOOP, 190 | LOCATION = 'wasbs://product@magicworksblob.blob.core.windows.net', 191 | CREDENTIAL = AzureStorageCredential); 192 | 193 | 194 | CREATE EXTERNAL TABLE Ext.Product( 195 | [ProductID] NVARCHAR(50) , [Name] NVARCHAR(500) , [ProductNumber] NVARCHAR(500) , [MakeFlag] NVARCHAR(500) , [FinishedGoodsFlag] NVARCHAR(500) , [Color] NVARCHAR(500) , [SafetyStockLevel] NVARCHAR(500) , [ReorderPoint] NVARCHAR(500) , [StandardCost] NVARCHAR(500) , [ListPrice] NVARCHAR(500) , [Size] NVARCHAR(500) , [SizeUnitMeasureCode] NVARCHAR(500) , [WeightUnitMeasureCode] NVARCHAR(500) , [Weight] NVARCHAR(50) , [DaysToManufacture] NVARCHAR(50) , [ProductLine] NVARCHAR(500) , [Class] NVARCHAR(500) , [Style] NVARCHAR(500) , [ProductSubcategoryID] NVARCHAR(50) , [ProductModelID] NVARCHAR(50) , [SellStartDate] NVARCHAR(50) , [SellEndDate] NVARCHAR(50) , [DiscontinuedDate] NVARCHAR(50) , [rowguid] NVARCHAR(500) , [ModifiedDate] NVARCHAR(50) 196 | ) 197 | WITH (LOCATION='./', 198 | DATA_SOURCE = Blob_product, 199 | FILE_FORMAT = TextFile, 200 | REJECT_TYPE = VALUE, 201 | REJECT_VALUE = 0); 202 | 203 | 204 | SELECT * FROM Ext.Product 205 | ``` -------------------------------------------------------------------------------- /Labs/LAB_05/README.md: -------------------------------------------------------------------------------- 1 | # Managing surrogates [10 Minutes] 2 | 3 | This lab tackles a very common data warehousing issue - applying surrogate keys to a dimension table during an insert. The standard approach for this would be to use an IDENTITY table, but this is very different in SQLDW and so we have a few options. 4 | 5 | To complete this Lab, we need to: 6 | 1. Run a script to set up our demo 7 | 2. Run Option 1 - Applying Surrogate Keys via Identity 8 | 3. Run Option 2 - Applying Surrogate Keys via ROW_NUMBER() 9 | 4. Run Option 3 - Applying Surrogate Keys via HASH() 10 | 11 | ## Populate Dimension & Delta Table for our Demo 12 | 13 | We first need to set up a table and some changed records so that we can model our surrogate inserts. Run the following script to pull data in from the DimProduct external table and land it as dbo.DimProduct. This is taken from the AdventureWorksDW sample and so already has surrogate keys generated. 14 | 15 | ```sql 16 | CREATE TABLE dbo.DimProduct 17 | WITH 18 | ( 19 | HEAP, 20 | DISTRIBUTION = ROUND_ROBIN 21 | ) 22 | AS 23 | SELECT * 24 | FROM ext.DimProduct 25 | 26 | CREATE TABLE dbo.DimProductDelta 27 | WITH 28 | ( 29 | HEAP, 30 | DISTRIBUTION = ROUND_ROBIN 31 | ) 32 | AS 33 | SELECT TOP 10 34 | [ProductAlternateKey] + 'D' [ProductAlternateKey] , [ProductSubcategoryKey], [WeightUnitMeasureCode], [SizeUnitMeasureCode], [EnglishProductName], [SpanishProductName], [FrenchProductName], [StandardCost], [FinishedGoodsFlag], [Color], [SafetyStockLevel], [ReorderPoint], [ListPrice], [Size], [SizeRange], [Weight], [DaysToManufacture], [ProductLine], [DealerPrice], [Class], [Style], [ModelName], [EnglishDescription], [FrenchDescription], [ChineseDescription], [ArabicDescription], [HebrewDescription], [ThaiDescription], [GermanDescription], [JapaneseDescription], [TurkishDescription], [StartDate], [EndDate], [Status] 35 | FROM [dbo].[DimProduct] 36 | UNION ALL 37 | SELECT TOP 10 38 | [ProductAlternateKey], [ProductSubcategoryKey], [WeightUnitMeasureCode], [SizeUnitMeasureCode], [EnglishProductName], [SpanishProductName], [FrenchProductName], [StandardCost], [FinishedGoodsFlag], [Color], [SafetyStockLevel], [ReorderPoint], [ListPrice], [Size], [SizeRange], [Weight], [DaysToManufacture], [ProductLine], [DealerPrice], [Class], [Style], [ModelName], [EnglishDescription], [FrenchDescription], [ChineseDescription], [ArabicDescription], [HebrewDescription], [ThaiDescription], [GermanDescription], [JapaneseDescription], [TurkishDescription], [StartDate], [EndDate], [Status] 39 | FROM dbo.DimProduct 40 | ``` 41 | 42 | This will create the two tables we're using for our example. Take a look at DimProduct, which contains records already populated with data including surrogate keys, and the DimProductDelta table that contains records which need a surrogate appending before being added to our dimension table. 43 | 44 | ## Option 1 - IDENTITY Tables 45 | 46 | Similar to the normal SQL Server engine, Azure SQLDW can have identity columns which will automatically populate as records are added. However, in order to enable massively parallel inserts, the identities generated are sparsely populated and there is potential for collisions. 47 | 48 | First we need to create the new dimension table, run the following script to create a DimProduct_Identity with the IDENTITY(1,1) attribute on the ProductKey column 49 | 50 | ```sql 51 | CREATE TABLE [dbo].[DimProduct_Identity] 52 | ( 53 | [ProductKey] [int] IDENTITY(1,1) NOT NULL, 54 | [ProductAlternateKey] [nvarchar](25) NULL, 55 | [ProductSubcategoryKey] [int] NULL, 56 | [WeightUnitMeasureCode] [nchar](3) NULL, 57 | [SizeUnitMeasureCode] [nchar](3) NULL, 58 | [EnglishProductName] [nvarchar](50) NOT NULL, 59 | [SpanishProductName] [nvarchar](50) NULL, 60 | [FrenchProductName] [nvarchar](50) NULL, 61 | [StandardCost] [money] NULL, 62 | [FinishedGoodsFlag] [bit] NOT NULL, 63 | [Color] [nvarchar](15) NOT NULL, 64 | [SafetyStockLevel] [smallint] NULL, 65 | [ReorderPoint] [smallint] NULL, 66 | [ListPrice] [money] NULL, 67 | [Size] [nvarchar](50) NULL, 68 | [SizeRange] [nvarchar](50) NULL, 69 | [Weight] [float] NULL, 70 | [DaysToManufacture] [int] NULL, 71 | [ProductLine] [nchar](2) NULL, 72 | [DealerPrice] [money] NULL, 73 | [Class] [nchar](2) NULL, 74 | [Style] [nchar](2) NULL, 75 | [ModelName] [nvarchar](50) NULL, 76 | [EnglishDescription] [nvarchar](400) NULL, 77 | [FrenchDescription] [nvarchar](400) NULL, 78 | [ChineseDescription] [nvarchar](400) NULL, 79 | [ArabicDescription] [nvarchar](400) NULL, 80 | [HebrewDescription] [nvarchar](400) NULL, 81 | [ThaiDescription] [nvarchar](400) NULL, 82 | [GermanDescription] [nvarchar](400) NULL, 83 | [JapaneseDescription] [nvarchar](400) NULL, 84 | [TurkishDescription] [nvarchar](400) NULL, 85 | [StartDate] [datetime] NULL, 86 | [EndDate] [datetime] NULL, 87 | [Status] [nvarchar](7) NULL 88 | ) 89 | WITH 90 | ( 91 | DISTRIBUTION = HASH ( [ProductAlternateKey] ), 92 | CLUSTERED COLUMNSTORE INDEX 93 | ) 94 | GO 95 | 96 | ``` 97 | 98 | We can now insert records into this table. Note that we need to run this as a straight insert, we cannot use the CTAS syntax in combination with an identity. 99 | 100 | ```sql 101 | INSERT INTO [dbo].[DimProduct_Identity] 102 | ([ProductAlternateKey], [ProductSubcategoryKey], [WeightUnitMeasureCode], [SizeUnitMeasureCode], [EnglishProductName], [SpanishProductName], [FrenchProductName], [StandardCost], [FinishedGoodsFlag], [Color], [SafetyStockLevel], [ReorderPoint], [ListPrice], [Size], [SizeRange], [Weight], [DaysToManufacture], [ProductLine], [DealerPrice], [Class], [Style], [ModelName], [EnglishDescription], [FrenchDescription], [ChineseDescription], [ArabicDescription], [HebrewDescription], [ThaiDescription], [GermanDescription], [JapaneseDescription], [TurkishDescription], [StartDate], [EndDate], [Status]) 103 | SELECT * FROM dbo.DimProductDelta 104 | ``` 105 | 106 | Once that has completed, we can look at the records that have been inserted 107 | 108 | ```sql 109 | SELECT * FROM [dbo].[DimProduct_Identity] 110 | ``` 111 | 112 | Normally, we would expect our records to be numbers 1-20, but you should see something quite different! Azure SQLDW will sparsely populate the identity to enable the parallel inserts needed to improve performance. Also, not being able to use a CTAS means our loading patterns have to be updated. 113 | 114 | ## Option 2 - ROW_NUMBER() Pattern 115 | 116 | A standard approach is to use the ROW_NUMBER() window function within our select statement to generate a seqeuential integer for each row of the delta table. We can add the current maximum key to this number to ensure we are not duplicating existing keys. 117 | 118 | ```sql 119 | DECLARE @MaxKey int = (SELECT MAX(ProductKey) FROM dbo.DimProduct) 120 | 121 | SELECT ISNULL(DP.ProductKey,ROW_NUMBER() OVER (ORDER BY DPD.ProductAlternateKey) + @MaxKey) as ProductKey, 122 | DPD.* 123 | FROM dbo.DimProductDelta DPD LEFT JOIN 124 | dbo.DimProduct DP ON DPD.ProductAlternateKey = DP.ProductAlternateKey 125 | ``` 126 | 127 | This is a fairly straight-forward approach and is very commonly used across organisations that are managing Kimball-style warehouses in Azure SQLDW. There is a performance impact from joining to the dimension to retrieve existing keys - if it is a large dimension you might want to split this into an "Inserts" and an "Update/Delete" statement to manage performance separately. 128 | 129 | ## Option 3 - Applying Surrogates via HASH 130 | 131 | A final option would be to apply a HASHBYTES to your business key. This removes the need to join to the dimension table in order to see where records already exist, the hash can be generated during earlier data transformations. 132 | 133 | ```sql 134 | SELECT LOWER(CONVERT(CHAR(32),HASHBYTES('MD5',DPD.ProductAlternateKey),2)) ProductKey, 135 | DPD.* 136 | FROM dbo.DimProductDelta DPD 137 | ``` 138 | 139 | This is a common loading pattern where the emphasis is on getting data into the system as fast as possible. Patterns such as Data Vault favour this method, but you can certainly use it in classic warehousing if you are performing many small updates throughout the day. 140 | 141 | Lab Complete -------------------------------------------------------------------------------- /Labs/LAB_06/README.md: -------------------------------------------------------------------------------- 1 | # Performance DMV and EXPLAIN [15 Minutes] 2 | 3 | This lab will introduce you to the system views used to monitor performance within Azure SQLDW. We will look at an example query and the execution plan behind it. 4 | 5 | We will: 6 | 1. Bring in the necessary data for our query 7 | 2. Run a large query 8 | 3. Identify performance problems upfront using EXPLAIN 9 | 4. Identify performance problems after execution using DMVS 10 | 11 | # Load the Data 12 | Firstly, let's load a couple of tables from our external polybase layer so we have something to work with: 13 | 14 | ```sql 15 | CREATE TABLE dbo.SalesOrderHeader 16 | WITH 17 | ( 18 | CLUSTERED COLUMNSTORE INDEX, 19 | DISTRIBUTION = ROUND_ROBIN 20 | ) 21 | AS 22 | SELECT * 23 | FROM [ext].SalesOrderHeader 24 | 25 | CREATE TABLE dbo.Customer 26 | WITH 27 | ( 28 | CLUSTERED COLUMNSTORE INDEX, 29 | DISTRIBUTION = ROUND_ROBIN 30 | ) 31 | AS 32 | SELECT * 33 | FROM [ext].Customer 34 | 35 | CREATE TABLE dbo.SalesOrderDetail 36 | WITH 37 | ( 38 | CLUSTERED COLUMNSTORE INDEX, 39 | DISTRIBUTION = ROUND_ROBIN 40 | ) 41 | AS 42 | SELECT * 43 | FROM [ext].SalesOrderDetail 44 | ``` 45 | 46 | Once that has completed, we can now run our query to gather some performance results. 47 | 48 | # Run Query 49 | We've put together a very simple query that joins several tables together - this involves a little bit of data movement and could potentially be optimised, but we don't know how until we know what's happening when we execute the query! 50 | 51 | 52 | ```sql 53 | SELECT 54 | C.[CustomerID], 55 | SUM(CAST([LineTotal] as money)) TotalSales 56 | FROM 57 | dbo.Customer C 58 | INNER JOIN dbo.SalesOrderHeader SOH ON C.CustomerID = SOH.CustomerID 59 | INNER JOIN dbo.SalesOrderDetail SOD ON SOH.SalesOrderID = SOD.SalesOrderID 60 | GROUP BY C.[CustomerID] 61 | OPTION (LABEL = 'This is the query we are interested in') 62 | ``` 63 | 64 | # Using the EXPLAIN Keyword 65 | 66 | Firstly, we can ask Azure SQLDW how it's going to approach the problem. Putting the EXPLAIN keyword in front of the statement produces an XML output. In SSMS currently this is returned as a text result set, you'll need to copy it into a text reader such as VSCode, Visual Studio or Notepad++ to visualise the XML properly. 67 | 68 | ```sql 69 | EXPLAIN 70 | SELECT 71 | C.[CustomerID], 72 | SUM(CAST([LineTotal] as money)) TotalSales 73 | FROM 74 | dbo.Customer C 75 | INNER JOIN dbo.SalesOrderHeader SOH ON C.CustomerID = SOH.CustomerID 76 | INNER JOIN dbo.SalesOrderDetail SOD ON SOH.SalesOrderID = SOD.SalesOrderID 77 | GROUP BY C.[CustomerID] 78 | OPTION (LABEL = 'This is the query we are interested in') 79 | ``` 80 | 81 | You should see the different tags and the various different operation types underneath - Broadcast Move, Shuffle Move etc - these are the data movements that are occurring and could potentially be avoided. 82 | 83 | # Using the performance DMVs 84 | 85 | What if we see performance problems but we don't know the query that caused it? 86 | 87 | First, we can use the sys.dm_pdw_exec_requests view - this tells us all the queries that have been run recently. It can be used to see where queries with large resource classes have been run, what sql statement consisted of and the overall duration. 88 | 89 | ```sql 90 | SELECT * 91 | FROM sys.dm_pdw_exec_requests 92 | ``` 93 | 94 | What was the most expensive query run recently? You might notice that some queries don't have a resource class - that's because any queries on system views or using DDL won't inherit the user's resource class and will automatically use a small rc. You will also notice that each query has a unique ID. What's even more useful - you can see the "Label" for our query, it should be populated with our "This is the query we are interested in" comment! 95 | 96 | But what happened within that statement? We can see the individual steps (data movement, sql etc) by querying another DMV. 97 | 98 | ```sql 99 | SELECT * 100 | FROM sys.dm_pdw_request_steps 101 | WHERE request_id = 102 | ``` 103 | 104 | Put the request you're trying to analyse into the above query and run it. You'll see a number of steps, with details of how long each step took, where it was run (control node, compute nodes or distributions) and whether it was a data movement step or a sql engine step. This will resemble the details you saw in the EXPLAIN plan. 105 | 106 | Finally, we can dig into what each of those steps actually did on each distribution. We have two choices for this - one for SQL operations and another for DMS. 107 | 108 | For SQL tasks: 109 | ```sql 110 | SELECT * 111 | FROM sys.dm_pdw_sql_requests 112 | WHERE request_id = AND step_index = 113 | ``` 114 | 115 | For DMS tasks: 116 | ```sql 117 | SELECT * 118 | FROM sys.dm_pdw_dms_workers 119 | WHERE request_id = AND step_index = 120 | ``` 121 | 122 | With these tools, you can dig right into the details of any queries that have been run recently. 123 | 124 | ## NOTE 125 | These DMVs will only show data collected since the SQL DataWarehouse was last resumed - as new requests come in, older queries will gradually be aged out of these views. -------------------------------------------------------------------------------- /MagicWorks/Abracadabra_PersonPerson.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Abracadabra_PersonPerson.sql -------------------------------------------------------------------------------- /MagicWorks/Abracadabra_Product.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks; 2 | GO 3 | 4 | -- ####################################################################################################################################### 5 | -- Update Product Names 6 | -- ####################################################################################################################################### 7 | SELECT 8 | [Name] 9 | ,Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace([Name],'4Bike','Broom'),'4Bike','Broom'),'Adjustable','Adjustable'),'AllPurpose','AllPurpose'),'Angle','Angle'),'Assembly','Assembly'),'AWC','Horcrux'),'Ball','Ball'),'Bar','Bar'),'BatteryPowered','Magic Powered'),'BB','Elder Wand'),'Bearing','Horcrux'),'Bearings','Exploding Snap'),'BibShorts','Speed shorts'),'Bike','Broom'),'Black','Black'),'Blade','Wand'),'Blue','Blue'),'Bolt','Bolt'),'Bolts','Bolts'),'Bottle','Flask'),'Bottom','Sneakoscope'),'Bracket','Bracket'),'Brakes','Exploding Brakes'),'Cable','Sensor'),'Cage','Cage'),'Cap','Cap'),'Caps','Caps'),'Chain','Chain'),'Chainring','Berties Every Flavour bean'),'Classic','Classic'),'ConeShaped','ConeShaped'),'Crankarm','Wand Part'),'Crankset','Lizard Eye'),'Crown','Crown'),'CupShaped','Marvolo ring'),'Decal','Diary'),'Derailleur','Curse'),'Dissolver','Dissolver'),'Down','Down'),'DualBeam','DualBeam'),'End','End'),'External','External'),'Fender','Fender'),'Flat','Flat'),'Fork','Shaft'),'Frame','Broom'),'Freewheel','Locket'),'Front','Front'),'FullFinger','FullFinger'),'Gloves','Gloves'),'Grip','Grip'),'Guide','Guide'),'HalfFinger','HalfFinger'),'Handlebar','Handlebar'),'Handlebars','Handlebars'),'Head','Head'),'Headlights','Head Illuminator'),'Headset','Headset'),'Helmet','Helmet'),'Hex','Hex'),'Hitch','Hitch'),'Hub','Hub'),'Hydration','Hydration'),'Internal','Internal'),'Jersey','Cloak'),'Keyed','Wand'),'Kit/8','Cape'),'Large','Large'),'Linkage','Linkage'),'Lock','Magical'),'Logo','Clock'),'LongSleeve','LongSleeve'),'Lower','Lower'),'Lug','Lug'),'Mens','Mens'),'Metal','Metal'),'Minipump','Minipump'),'Mountain','Nimbus'),'Nipple','Orc'),'Nut','Nut'),'Pack','Pack'),'Paint','Potion'),'Patch','Patch'),'Patches','Dark Arts'),'Pedal','Pendant'),'Pinch','Pinch'),'Plate','Plate'),'Post','Post'),'Pulley','Pulley'),'Pump','Pump'),'Race','Diadem'),'Racing','Diadems'),'Rack','Rack'),'Rear','Rear'),'Red','Red'),'Reflector','Reflector'),'Rim','Rim'),'Ring','Ring'),'Road','Sky'),'Seat','Seat'),'Seat/Saddle','Seat/Saddle'),'Set','Set'),'Sheet','Sheet'),'Shell','Shell'),'Shorts','Shorts'),'ShortSleeve','ShortSleeve'),'Silver','Silver'),'Socks','Socks'),'Spindle/Axle','Duelling Wands'),'Spokes','Spokes'),'Sport100','Sport100'),'Sports','Quidditch'),'Stand','Stand'),'Stays','Stays'),'Steerer','Steerer'),'Stem','Stem'),'Taillights','Taillights'),'Tape','Tape'),'Tension','Tension'),'ThinJam','ThinJam'),'Tights','Tights'),'Tire','Tire'),'Top','Top'),'Touring','Fire Bolt'),'Tread','Tread'),'Tube','Nimbus'),'Vest','Cloak'),'Wash','Wash'),'Washer','Owl'),'Water','Water'),'Weatherproof','Weatherproof'),'Wheel','Wheel'),'Womens','Womens'),'Yellow','Yellow'),'HL','Must Have'),'LL','Last Year') AS 'MagicalName' 10 | FROM 11 | Production.Product; 12 | 13 | UPDATE Production.Product SET [Name] = Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace([Name],'4Bike','Broom'),'4Bike','Broom'),'Adjustable','Adjustable'),'AllPurpose','AllPurpose'),'Angle','Angle'),'Assembly','Assembly'),'AWC','Horcrux'),'Ball','Ball'),'Bar','Bar'),'BatteryPowered','Magic Powered'),'BB','Elder Wand'),'Bearing','Horcrux'),'Bearings','Exploding Snap'),'BibShorts','Speed shorts'),'Bike','Broom'),'Black','Black'),'Blade','Wand'),'Blue','Blue'),'Bolt','Bolt'),'Bolts','Bolts'),'Bottle','Flask'),'Bottom','Sneakoscope'),'Bracket','Bracket'),'Brakes','Exploding Brakes'),'Cable','Sensor'),'Cage','Cage'),'Cap','Cap'),'Caps','Caps'),'Chain','Chain'),'Chainring','Berties Every Flavour bean'),'Classic','Classic'),'ConeShaped','ConeShaped'),'Crankarm','Wand Part'),'Crankset','Lizard Eye'),'Crown','Crown'),'CupShaped','Marvolo ring'),'Decal','Diary'),'Derailleur','Curse'),'Dissolver','Dissolver'),'Down','Down'),'DualBeam','DualBeam'),'End','End'),'External','External'),'Fender','Fender'),'Flat','Flat'),'Fork','Shaft'),'Frame','Broom'),'Freewheel','Locket'),'Front','Front'),'FullFinger','FullFinger'),'Gloves','Gloves'),'Grip','Grip'),'Guide','Guide'),'HalfFinger','HalfFinger'),'Handlebar','Handlebar'),'Handlebars','Handlebars'),'Head','Head'),'Headlights','Head Illuminator'),'Headset','Headset'),'Helmet','Helmet'),'Hex','Hex'),'Hitch','Hitch'),'Hub','Hub'),'Hydration','Hydration'),'Internal','Internal'),'Jersey','Cloak'),'Keyed','Wand'),'Kit/8','Cape'),'Large','Large'),'Linkage','Linkage'),'Lock','Magical'),'Logo','Clock'),'LongSleeve','LongSleeve'),'Lower','Lower'),'Lug','Lug'),'Mens','Mens'),'Metal','Metal'),'Minipump','Minipump'),'Mountain','Nimbus'),'Nipple','Orc'),'Nut','Nut'),'Pack','Pack'),'Paint','Potion'),'Patch','Patch'),'Patches','Dark Arts'),'Pedal','Pendant'),'Pinch','Pinch'),'Plate','Plate'),'Post','Post'),'Pulley','Pulley'),'Pump','Pump'),'Race','Diadem'),'Racing','Diadems'),'Rack','Rack'),'Rear','Rear'),'Red','Red'),'Reflector','Reflector'),'Rim','Rim'),'Ring','Ring'),'Road','Sky'),'Seat','Seat'),'Seat/Saddle','Seat/Saddle'),'Set','Set'),'Sheet','Sheet'),'Shell','Shell'),'Shorts','Shorts'),'ShortSleeve','ShortSleeve'),'Silver','Silver'),'Socks','Socks'),'Spindle/Axle','Duelling Wands'),'Spokes','Spokes'),'Sport100','Sport100'),'Sports','Quidditch'),'Stand','Stand'),'Stays','Stays'),'Steerer','Steerer'),'Stem','Stem'),'Taillights','Taillights'),'Tape','Tape'),'Tension','Tension'),'ThinJam','ThinJam'),'Tights','Tights'),'Tire','Tire'),'Top','Top'),'Touring','Fire Bolt'),'Tread','Tread'),'Tube','Nimbus'),'Vest','Cloak'),'Wash','Wash'),'Washer','Owl'),'Water','Water'),'Weatherproof','Weatherproof'),'Wheel','Wheel'),'Womens','Womens'),'Yellow','Yellow'),'HL','Must Have'),'LL','Last Year') -------------------------------------------------------------------------------- /MagicWorks/Abracadabra_ProductCategory.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks; 2 | GO 3 | 4 | SELECT 5 | [Name] 6 | , Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace([Name],'Bikes','Brooms'),'Bikes','Brooms'),'Bike','Brrom'),'Components','Wands'),'Component','Wand'),'Clothing','Capes'),'Accessories','Runes'),'Road','Quiddich'),'Chains','Magic Accelarator'),'Mountain','Nimbus'),'Frame','Broom'),'Jerseys','cloaks'),'Vests','Capes'),'Hydration','Potion'),'Lights','Eluminators'),'Pumps','Leviation device') 7 | 8 | FROM 9 | Production.ProductCategory; 10 | 11 | -- ####################################################################################################################################### 12 | -- Update 13 | -- ####################################################################################################################################### 14 | 15 | UPDATE Production.ProductCategory SET [Name] = Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace([Name],'Bikes','Brooms'),'Bikes','Brooms'),'Bike','Brrom'),'Components','Wands'),'Component','Wand'),'Clothing','Capes'),'Accessories','Runes'),'Road','Quiddich'),'Chains','Magic Accelarator'),'Mountain','Nimbus'),'Frame','Broom'),'Jerseys','cloaks'),'Vests','Capes'),'Hydration','Potion'),'Lights','Eluminators'),'Pumps','Leviation device') -------------------------------------------------------------------------------- /MagicWorks/Abracadabra_ProductSubCategory.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks; 2 | GO 3 | 4 | SELECT 5 | [Name] 6 | , Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace([Name],'4Bike','Broom'),'4Bike','Broom'),'Adjustable','Adjustable'),'AllPurpose','AllPurpose'),'Angle','Angle'),'Assembly','Assembly'),'AWC','Horcrux'),'Ball','Ball'),'Bar','Bar'),'BatteryPowered','Magic Powered'),'BB','Elder Wand'),'Bearing','Horcrux'),'Bearings','Exploding Snap'),'BibShorts','Speed shorts'),'Bike','Broom'),'Black','Black'),'Blade','Wand'),'Blue','Blue'),'Bolt','Bolt'),'Bolts','Bolts'),'Bottle','Flask'),'Bottom','Sneakoscope'),'Bracket','Bracket'),'Brakes','Exploding Brakes'),'Cable','Sensor'),'Cage','Cage'),'Cap','Cap'),'Caps','Caps'),'Chain','Chain'),'Chainring','Berties Every Flavour bean'),'Classic','Classic'),'ConeShaped','ConeShaped'),'Crankarm','Wand Part'),'Crankset','Lizard Eye'),'Crown','Crown'),'CupShaped','Marvolo ring'),'Decal','Diary'),'Derailleur','Curse'),'Dissolver','Dissolver'),'Down','Down'),'DualBeam','DualBeam'),'End','End'),'External','External'),'Fender','Fender'),'Flat','Flat'),'Fork','Shaft'),'Frame','Frame'),'Freewheel','Locket'),'Front','Front'),'FullFinger','FullFinger'),'Gloves','Gloves'),'Grip','Grip'),'Guide','Guide'),'HalfFinger','HalfFinger'),'Handlebar','Handlebar'),'Handlebars','Handlebars'),'Head','Head'),'Headlights','Head Illuminator'),'Headset','Headset'),'Helmet','Helmet'),'Hex','Hex'),'Hitch','Hitch'),'Hub','Hub'),'Hydration','Hydration'),'Internal','Internal'),'Jersey','Cloak'),'Keyed','Wand'),'Kit/8','Cape'),'Large','Large'),'Linkage','Linkage'),'Lock','Magical'),'Logo','Clock'),'LongSleeve','LongSleeve'),'Lower','Lower'),'Lug','Lug'),'Mens','Mens'),'Metal','Metal'),'Minipump','Minipump'),'Mountain','Nimbus'),'Nipple','Orc'),'Nut','Nut'),'Pack','Pack'),'Paint','Potion'),'Patch','Patch'),'Patches','Dark Arts'),'Pedal','Pendant'),'Pinch','Pinch'),'Plate','Plate'),'Post','Post'),'Pulley','Pulley'),'Pump','Pump'),'Race','Diadem'),'Racing','Diadems'),'Rack','Rack'),'Rear','Rear'),'Red','Red'),'Reflector','Reflector'),'Rim','Rim'),'Ring','Ring'),'Road','Sky'),'Seat','Seat'),'Seat/Saddle','Seat/Saddle'),'Set','Set'),'Sheet','Sheet'),'Shell','Shell'),'Shorts','Shorts'),'ShortSleeve','ShortSleeve'),'Silver','Silver'),'Socks','Socks'),'Spindle/Axle','Duelling Wands'),'Spokes','Spokes'),'Sport100','Sport100'),'Sports','Quidditch'),'Stand','Stand'),'Stays','Stays'),'Steerer','Steerer'),'Stem','Stem'),'Taillights','Taillights'),'Tape','Tape'),'Tension','Tension'),'ThinJam','ThinJam'),'Tights','Tights'),'Tire','Tire'),'Top','Top'),'Touring','Fire Bolt'),'Tread','Tread'),'Tube','Nimbus'),'Vest','Formal Cloak'),'Wash','Wash'),'Washer','Owl'),'Water','Water'),'Weatherproof','Weatherproof'),'Wheel','Wheel'),'Womens','Womens'),'Yellow','Yellow'),'HL','Must Have'),'LL','Last Year'),'LL','Shaft'),'Cleaners','Potions'),'Fenders','Familiars'),'Headsets','Travel Chests'),'Lights','Illuminators'),'Panniers','Undetectable Extension Charms'),'Shorts','Hats'),'Socks','Charms'),'Tights','Tights'),'Tires','Spells') 7 | 8 | 9 | FROM 10 | Production.ProductSubcategory; 11 | 12 | -- ####################################################################################################################################### 13 | -- Update 14 | -- ####################################################################################################################################### 15 | 16 | UPDATE Production.ProductSubcategory SET [Name] = Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace(Replace([Name],'4Bike','Broom'),'4Bike','Broom'),'Adjustable','Adjustable'),'AllPurpose','AllPurpose'),'Angle','Angle'),'Assembly','Assembly'),'AWC','Horcrux'),'Ball','Ball'),'Bar','Bar'),'BatteryPowered','Magic Powered'),'BB','Elder Wand'),'Bearing','Horcrux'),'Bearings','Exploding Snap'),'BibShorts','Speed shorts'),'Bike','Broom'),'Black','Black'),'Blade','Wand'),'Blue','Blue'),'Bolt','Bolt'),'Bolts','Bolts'),'Bottle','Flask'),'Bottom','Sneakoscope'),'Bracket','Bracket'),'Brakes','Exploding Brakes'),'Cable','Sensor'),'Cage','Cage'),'Cap','Cap'),'Caps','Caps'),'Chain','Chain'),'Chainring','Berties Every Flavour bean'),'Classic','Classic'),'ConeShaped','ConeShaped'),'Crankarm','Wand Part'),'Crankset','Lizard Eye'),'Crown','Crown'),'CupShaped','Marvolo ring'),'Decal','Diary'),'Derailleur','Curse'),'Dissolver','Dissolver'),'Down','Down'),'DualBeam','DualBeam'),'End','End'),'External','External'),'Fender','Fender'),'Flat','Flat'),'Fork','Shaft'),'Frame','Frame'),'Freewheel','Locket'),'Front','Front'),'FullFinger','FullFinger'),'Gloves','Gloves'),'Grip','Grip'),'Guide','Guide'),'HalfFinger','HalfFinger'),'Handlebar','Handlebar'),'Handlebars','Handlebars'),'Head','Head'),'Headlights','Head Illuminator'),'Headset','Headset'),'Helmet','Helmet'),'Hex','Hex'),'Hitch','Hitch'),'Hub','Hub'),'Hydration','Hydration'),'Internal','Internal'),'Jersey','Cloak'),'Keyed','Wand'),'Kit/8','Cape'),'Large','Large'),'Linkage','Linkage'),'Lock','Magical'),'Logo','Clock'),'LongSleeve','LongSleeve'),'Lower','Lower'),'Lug','Lug'),'Mens','Mens'),'Metal','Metal'),'Minipump','Minipump'),'Mountain','Nimbus'),'Nipple','Orc'),'Nut','Nut'),'Pack','Pack'),'Paint','Potion'),'Patch','Patch'),'Patches','Dark Arts'),'Pedal','Pendant'),'Pinch','Pinch'),'Plate','Plate'),'Post','Post'),'Pulley','Pulley'),'Pump','Pump'),'Race','Diadem'),'Racing','Diadems'),'Rack','Rack'),'Rear','Rear'),'Red','Red'),'Reflector','Reflector'),'Rim','Rim'),'Ring','Ring'),'Road','Sky'),'Seat','Seat'),'Seat/Saddle','Seat/Saddle'),'Set','Set'),'Sheet','Sheet'),'Shell','Shell'),'Shorts','Shorts'),'ShortSleeve','ShortSleeve'),'Silver','Silver'),'Socks','Socks'),'Spindle/Axle','Duelling Wands'),'Spokes','Spokes'),'Sport100','Sport100'),'Sports','Quidditch'),'Stand','Stand'),'Stays','Stays'),'Steerer','Steerer'),'Stem','Stem'),'Taillights','Taillights'),'Tape','Tape'),'Tension','Tension'),'ThinJam','ThinJam'),'Tights','Tights'),'Tire','Tire'),'Top','Top'),'Touring','Fire Bolt'),'Tread','Tread'),'Tube','Nimbus'),'Vest','Formal Cloak'),'Wash','Wash'),'Washer','Owl'),'Water','Water'),'Weatherproof','Weatherproof'),'Wheel','Wheel'),'Womens','Womens'),'Yellow','Yellow'),'HL','Must Have'),'LL','Last Year'),'LL','Shaft'),'Cleaners','Potions'),'Fenders','Familiars'),'Headsets','Travel Chests'),'Lights','Illuminators'),'Panniers','Undetectable Extension Charms'),'Shorts','Hats'),'Socks','Charms'),'Tights','Tights'),'Tires','Spells') 17 | 18 | -------------------------------------------------------------------------------- /MagicWorks/AdatisFramework.BuildAnAzureDataWarehouse.ps1: -------------------------------------------------------------------------------- 1 | ############################################################################################################################################ 2 | ############################################################################################################################################ 3 | ## 4 | ## Process: Adatis PowerShell Azure clear and rebuild script 5 | ## Created by: Terry McCann tpm@acl 6 | ## Created on: 01/02/2017 7 | ## Notes: This powershell script is all variable and config driven. A json config file is required to populate the variables. 8 | ## 1 Read a file 9 | ## 2 replace parts of the file 10 | ## 3 Read data from a sql database / Option to not read from a DB but from a file 11 | ############################################################################################################################################ 12 | ############################################################################################################################################ 13 | 14 | Remove-Variable * -ErrorAction SilentlyContinue 15 | 16 | $BlobAccountName = 'magicworksblob7' 17 | $BlobStorageKey = 'dpUqFYVTcV8SCVf/sV/qX76sRGpEi/PQVlvdg/xiR8PJALPiYuJXNBn/HLbV4mQ5kX5aAurYVoBXQo4kjNCxGA==' 18 | $DatabaseName= 'Adventureworks' 19 | $UserNameShort = 'acl\tpm' 20 | 21 | $query = "EXEC datawarehouse.AdatisASDWMetadata; " 22 | 23 | 24 | 25 | ## ------ Change filepath to existing configuration file ------ ## 26 | #$PowerShellConfigFilePath = 'C:\Users\tpm\Dropbox\Presentations\Data Factory\Introduction to ADF\Exeter 20170330\SQLSouthWest\Config.json' 27 | #$Config = Get-Content $PowerShellConfigFilePath | ConvertFrom-Json 28 | 29 | #Storage Sunscription 30 | $ctx = New-AzureStorageContext -StorageAccountName $BlobAccountName -StorageAccountKey $BlobStorageKey 31 | 32 | #Create your SQL connection string, and then a connection to Wrestlers 33 | $ServerAConnectionString = 'Data Source='+$ServerName+';Initial Catalog='+$DatabaseName+';User Id='+ $UserNameShort +';Integrated Security = True' 34 | $ServerAConnection = new-object system.data.SqlClient.SqlConnection($ServerAConnectionString); 35 | 36 | #------------ 37 | $dataSet = new-object "System.Data.DataSet" "MetadataDataset" 38 | $dataAdapter = new-object "System.Data.SqlClient.SqlDataAdapter" ($query, $ServerAConnection) 39 | $dataAdapter.Fill($dataSet) | Out-Null 40 | 41 | #----------- Remove any existing containers ------------# 42 | foreach ($Row in $dataSet.Tables[0].Rows) 43 | { 44 | $ContainerName = $Row[1].ToLower() 45 | Write-Host $ContainerName 46 | $ExistingContainer = Get-AzureStorageContainer -Name $ContainerName -Context $ctx -ErrorAction Ignore 47 | if ($ExistingContainer -eq $null){ 48 | New-AzureStorageContainer -Name $ContainerName -Context $ctx 49 | } 50 | } 51 | 52 | #Create your SQL connection string, and then a connection to Wrestlers 53 | $ServerBConnectionString = 'Data Source='+$ServerName+';Initial Catalog=AdventureWorksDW2012;User Id='+ $UserNameShort +';Integrated Security = True' 54 | $ServerBConnection = new-object system.data.SqlClient.SqlConnection($ServerBConnectionString); 55 | 56 | #------------ 57 | $dataSetB = new-object "System.Data.DataSet" "MetadataDatasetB" 58 | $dataAdapterB = new-object "System.Data.SqlClient.SqlDataAdapter" ($query, $ServerBConnection) 59 | $dataAdapterB.Fill($dataSetB) | Out-Null 60 | 61 | #----------- Remove any existing containers ------------# 62 | foreach ($Row in $dataSetB.Tables[0].Rows) 63 | { 64 | $ContainerName = $Row[1].ToLower() 65 | Write-Host $ContainerName 66 | $ExistingContainer = Get-AzureStorageContainer -Name $ContainerName -Context $ctx -ErrorAction Ignore 67 | if ($ExistingContainer -eq $null){ 68 | New-AzureStorageContainer -Name $ContainerName -Context $ctx 69 | } 70 | } 71 | 72 | 73 | 74 | #----------------------------------------------------------------------------------------------------------- 75 | #Upload files in to blob storage. 76 | 77 | #MagicWorks 78 | $ConfigFile = Import-Csv "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks\config.txt" -Delimiter "," -Header A,B,C, D 79 | 80 | foreach ($item in $ConfigFile) 81 | { 82 | # Disable TM 83 | Write-Host $item.B 84 | iex $item.D 85 | ##New-AzureStorageContainer -Name $item.BlobName -Context $ctx 86 | } 87 | 88 | #MagicWorksDW 89 | $ConfigFile = Import-Csv "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\config.txt" -Delimiter "," -Header A,B,C, D 90 | 91 | foreach ($item in $ConfigFile) 92 | { 93 | # Disable TM 94 | Write-Host $item.B 95 | iex $item.D 96 | ##New-AzureStorageContainer -Name $item.BlobName -Context $ctx 97 | } -------------------------------------------------------------------------------- /MagicWorks/AdatisFramework.Cleardown.sql: -------------------------------------------------------------------------------- 1 | --SELECT 2 | --'BEGIN TRY 3 | -- DROP EXTERNAL TABLE [' + S.Name + '].[' + T.Name + '] 4 | --END TRY 5 | --BEGIN CATCH 6 | -- PRINT ''No Need'' 7 | --END CATCH' 8 | --FROM 9 | -- sys.tables AS T 10 | --INNER JOIN sys.schemas AS S ON S.schema_id = T.schema_id 11 | --WHERE S.Name = 'ext' 12 | -------------------------------------------------------------------------------- /MagicWorks/AdatisFramework.CreateMultipleInstancesOfAzureSQLDW.ps1: -------------------------------------------------------------------------------- 1 | ############################################################################################################################## 2 | ## 3 | ## 4 | ## 5 | ## 6 | ## 7 | ############################################################################################################################## 8 | 9 | #$AzureLogin = Login-AzureRmAccount 10 | 11 | $resourceGroupLocation = 'North Europe' 12 | Select-AzureRmSubscription -SubscriptionName 'MICROSOFT AZURE SPONSORSHIP' 13 | 14 | 15 | 16 | 17 | $j = 70 18 | 19 | for ($i=1; $i -le $j; $i++) 20 | { 21 | 22 | $AzureSQLDataWarehouseName = $('sqlbits2018User'+$i) 23 | ####################################### 24 | $DatabaseServer = 'magicadventure' 25 | $ResourceGroup = 'sqlbits2018' 26 | $ResourceGroupLocation = 'North Europe' 27 | $TemplateStore = 'G:\GitHub\MagicWorks\DeploymentTemplates\' 28 | ####################################### 29 | $AzureSQLDataWarehouseServer = 'magicadventure' 30 | $AzureSQLDataWarehouseUser = 'gandalf' 31 | $AzureSQLDataWarehousePassword = 'Password1234!' 32 | ####################################### 33 | 34 | 35 | $ASDW = Get-AzureRmSqlDatabase -DatabaseName $AzureSQLDataWarehouseName -ServerName $DatabaseServer -ResourceGroupName $ResourceGroup -ErrorAction SilentlyContinue 36 | 37 | if ($ASDW -eq $null) { 38 | 39 | Write-Host $AzureSQLDataWarehouseName "Started deployment" -ForegroundColor Cyan 40 | 41 | New-AzureRmSqlDatabase -RequestedServiceObjectiveName "DW100" -DatabaseName $AzureSQLDataWarehouseName -ServerName $DatabaseServer -ResourceGroupName $ResourceGroup -Edition "DataWarehouse" -CollationName "SQL_Latin1_General_CP1_CI_AS" -MaxSizeBytes 10995116277760 | out-null 42 | 43 | Write-Host $AzureSQLDataWarehouseName "Created" -ForegroundColor Green 44 | } else { 45 | Write-Host $AzureSQLDataWarehouseName "Already exists" -ForegroundColor Yellow 46 | } 47 | # ------------ Process all transform scripts ---------- # 48 | Get-ChildItem "G:\GitHub\Labs\BuildAutomation\" -Filter *.sql | 49 | Foreach-Object { 50 | $content = Get-Content $_.FullName | Out-String 51 | #$content 52 | $spm = $content 53 | $_.FullName 54 | 55 | $params = @{ 56 | 'Database' = $AzureSQLDataWarehouseName 57 | 'ServerInstance' = 'tcp:magicadventure.database.windows.net' 58 | 'Username' = $AzureSQLDataWarehouseUser 59 | 'Password' = $AzureSQLDataWarehousePassword 60 | 'OutputSqlErrors' = $true 61 | 'Query' = $spm 62 | } 63 | 64 | Invoke-Sqlcmd @params 65 | 66 | } 67 | 68 | 69 | 70 | $DataWarehouse = $null 71 | $ASDW = $null 72 | 73 | } 74 | -------------------------------------------------------------------------------- /MagicWorks/AdatisFramework.Metadata.sql: -------------------------------------------------------------------------------- 1 | BEGIN TRY 2 | DROP PROCEDURE datawarehouse.AdatisASDWMetadata 3 | END TRY 4 | BEGIN CATCH 5 | PRINT 'No Need' 6 | END CATCH; 7 | GO 8 | 9 | CREATE PROCEDURE datawarehouse.AdatisASDWMetadata 10 | as 11 | BEGIN 12 | 13 | BEGIN TRY 14 | DROP TABLE #ColumnMetadata 15 | END TRY 16 | BEGIN CATCH 17 | PRINT 'No Need' 18 | END CATCH; 19 | 20 | 21 | CREATE TABLE #ColumnMetadata 22 | ( 23 | [TableName] VARCHAR(500), 24 | [TableNameShort] VARCHAR(500), 25 | [LooselyTyped] VARCHAR(8000), 26 | [StronglyTyped] VARCHAR(8000), 27 | [SelectColumns] VARCHAR(8000), 28 | [StronglyTypedCast] VARCHAR(8000), 29 | [BlobName] VARCHAR(500), 30 | [PrimaryKey] VARCHAR(500), 31 | [Quoted] VARCHAR(8000) 32 | ) 33 | 34 | 35 | DECLARE @TableName VARCHAR(50); 36 | DECLARE @SchemaNameShort VARCHAR(50); 37 | DECLARE @TableNameShort VARCHAR(50); 38 | DECLARE db_cursor_outer CURSOR 39 | FOR 40 | with this as ( 41 | SELECT CONCAT('[',s.name,'].[', t.name, ']') 'TableAttribute', s.name AS 'SchemaNameShort', t.name AS 'TableNameShort' FROM sys.tables AS T INNER JOIN sys.schemas AS S ON S.schema_id = T.schema_id 42 | --union all 43 | --SELECT CONCAT('[',s.name,'].[', t.name, ']') FROM sys.views AS T INNER JOIN sys.schemas AS S ON S.schema_id = T.schema_id 44 | ) 45 | SELECT * FROM this 46 | 47 | 48 | 49 | OPEN db_cursor_outer; 50 | FETCH NEXT FROM db_cursor_outer INTO @TableName, @SchemaNameShort, @TableNameShort; 51 | 52 | WHILE @@FETCH_STATUS = 0 53 | BEGIN 54 | 55 | DECLARE @OverWriteColumn VARCHAR(50) = 'Nvarchar(500)'; 56 | DECLARE @ColumnName VARCHAR(50); 57 | DECLARE @TypeName VARCHAR(50); 58 | DECLARE @TypeLength VARCHAR(50); 59 | DECLARE @SQL VARCHAR(8000); 60 | DECLARE @SQL2 VARCHAR(8000); 61 | DECLARE @SQL3 VARCHAR(8000); 62 | DECLARE @SQL4 VARCHAR(8000); 63 | DECLARE @SQL5 VARCHAR(8000); 64 | DECLARE @DatabaseName VARCHAR(150) = DB_NAME() 65 | 66 | DECLARE @listStr VARCHAR(MAX) 67 | SELECT @listStr = COALESCE(@listStr+',' ,'') + 68 | COL_NAME(ic.object_id,ic.column_id) 69 | FROM 70 | sys.indexes AS i 71 | INNER JOIN sys.index_columns AS ic ON i.object_id = ic.object_id 72 | AND i.index_id = ic.index_id 73 | WHERE 74 | i.is_primary_key = 1 75 | AND OBJECT_NAME(ic.object_id) = REPLACE(REPLACE(SUBSTRING(@TableName, CHARINDEX('.', @TableName)+1,100),'[',''),']','') 76 | 77 | 78 | 79 | DECLARE db_cursor CURSOR 80 | FOR 81 | SELECT 82 | C.name 83 | , T2.Name 84 | , case when C.max_length >= 4000 then 4000 else C.max_length end as max_length 85 | FROM 86 | sys.tables AS T 87 | INNER JOIN sys.columns AS C ON C.object_id = T.object_id 88 | INNER JOIN sys.types AS T2 ON T2.user_type_id = C.user_type_id 89 | INNER JOIN sys.schemas AS S ON S.schema_id = T.schema_id 90 | WHERE 91 | '[' + S.name + '].[' + T.name + ']' = @TableName AND t2.Name <> 'sysname' 92 | union all 93 | SELECT 94 | C.name 95 | , T2.Name 96 | , case when C.max_length >= 4000 then 4000 else C.max_length end as max_length 97 | FROM 98 | sys.views AS T 99 | INNER JOIN sys.columns AS C ON C.object_id = T.object_id 100 | INNER JOIN sys.types AS T2 ON T2.system_type_id = C.system_type_id 101 | INNER JOIN sys.schemas AS S ON S.schema_id = T.schema_id 102 | WHERE 103 | '[' + S.name + '].[' + T.name + ']' = @TableName AND t2.Name <> 'sysname' 104 | OPEN db_cursor; 105 | FETCH NEXT FROM db_cursor INTO @ColumnName, @TypeName, @TypeLength; 106 | 107 | SET @SQL = '' 108 | SET @SQL2 = '' 109 | SET @SQL3 = '' 110 | SET @SQL4 = '' 111 | SET @SQL5 = '' 112 | 113 | WHILE @@FETCH_STATUS = 0 114 | BEGIN 115 | 116 | SET @SQL = @SQL + ' [' + @ColumnName + '] ' + 117 | CASE 118 | WHEN @TypeLength > 500 and @TypeLength <= 4000 THEN 'NVARCHAR(' + @TypeLength +')' 119 | WHEN @TypeLength >4000 THEN 'NVARCHAR(4000)' 120 | WHEN @TypeName = 'CHAR' THEN 'NVARCHAR(500)' 121 | WHEN @TypeName = 'BOOLEAN' THEN 'NVARCHAR(5)' 122 | WHEN @TypeName = 'BIGINT' THEN 'NVARCHAR(250)' 123 | WHEN @TypeName = 'INT' THEN 'NVARCHAR(50)' 124 | WHEN @TypeName = 'DECIMAL' THEN 'NVARCHAR(50)' 125 | WHEN @TypeName = 'NUMERIC' THEN 'NVARCHAR(50)' 126 | WHEN @TypeName = 'FLOAT' THEN 'NVARCHAR(50)' 127 | WHEN @TypeName = 'REAL' THEN 'NVARCHAR(50)' 128 | WHEN @TypeName = 'DOUBLE' THEN 'NVARCHAR(50)' 129 | WHEN @TypeName = 'DATE' THEN 'NVARCHAR(50)' 130 | WHEN @TypeName = 'DATETIME' THEN 'NVARCHAR(50)' 131 | WHEN @TypeName = 'TIME' THEN 'NVARCHAR(50)' 132 | WHEN @TypeName = 'TIMESTAMP' THEN 'NVARCHAR(50)' 133 | ELSE 'NVARCHAR(500)' END + ' ,' + CHAR(13) + CHAR(10) 134 | --CASE WHEN @TypeName IN ('int', 'money', 'datetime', 'bit','smallint','varbinary','date','tinyint') THEN '' ELSE '(' + @TypeLength + ')' END + ' NULL , ' + CHAR(13) 135 | 136 | 137 | 138 | SET @SQL2 = @SQL2 + ' [' + @ColumnName + '] , '+ CHAR(13) + CHAR(10) 139 | SET @SQL5 = @SQL5 + ' QUOTENAME(' + @ColumnName + ', CHAR(34)) , '+ CHAR(13) + CHAR(10) 140 | SET @SQL3 = @SQL3 + ' [' + @ColumnName + '] ' + @TypeName + CASE WHEN @TypeName = 'Decimal' THEN '(12,5) ' WHEN @TypeName IN ('int', 'money', 'datetime', 'bit','smallint','varbinary','date','tinyint','uniqueidentifier') THEN '' ELSE '(' + @TypeLength + ')' END + ' , ' + CHAR(13) + CHAR(10) 141 | SET @SQL4 = @SQL4 + CASE WHEN @TypeName = 'datetime' THEN ' CONVERT(datetime, LEFT(' + @ColumnName + ',22), 101' ELSE ' CAST(' + @ColumnName + ' AS ' + @TypeName + CASE WHEN @TypeName = 'Decimal' THEN '(12,5)' WHEN @TypeName IN ('int', 'money', 'datetime', 'bit','smallint','varbinary','date','tinyint','uniqueidentifier') THEN '' ELSE '(' + @TypeLength + ')' END END + ') AS '+@ColumnName+', '+ CHAR(13) + CHAR(10) 142 | FETCH NEXT FROM db_cursor INTO @ColumnName, @TypeName, @TypeLength; 143 | END; 144 | 145 | CLOSE db_cursor; 146 | DEALLOCATE db_cursor; 147 | 148 | INSERT INTO #ColumnMetadata 149 | SELECT 150 | @TableName 151 | , REPLACE(REPLACE(SUBSTRING(@TableName, CHARINDEX('.', @TableName)+1,100),'[',''),']','') 152 | , LEFT(@SQL, CASE WHEN LEN(@sql) = 0 THEN LEN(@Sql) ELSE LEN(@Sql)-4 END ) 'LooselyTyped' 153 | , LEFT(@SQL3, CASE WHEN LEN(@sql3) = 0 THEN LEN(@Sql3) ELSE LEN(@Sql3)-4 END ) AS 'StronglyTyped' 154 | , LEFT(@SQL2, CASE WHEN LEN(@sql2) = 0 THEN LEN(@Sql2) ELSE LEN(@Sql2)-4 END ) AS 'ColumnSelect' 155 | , LEFT(@SQL4, CASE WHEN LEN(@sql4) = 0 THEN LEN(@Sql4) ELSE LEN(@Sql4)-4 END ) 156 | , replace(LOWER(REPLACE(REPLACE(REPLACE(@TableName, '[', ''),']',''),'.','')),'vw','') 157 | , @listStr 158 | , 'EXEC xp_cmdshell ''bcp "SELECT ' + LEFT(@SQL5, CASE WHEN LEN(@sql5) = 0 THEN LEN(@Sql5) ELSE LEN(@Sql5)-4 END ) + ' FROM ' + @DatabaseName + '.' + @TableName + '" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\'+@SchemaNameShort+'_'+@TableNameShort+'.txt" -T -c -t,''' AS 'Export' 159 | 160 | --END 161 | --GO 162 | SET @listStr = NULL 163 | FETCH NEXT FROM db_cursor_outer INTO @TableName, @SchemaNameShort, @TableNameShort; 164 | END; 165 | 166 | CLOSE db_cursor_outer; 167 | DEALLOCATE db_cursor_outer; 168 | 169 | SELECT * FROM #ColumnMetadata AS CM WHERE CM.LooselyTyped IS NOT NULL AND CM.LooselyTyped <> '' 170 | 171 | END 172 | 173 | GO 174 | 175 | 176 | EXEC datawarehouse.AdatisASDWMetadata 177 | 178 | 179 | -------------------------------------------------------------------------------- /MagicWorks/BCPTablesFrom SQLToFileOLAP.sql: -------------------------------------------------------------------------------- 1 | use AdventureWorksDW2012; 2 | GO 3 | 4 | EXEC master.dbo.sp_configure 'show advanced options', 1 5 | RECONFIGURE 6 | EXEC master.dbo.sp_configure 'xp_cmdshell', 1 7 | RECONFIGURE; 8 | 9 | BEGIN TRY 10 | DROP VIEW dbo.config 11 | END TRY 12 | BEGIN CATCH 13 | PRINT 'No Need' 14 | END CATCH; 15 | GO 16 | 17 | CREATE VIEW dbo.config AS 18 | SELECT 19 | s.Name AS 'SchemaName' 20 | , T.NAme AS 'TableName' 21 | , 'EXEC xp_cmdshell ''bcp "SELECT * FROM AdventureWorksDW2012.' + s.Name +'.'+ T.NAme + '" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\' + s.Name +'_'+ T.NAme + '.txt" -T -c -t''' AS 'Export' 22 | , 'AzCopy /Source:"G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW" /Dest:https://magicworksblob.blob.core.windows.net/'+ LOWER(T.NAme) + ' /DestKey:WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA== /Pattern:"' + s.Name +'_'+ T.NAme + '.txt" /y' AS 'Import' 23 | FROM 24 | sys.tables t 25 | INNER JOIN sys.schemas S ON S.schema_id = t.schema_id; 26 | GO 27 | 28 | SELECT * FROM dbo.config 29 | 30 | EXEC xp_cmdshell 'bcp "SELECT * FROM adventureworksDW2012.dbo.config" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\config.txt" -T -c -t,' 31 | 32 | -- ####################################################################################################################################### 33 | -- 34 | -- ####################################################################################################################################### 35 | 36 | use AdventureWorksDW2012; 37 | GO 38 | 39 | EXEC master.dbo.sp_configure 'show advanced options', 1 40 | RECONFIGURE 41 | EXEC master.dbo.sp_configure 'xp_cmdshell', 1 42 | RECONFIGURE 43 | 44 | SELECT 45 | s.Name 46 | , T.NAme 47 | , 'EXEC xp_cmdshell ''bcp "SELECT * FROM AdventureWorksDW2012.' + s.Name +'.'+ T.NAme + '" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\' + s.Name +'_'+ T.NAme + '.txt" -T -c -t,''' 48 | , 'AzCopy /Source:"G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW" /Dest:https://magicworksblob.blob.core.windows.net/bcptest /DestKey:WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA== /Pattern:"bcptest.txt"' 49 | FROM 50 | sys.tables t 51 | INNER JOIN sys.schemas S ON S.schema_id = t.schema_id 52 | -------------------------------------------------------------------------------- /MagicWorks/BCPTablesFrom SQLToFileOLTP.sql: -------------------------------------------------------------------------------- 1 | use AdventureWorks; 2 | GO 3 | 4 | EXEC master.dbo.sp_configure 'show advanced options', 1 5 | RECONFIGURE 6 | EXEC master.dbo.sp_configure 'xp_cmdshell', 1 7 | RECONFIGURE; 8 | 9 | BEGIN TRY 10 | DROP VIEW dbo.config 11 | END TRY 12 | BEGIN CATCH 13 | PRINT 'No Need' 14 | END CATCH; 15 | GO 16 | 17 | CREATE VIEW dbo.config AS 18 | SELECT 19 | s.Name AS 'SchemaName' 20 | , T.NAme AS 'TableName' 21 | , 'EXEC xp_cmdshell ''bcp "SELECT * FROM AdventureWorks.' + s.Name +'.'+ T.NAme + '" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks\' + s.Name +'_'+ T.NAme + '.txt" -T -c -t -q''' AS 'Export' 22 | , 'AzCopy /Source:"G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks" /Dest:https://magicworksblob.blob.core.windows.net/'+ LOWER(T.NAme) + ' /DestKey:WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA== /Pattern:"' + s.Name +'_'+ T.NAme + '.txt" /y' AS 'Import' 23 | FROM 24 | sys.tables t 25 | INNER JOIN sys.schemas S ON S.schema_id = t.schema_id; 26 | GO 27 | 28 | SELECT * FROM dbo.config 29 | 30 | EXEC xp_cmdshell 'bcp "SELECT * FROM adventureworks.dbo.config" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks\config.txt" -T -c -t,' 31 | -------------------------------------------------------------------------------- /MagicWorks/BCPTablesFrom SQLToFilesql.sql: -------------------------------------------------------------------------------- 1 | use AdventureWorks; 2 | GO 3 | 4 | EXEC master.dbo.sp_configure 'show advanced options', 1 5 | RECONFIGURE 6 | EXEC master.dbo.sp_configure 'xp_cmdshell', 1 7 | RECONFIGURE; 8 | 9 | BEGIN TRY 10 | DROP VIEW dbo.config 11 | END TRY 12 | BEGIN CATCH 13 | PRINT 'No Need' 14 | END CATCH; 15 | GO 16 | 17 | CREATE VIEW dbo.config AS 18 | SELECT 19 | s.Name AS 'SchemaName' 20 | , T.NAme AS 'TableName' 21 | , 'EXEC xp_cmdshell ''bcp "SELECT * FROM AdventureWorks' + s.Name +'.'+ T.NAme + '" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\' + s.Name +'_'+ T.NAme + '.txt" -T -c -t''' AS 'Export' 22 | , 'AzCopy /Source:"G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks" /Dest:https://magicworksblob.blob.core.windows.net/'+ LOWER(T.NAme) + ' /DestKey:WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA== /Pattern:"' + s.Name +'_'+ T.NAme + '.txt" /y' AS 'Import' 23 | FROM 24 | sys.tables t 25 | INNER JOIN sys.schemas S ON S.schema_id = t.schema_id; 26 | GO 27 | 28 | SELECT * FROM dbo.config 29 | 30 | EXEC xp_cmdshell 'bcp "SELECT * FROM adventureworks.dbo.config" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks\config.txt" -T -c -t,' 31 | 32 | -- ####################################################################################################################################### 33 | -- 34 | -- ####################################################################################################################################### 35 | 36 | use AdventureWorksDW2012; 37 | GO 38 | 39 | EXEC master.dbo.sp_configure 'show advanced options', 1 40 | RECONFIGURE 41 | EXEC master.dbo.sp_configure 'xp_cmdshell', 1 42 | RECONFIGURE 43 | 44 | SELECT 45 | s.Name 46 | , T.NAme 47 | , 'EXEC xp_cmdshell ''bcp "SELECT * FROM AdventureWorksDW2012.' + s.Name +'.'+ T.NAme + '" queryout "G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorksDW\' + s.Name +'_'+ T.NAme + '.txt" -T -c -t,''' 48 | , 'AzCopy /Source:"G:\Adatis\SQLBits - SQLDW Planning - General\ExportedData\MagicWorks" /Dest:https://magicworksblob.blob.core.windows.net/bcptest /DestKey:WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA== /Pattern:"bcptest.txt"' 49 | FROM 50 | sys.tables t 51 | INNER JOIN sys.schemas S ON S.schema_id = t.schema_id 52 | -------------------------------------------------------------------------------- /MagicWorks/DeploymentTemplates/AzureSQLDWCreateLoginAgainstAzureSQLDW.txt: -------------------------------------------------------------------------------- 1 | CREATE USER %UserName% FOR LOGIN %UserName%Login; -------------------------------------------------------------------------------- /MagicWorks/DeploymentTemplates/AzureSQLDWCreateLoginAgainstMaster.txt: -------------------------------------------------------------------------------- 1 | CREATE LOGIN %UserName%Login WITH PASSWORD = '%Password%'; 2 | CREATE USER %UserName% FOR LOGIN %UserName%Login; -------------------------------------------------------------------------------- /MagicWorks/MagicWorks.InitialBuildScript.sql: -------------------------------------------------------------------------------- 1 | -- ####################################################################################################################################### 2 | -- Create a Master Key 3 | -- ####################################################################################################################################### 4 | CREATE MASTER KEY; 5 | 6 | -- ####################################################################################################################################### 7 | -- Create a Scoped Credential 8 | -- ####################################################################################################################################### 9 | CREATE DATABASE SCOPED CREDENTIAL AzureStorageCredential 10 | WITH 11 | IDENTITY = 'user', 12 | SECRET = 'WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA==' 13 | ; 14 | 15 | -- ####################################################################################################################################### 16 | --Create a File format 17 | -- ####################################################################################################################################### 18 | CREATE EXTERNAL FILE FORMAT TextFile 19 | WITH ( 20 | FORMAT_TYPE = DelimitedText, 21 | FORMAT_OPTIONS (FIELD_TERMINATOR = ',') 22 | ); 23 | 24 | -- ####################################################################################################################################### 25 | -- Create a schema 26 | -- ####################################################################################################################################### 27 | CREATE SCHEMA ext; 28 | GO 29 | 30 | CREATE SCHEMA oltp; 31 | GO 32 | 33 | CREATE SCHEMA olap; 34 | GO 35 | 36 | -- ####################################################################################################################################### 37 | -- 38 | -- ####################################################################################################################################### 39 | 40 | -------------------------------------------------------------------------------- /MagicWorks/MagicWorks_SampleQueries.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks; 2 | GO 3 | 4 | SELECT 5 | P.FirstName + ' ' + P.LastName 6 | , ProductCategory.Name 7 | , ProductSubCategory.Name 8 | , Product.Name 9 | 10 | FROM Sales.SalesOrderDetail SOD 11 | INNER JOIN Sales.SalesOrderHeader SOH ON SOH.SalesOrderID = SOD.SalesOrderID 12 | INNER JOIN Production.Product ON Product.ProductID = SOD.ProductID 13 | INNER JOIN Production.ProductSubcategory ON ProductSubcategory.ProductSubcategoryID = Product.ProductSubcategoryID 14 | INNER JOIN Production.ProductCategory ON ProductCategory.ProductCategoryID = ProductSubcategory.ProductCategoryID 15 | INNER JOIN Person.Person P ON P.BusinessEntityID = SOH.CustomerID -------------------------------------------------------------------------------- /MagicWorks/Microsoft.RestoreAzureSQLDataWareouse.ps1: -------------------------------------------------------------------------------- 1 |  2 | $SubscriptionName="Microsoft Azure Sponsorship" 3 | $ResourceGroupName="sqlbits2018" 4 | $ServerName="magicadventure" # Without database.windows.net 5 | $DatabaseName="sqlbits2018" 6 | $NewDatabaseName="restoredsqlbits2" 7 | 8 | Login-AzureRmAccount 9 | Get-AzureRmSubscription 10 | Select-AzureRmSubscription -SubscriptionName $SubscriptionName 11 | 12 | # List the last 10 database restore points 13 | ((Get-AzureRMSqlDatabaseRestorePoints -ResourceGroupName $ResourceGroupName -ServerName $ServerName -DatabaseName ($DatabaseName)).RestorePointCreationDate)[-10 .. -1] 14 | 15 | # Or list all restore points 16 | Get-AzureRmSqlDatabaseRestorePoints -ResourceGroupName $ResourceGroupName -ServerName $ServerName -DatabaseName $DatabaseName 17 | 18 | # Get the specific database to restore 19 | $Database = Get-AzureRmSqlDatabase -ResourceGroupName $ResourceGroupName -ServerName $ServerName -DatabaseName $DatabaseName 20 | 21 | # Pick desired restore point using RestorePointCreationDate 22 | $PointInTime="20 February 2018 12:43:42" 23 | 24 | # Restore database from a restore point 25 | $RestoredDatabase = Restore-AzureRmSqlDatabase –FromPointInTimeBackup –PointInTime $PointInTime -ResourceGroupName $Database.ResourceGroupName -ServerName $Database.ServerName -TargetDatabaseName $NewDatabaseName –ResourceId $Database.ResourceID 26 | 27 | # Verify the status of restored database 28 | $RestoredDatabase.status -------------------------------------------------------------------------------- /MagicWorks/NormalToMagicConversion.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/NormalToMagicConversion.xlsx -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/AdatisFramewor.DeploySQLToAzureSQLDW.ps1: -------------------------------------------------------------------------------- 1 | # -------------------------------------------------------------------------------- # 2 | # Purpose: To create the Json objects for ADF 3 | # Createded by: Terry McCann (Adatis consulting limited) 4 | # Created on: 30/01/2017 5 | # Version history: 6 | # V1 - 7 | # -------------------------------------------------------------------------------- # 8 | 9 | 10 | #---------------- This script does the following ----------------------# 11 | 12 | # 1 Read a file 13 | # 2 replace parts of the file 14 | # 3 Read data from a sql database / Option to not read from a DB but from a file 15 | 16 | # VARIABLES: 17 | # %CREATETIME% - A datetime stamp for the auto-comments within the script. Populated at script runtime 18 | # %ENTITYNAME% - The name of the entity, this is the table name across the various warehouse stages 19 | # %COLUMNLIST% - Comma-separated list of columns within the entity 20 | # %COLUMNTYPINGS% - Comma-separated list of columns within the entity, including CAST() and ISNULL() wrappers to enforce target datatypes 21 | # %COLUMNEXTDDL% - Comma-separated list of columns within the entity, including polybase datatype 22 | # %BLOBACCOUNT% - Name of the blob storage account 23 | # %CONTAINERNAME% - Name of the entity-specific container within blob storage 24 | # %FILEFORMAT% - Name of the file format external resource that describes the filetype this entity belongs to 25 | # %CREDENTIALNAME% 26 | 27 | 28 | ## Normal user 29 | #$UserName = 'adwadmin' 30 | #$Password = '' 31 | 32 | ## Large User 33 | $UserName = 'gandalf' 34 | $Password = 'Password1234!' 35 | 36 | 37 | $DataWarehouseName = 'sqlbits2018' 38 | $ServerName = 'tcp:magicadventure.database.windows.net' 39 | 40 | $BlobStorageKey = '' 41 | $BlobAccountName = '' 42 | $CreateTime = Get-Date 43 | 44 | 45 | 46 | # ------------ Process all transform scripts ---------- # 47 | Get-ChildItem "G:\GitHub\MagicWorks\Polybase Generation\SQLToBeDeployed" -Filter *.dsql | 48 | Foreach-Object { 49 | $content = Get-Content $_.FullName | Out-String 50 | #$content 51 | $spm = $content 52 | $_.FullName 53 | 54 | $params = @{ 55 | 'Database' = $DataWarehouseName 56 | 'ServerInstance' = 'tcp:magicadventure.database.windows.net' 57 | 'Username' = $UserName 58 | 'Password' = $Password 59 | 'OutputSqlErrors' = $true 60 | 'Query' = $spm 61 | } 62 | 63 | Invoke-Sqlcmd @params 64 | 65 | } 66 | -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/AdatisFramework.GenerateDeploymentSQL.ps1: -------------------------------------------------------------------------------- 1 | ############################################################################################################################################ 2 | ############################################################################################################################################ 3 | ## 4 | ## Process: Adatis PowerShell Azure clear and rebuild script 5 | ## Created by: Terry McCann tpm@acl 6 | ## Created on: 01/02/2017 7 | ## Notes: This powershell script is all variable and config driven. A json config file is required to populate the variables. 8 | ## 1 Read a file 9 | ## 2 replace parts of the file 10 | ## 3 Read data from a sql database / Option to not read from a DB but from a file 11 | ############################################################################################################################################ 12 | ############################################################################################################################################ 13 | 14 | Remove-Variable * -ErrorAction SilentlyContinue 15 | 16 | 17 | ## ------ Change filepath to existing configuration file ------ ## 18 | $PowerShellConfigFilePath = 'G:\GitHub\MagicWorks\Polybase Generation\Config.json' 19 | $Config = Get-Content $PowerShellConfigFilePath | ConvertFrom-Json 20 | 21 | ## ------ Set by config file ------ ## 22 | $MetadataFilePath = $Config.MetadataFilePath 23 | $MasterTemplateLocation = $Config.MasterTemplateLocation 24 | $AzureSQLDataWarehouseName = $Config.AzureSQLDataWarehouseName 25 | $AzureSQLDataWarehouseServer = $Config.AzureSQLDataWarehouseServer 26 | $AzureSQLDataWarehouseNameAdminUserName = $Config.AzureSQLDataWarehouseNameAdminUserName 27 | $AzureSQLDataWarehouseNameAdminPassword = $Config.AzureSQLDataWarehouseNameAdminPassword 28 | $AzureSQLDataWarehouseNameMediumUserName = $Config.AzureSQLDataWarehouseNameMediumUserName 29 | $AzureSQLDataWarehouseNameMediumPassword = $Config.AzureSQLDataWarehouseNameMediumPassword 30 | $AzureSQLDataWarehouseNameLargeUserName = $Config.AzureSQLDataWarehouseNameLargeUserName 31 | $AzureSQLDataWarehouseNameLargePassword = $Config.AzureSQLDataWarehouseNameLargePassword 32 | $AzureSQLDataWarehouseNameExtraLargeUserName = $Config.AzureSQLDataWarehouseNameExtraLargeUserName 33 | $AzureSQLDataWarehouseNameExtraLargePassword = $Config.AzureSQLDataWarehouseNameExtraLargePassword 34 | $AzureSQLDataWarehouseSQLDeploymentPath = $Config.AzureSQLDataWarehouseSQLDeploymentPath 35 | $BlobAccountNameName = $Config.BlobAccountName 36 | $BlobAccountNameResourceGroup = $Config.BlobAccountResourceGroup 37 | $BlobStorageKey = $Config.BlobStorageKey 38 | $SourceDatabaseName = $Config.SourceDatabaseName 39 | $ScheduleStartTime = $Config.ScheduleStartTime 40 | $ScheduleEndTime = $Config.ScheduleEndTime 41 | $PolybaseFileFormat = $Config.PolybaseFileFormat 42 | $SQLDeploymentPath = $Config.SQLDeploymentPath 43 | $AzureSubscriptionName = $Config.AzureSubscriptionName 44 | 45 | 46 | # ------- CSV containing export of Adatis metadata ------- # 47 | $path = Import-Csv $($MetadataFilePath + 'MagicWorksMetadata.csv') 48 | #$path = Import-Csv $($MetadataFilePath + 'MagicWorksDWMetadata.csv') 49 | 50 | $CredentialName = 'AzureStorageCredential' 51 | 52 | 53 | foreach ($item in $path) 54 | { 55 | #----------- Do not change -----------# 56 | 57 | 58 | $FileLocationExternal = $MasterTemplateLocation + 'Template-ExternalTable.Blob.dsql' 59 | $FileContentExternal = Get-Content $FileLocationExternal | Out-String 60 | 61 | $EntityNameFull = $item.TableName 62 | $EntityName = $EntityNameFull -replace '[][]','' 63 | $EntityName = $EntityName.Split(".")[1] 64 | $EntityName = $EntityName -replace 'vw','' 65 | 66 | #-------------------- Loop -------------# 67 | $DDLdataSet = $null 68 | $DDLdataAdapter = $null 69 | 70 | $EntityName 71 | 72 | $ColumnDDL = $item.LooselyTyped 73 | $ColumnList = $item.SelectColumns 74 | $ColumnTypings = $item.StronglyTypedCast 75 | $ContainerName = $item.BlobName 76 | 77 | # ------------------ Final Export ----------------- # 78 | # ------------------ External ----------------- # 79 | $FileContentExternal = $FileContentExternal -replace "%ENTITYNAME%", $EntityName 80 | $FileContentExternal = $FileContentExternal -replace "%COLUMNLIST%", $ColumnList 81 | $FileContentExternal = $FileContentExternal -replace "%COLUMNEXTDDL%", $ColumnDDL 82 | $FileContentExternal = $FileContentExternal -replace "%CREATETIME%", $CreateTime 83 | $FileContentExternal = $FileContentExternal -replace "%COLUMNTYPINGS%", $ColumnTypings 84 | $FileContentExternal = $FileContentExternal -replace "%BLOBACCOUNT%", $BlobAccountNameName 85 | $FileContentExternal = $FileContentExternal -replace "%CONTAINERNAME%", $EntityName.ToLower() #$EntityNameFull 86 | $FileContentExternal = $FileContentExternal -replace "%FILEFORMAT%", $PolybaseFileFormat 87 | $FileContentExternal = $FileContentExternal -replace "%CREDENTIALNAME%", $CredentialName 88 | $FileContentExternal = $FileContentExternal -replace "%PRIMARYKEY%", $PrimaryKey 89 | $FileContentExternal = $FileContentExternal -replace "%LAKEROOT%", $LakeRoot 90 | $FileContentExternal = $FileContentExternal -replace "%EXTDATASOURCE%", $ExternalDataSource 91 | #$FileContentExternal 92 | 93 | 94 | $FileContentExternal | out-file $($SQLDeploymentPath + 'External.' + $EntityName + '.dsql') 95 | 96 | } -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/AdatisFramework.GenerateDeplymentSQL.ps1: -------------------------------------------------------------------------------- 1 | # -------------------------------------------------------------------------------- # 2 | # Purpose: To create the Json objects for ADF 3 | # Createded by: Terry McCann (Adatis consulting limited) 4 | # Created on: 30/01/2014 5 | # Version history: 6 | # V1 - 7 | # -------------------------------------------------------------------------------- # 8 | 9 | 10 | #---------------- This script does the following ----------------------# 11 | 12 | # 1 Read a file 13 | # 2 replace parts of the file 14 | # 3 Read data from a sql database / Option to not read from a DB but from a file 15 | 16 | # VARIABLES: 17 | # %CREATETIME% - A datetime stamp for the auto-comments within the script. Populated at script runtime 18 | # %ENTITYNAME% - The name of the entity, this is the table name across the various warehouse stages 19 | # %COLUMNLIST% - Comma-separated list of columns within the entity 20 | # %COLUMNTYPINGS% - Comma-separated list of columns within the entity, including CAST() and ISNULL() wrappers to enforce target datatypes 21 | # %COLUMNEXTDDL% - Comma-separated list of columns within the entity, including polybase datatype 22 | # %BLOBACCOUNT% - Name of the blob storage account 23 | # %CONTAINERNAME% - Name of the entity-specific container within blob storage 24 | # %FILEFORMAT% - Name of the file format external resource that describes the filetype this entity belongs to 25 | 26 | #----------- Vaiables -------------# 27 | $DatabaseName = 'AdventureWorks' 28 | $ServerName = '.' 29 | $UserNameShort = 'tpm' 30 | $MasterFolderLocation = 'G:\GitHub\MagicWorks\Polybase Generation\' 31 | $DeployFolderLocation = 'G:\GitHub\MagicWorks\Polybase Generation\SQLToBeDeployed\' 32 | 33 | $BlobAccountName = 'magicworksblob' 34 | $BlobStorageKey = 'WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA==' 35 | $DatabaseName= 'Adventureworks' 36 | $UserNameShort = 'acl\tpm' 37 | 38 | $query = "EXEC datawarehouse.AdatisASDWMetadata; " 39 | 40 | #----------- Do not change -----------# 41 | $FileLocation = $MasterFolderLocation + 'Template-Staging.CreateLoad.dsql' 42 | 43 | $ServerAConnectionString = 'Data Source='+$ServerName+';Initial Catalog='+$DatabaseName+';User Id='+ $UserNameShort +';Integrated Security = True' 44 | $ServerAConnection = new-object system.data.SqlClient.SqlConnection($ServerAConnectionString); 45 | 46 | 47 | $dataSet = new-object "System.Data.DataSet" "MetadataDataset" 48 | $dataAdapter = new-object "System.Data.SqlClient.SqlDataAdapter" ($Query, $ServerAConnection) 49 | $dataAdapter.Fill($dataSet) | Out-Null 50 | 51 | foreach ($RowOuter in $dataSet.Tables[0].Rows) 52 | { 53 | $FileContent = Get-Content $FileLocation 54 | $EntityNameFull = $RowOuter[0] 55 | $EntityName = $EntityNameFull -replace '[][]','' 56 | $EntityName = $EntityName.Split(".")[1] 57 | 58 | 59 | 60 | #-------------------- Loop -------------# 61 | $DDLdataSet = $null 62 | $DDLdataAdapter = $null 63 | 64 | 65 | 66 | $DDLdataSet = new-object "System.Data.DataSet" "MetadataDataset" 67 | $DDLdataAdapter = new-object "System.Data.SqlClient.SqlDataAdapter" ($QueryDDL, $ServerAConnection) 68 | $DDLdataAdapter.Fill($DDLdataSet) | Out-Null 69 | 70 | foreach ($Row in $DDLdataSet.Tables[0].Rows) 71 | { 72 | $ColumnDDL= $Row[0] 73 | $ColumnList= $Row[1] 74 | } 75 | 76 | # ------------------ Final Export ----------------- # 77 | $FileContent = $FileContent -replace "%ENTITYNAME%", $EntityName 78 | $FileContent = $FileContent -replace "%COLUMNLIST%", $ColumnList 79 | $FileContent = $FileContent -replace "%COLUMNDDL%", $ColumnDDL 80 | 81 | $FileContent | out-file $($DeployFolderLocation + $EntityName + '.sql') 82 | } -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/Config.json: -------------------------------------------------------------------------------- 1 | { 2 | "MetadataFilePath": "G:\\GitHub\\MagicWorks\\Polybase Generation\\", 3 | "MasterTemplateLocation": "G:\\GitHub\\MagicWorks\\Polybase Generation\\", 4 | "AzureSubscriptionName": "Microsoft Azure Sponsorship", 5 | "AzureSQLDataWarehouseName": "sqlbits2018", 6 | "AzureSQLDataWarehouseServer": "tcp:magicadventure.database.windows.net", 7 | "AzureSQLDataWarehouseNameAdminUserName": "asdwadmin", 8 | "AzureSQLDataWarehouseNameAdminPassword": "Password1234!", 9 | "AzureSQLDataWarehouseNameMediumUserName": "asdwadmin", 10 | "AzureSQLDataWarehouseNameMediumPassword": "Password1234!", 11 | "AzureSQLDataWarehouseNameLargeUserName": "asdwadmin", 12 | "AzureSQLDataWarehouseNameLargePassword": "Password1234!", 13 | "AzureSQLDataWarehouseNameExtraLargeUserName": "asdwadmin", 14 | "AzureSQLDataWarehouseNameExtraLargePassword": "Password1234!", 15 | "AzureSQLDataWarehouseSQLDeploymentPath": "C:\\Development\\", 16 | "BlobAccountName": "magicworksblob", 17 | "BlobAccountResourceGroup": "sqlbits2018", 18 | "BlobStorageKey": "WR6PLCnUMJ9Hu6Wkt7EUadRLDnoVF3cTabiGm//3FBXXJOSFAPqjrkfqqEW9qT4P2OlsKDcY0iSRUfDWtNhKrA==", 19 | "SourceDatabaseName": "AdventureWorks", 20 | "ScheduleStartTime": "Today", 21 | "ScheduleEndTime": "Default", 22 | "PolybaseFileFormat": "TextFile", 23 | "SQLDeploymentPath": "G:\\GitHub\\MagicWorks\\Polybase Generation\\SQLToBeDeployed\\" 24 | } 25 | -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/AdatisFramework.CombineAllSQLFiles.ps1: -------------------------------------------------------------------------------- 1 | $UberScript ='' 2 | 3 | 4 | # ------------ Process all transform scripts ---------- # 5 | Get-ChildItem "G:\GitHub\MagicWorks\Polybase Generation\SQLToBeDeployed" -Filter *.dsql | 6 | Foreach-Object { 7 | $content = Get-Content $_.FullName | Out-String 8 | #$content 9 | $spm = $content 10 | Write-Host $_.FullName 11 | 12 | $UberScript += $content 13 | 14 | } 15 | 16 | 17 | $UberScript | out-file $('G:\GitHub\Labs\BuildAutomation\RunAll.sql') -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.AWBuildVersion.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.AWBuildVersion.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Address.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Address.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.AddressType.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.AddressType.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.AdventureWorksDWBuildVersion.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.AdventureWorksDWBuildVersion.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.AuditLog.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.AuditLog.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.BillOfMaterials.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.BillOfMaterials.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.BusinessEntity.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.BusinessEntity.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.BusinessEntityAddress.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.BusinessEntityAddress.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.BusinessEntityContact.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.BusinessEntityContact.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ContactType.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ContactType.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.CountryRegion.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.CountryRegion.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.CountryRegionCurrency.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.CountryRegionCurrency.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.CreditCard.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.CreditCard.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Culture.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Culture.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Currency.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Currency.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.CurrencyRate.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.CurrencyRate.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Customer.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Customer.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DatabaseLog.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DatabaseLog.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Department.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Department.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimAccount.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimAccount.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimCurrency.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimCurrency.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimCustomer.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimCustomer.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimDate.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimDate.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimDepartmentGroup.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimDepartmentGroup.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimEmployee.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimEmployee.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimGeography.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimGeography.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimOrganization.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimOrganization.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimProduct.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimProduct.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimProductCategory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimProductCategory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimProductSubcategory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimProductSubcategory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimPromotion.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimPromotion.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimReseller.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimReseller.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimSalesReason.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimSalesReason.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimSalesTerritory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimSalesTerritory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimScenario.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.DimScenario.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Document.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Document.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.EmailAddress.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.EmailAddress.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Employee.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Employee.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.EmployeeDepartmentHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.EmployeeDepartmentHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.EmployeePayHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.EmployeePayHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ErrorLog.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ErrorLog.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactCallCenter.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactCallCenter.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactCurrencyRate.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactCurrencyRate.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactFinance.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactFinance.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactInternetSales.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactInternetSales.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactInternetSalesReason.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactInternetSalesReason.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactProductInventory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactProductInventory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactResellerSales.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactResellerSales.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactSalesQuota.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactSalesQuota.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactSurveyResponse.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.FactSurveyResponse.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Illustration.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Illustration.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.JobCandidate.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.JobCandidate.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Location.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Location.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Password.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Password.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Person.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Person.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.PersonCreditCard.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.PersonCreditCard.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.PersonPhone.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.PersonPhone.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.PhoneNumberType.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.PhoneNumberType.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Product.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Product.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductCategory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductCategory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductCostHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductCostHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductDescription.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductDescription.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductDocument.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductDocument.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductInventory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductInventory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductListPriceHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductListPriceHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductModel.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductModel.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductModelIllustration.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductModelIllustration.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductPhoto.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductPhoto.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductProductPhoto.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductProductPhoto.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductReview.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductReview.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductSubcategory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductSubcategory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductVendor.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProductVendor.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProspectiveBuyer.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ProspectiveBuyer.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.PurchaseOrderDetail.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.PurchaseOrderDetail.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.PurchaseOrderHeader.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.PurchaseOrderHeader.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesOrderDetail.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesOrderDetail.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesOrderHeader.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesOrderHeader.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesOrderHeaderSalesReason.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesOrderHeaderSalesReason.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesPerson.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesPerson.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesPersonQuotaHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesPersonQuotaHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesReason.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesReason.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesTaxRate.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesTaxRate.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesTerritory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesTerritory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesTerritoryHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SalesTerritoryHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ScrapReason.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ScrapReason.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Shift.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Shift.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ShipMethod.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ShipMethod.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.ShoppingCartItem.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.ShoppingCartItem.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SpecialOffer.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SpecialOffer.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.SpecialOfferProduct.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.SpecialOfferProduct.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.StateProvince.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.StateProvince.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Store.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Store.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.TransactionHistory.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.TransactionHistory.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.TransactionHistoryArchive.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.TransactionHistoryArchive.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.UnitMeasure.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.UnitMeasure.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.Vendor.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.Vendor.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.WorkOrder.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.WorkOrder.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.WorkOrderRouting.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.WorkOrderRouting.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/SQLToBeDeployed/External.sysdiagrams.dsql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/MagicWorks/Polybase Generation/SQLToBeDeployed/External.sysdiagrams.dsql -------------------------------------------------------------------------------- /MagicWorks/Polybase Generation/Template-ExternalTable.Blob.dsql: -------------------------------------------------------------------------------- 1 | /*================================================================ 2 | * Desc: Create Script for External Table & Related Data Source 3 | * Created: This procedure was auto-generated at %CREATETIME% 4 | * Created By: Procedure Logic provided by Adatis Consulting Ltd 5 | ================================================================*/ 6 | 7 | BEGIN TRY 8 | DROP EXTERNAL TABLE Ext.%ENTITYNAME%; 9 | END TRY 10 | BEGIN CATCH 11 | PRINT 'DNGN' 12 | END CATCH 13 | 14 | BEGIN TRY 15 | DROP EXTERNAL DATA SOURCE Blob_%CONTAINERNAME%; 16 | END TRY 17 | BEGIN CATCH 18 | PRINT 'DNGN' 19 | END CATCH 20 | 21 | 22 | CREATE EXTERNAL DATA SOURCE Blob_%CONTAINERNAME% 23 | WITH (TYPE = HADOOP, 24 | LOCATION = 'wasbs://%CONTAINERNAME%@%BLOBACCOUNT%.blob.core.windows.net', 25 | CREDENTIAL = %CREDENTIALNAME%); 26 | 27 | 28 | CREATE EXTERNAL TABLE Ext.%ENTITYNAME%( 29 | %COLUMNEXTDDL% 30 | ) 31 | WITH (LOCATION='./', 32 | DATA_SOURCE = Blob_%CONTAINERNAME%, 33 | FILE_FORMAT = %FILEFORMAT%, 34 | REJECT_TYPE = VALUE, 35 | REJECT_VALUE = 0); 36 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Azure Sql Data Warehouse Training Materials 2 | 3 | Welcome to SQLBits. We hope that you have a magical time. 4 | As we move through the day you will be asked to complete a series of labs. You will find all the resources required to complete the labs on this GitHub Repository. 5 | You can choose to either copy the files directly from GitHub, download or fork and set up a local repo on your machine. For ease I recommend downloading the lot. 6 | 7 | We appreciate that this is not an easy topic to absorb in a single day. As such we have a few games and quizzes we will play through out the day, so make sure that you pay attention for a chance to win some prizes. We might also ask you to move around, if you're not able to/wish not to participate, please let us know (it's just a bit of fun). 8 | 9 | This Github repo will be available when you next need it. As material changes, we endeavour to keep this up-to-date. If there is something you think should be added, please make branch the codebase and submit a pull request. 10 | 11 | ## Agenda 12 | - Introduction 13 | - Service Architecture 14 | - Designing Tables 15 | - Data loading performance 16 | - Querying data 17 | - Extending the data warehouse and patterns 18 | - Closing slides 19 | 20 | We will have breaks at around 10:00, 12:00 and 15:00. 21 | 22 | ## Labs 23 | This session is designed to be a hands on workshop. You will get a mixture of Theory and real world solutions. 24 | To back this up we have a series of labs. 25 | - [000 - Connecting to Azure SQL Data Warehouse](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_00) 26 | - [001 - Creating a New Instance of Azure SQL Data Warehouse](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_01) 27 | - [002 - Monitoring data skew](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_02) 28 | - [003 - Redistributing data](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_03) 29 | - [004 - Loading data with Polybase](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_04) 30 | - [005 - Managing surrogate keys](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_05) 31 | - [006 - Performance DMV and EXPLAIN](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_06) 32 | - [007 - Performance tuning](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_07) 33 | 34 | Each lab will last less than 20 minutes. If you're not able to complete the lab in time, there will either be a procedure you can run to get you up to date, or a script to run. 35 | 36 | ## Tools required for today 37 | These labs require tools most Azure developers have on their development machines. They do need to be the latest edition for some of the new features to work. 38 | 39 | Can you please ensure that you have the following installed. 40 | - SQL Server Management Studio 17+ (17.5 is best) download [here](https://docs.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms) 41 | - Visual Studio 17 42 | OR Vscode 43 | - Azure Storage Explorer download [here](https://azure.microsoft.com/en-us/features/storage-explorer/) 44 | - PowerShell - We wont do any labs in PowerShell, but there is content for you to use. 45 | 46 | ## Structure of GitHub 47 | - Slides - You will find the latest version of all the slides located [here](https://github.com/SQLShark/ASDWPrecon/tree/master/Slides). 48 | - MagicWorks - We will use a very magical version of Adventure Works for all our demos. All files required are located in blob storage and also in their relevant files. You do not need to run these scripts, they are for reference only. 49 | - Labs - All the labs we will run through during this session. 50 | - Code Examples - You will see as we go through the session a lot of code in the slides. Rather than copying this from the slides, all content is here too. 51 | - Images - All the images used as documentation in labs. 52 | 53 | ## The Slack Channel 54 | Slack is a great resource for you to ask questions as we are going. 55 | Feel free to stop the speakers and ask a question, however if there is something that is not clear to you or you want to share something with the group you can do so in Slack. 56 | Terry will monitor the slack channel all day answering questions helping where needed. 57 | 58 | This Slack channel will be available for 12 weeks after the session has finished. If you start working with Azure SQL Data Warehouse and you have questions or you need support, we will be able to help you. 59 | 60 | ### How to access the Slack Channel? 61 | You will need to register. Follow the link below to register. 62 | https://join.slack.com/t/sqlbits-azure-sqldw/shared_invite/enQtMzEwNTc2NDQyMzc1LWM5ZGJjOTA0ZWFlMjE3ZTdjNGJjYmI0N2I0OTkxMDczY2MwN2ZmZGE4MmEyMWU2YmUxNmYxOTBiYmE4YjYxYjI 63 | 64 | Slack has both a web version and a desktop version. You can download the desktop version here: 65 | https://slack.com/ 66 | 67 | ## Connecting to the Demo Azure SQLDW. 68 | If you do not have an Azure subscription, you can connect to a version we have published already. 69 | Terry will come and ask you if you require access to this before we start. You will be given a Server to connect to, a username and password. If you have problems connecting please let me know either in person or on Skype. 70 | This environment will only be available for today. Please do not scale Azure SQLDW beyond 400DWU. There is a job running to check for instances running more than 400 DWU and they will automatically scale down to 100 DWU. This takes time and as a result you will be delayed slightly. 71 | 72 | Details about how to connect to Azure SQLDW are listed in [LAB_000](https://github.com/SQLShark/ASDWPrecon/tree/master/Labs/LAB_00) 73 | 74 | ## About the speakers 75 | There are business cards for all speakers on the desk at the front. 76 | 77 | ### James Rowland-Jones Principal Program Manager - Microsoft 78 | James Rowland-Jones (JRJ) is a Principal Program Manager at Microsoft. He is part of the Azure SQL Data Warehouse team and is passionate about delivering highly scalable solutions that are creative, simple and elegant in their design. JRJ is also a keen advocate for the worldwide SQL community. He has previously served on the Board of Directors for PASS and helped organise SQLBits. James was awarded Microsoft’s MVP accreditation from 2008 - 2015 for his services to the community. Yesterday it was James' birthday. Make sure you with him a very happy birthday. 79 | 80 | You can contact James on Twitter [@jrowlandjones](https://twitter.com/jrowlandjones) 81 | 82 | ### Terry McCann | Principal Consultant - Adatis 83 | Terry has about 10 years experience implementing data warehouses and has delivered Azure Data warehouse projects on behalf of Adatis Consulting Limited to some of the UK's largest Azure consumers. If you want to know more about these projects or Adatis, make sure that you visit our stand through out the conference. 84 | 85 | Microsoft Data Platform MVP. Principal Data Science & Advanced Analytics Consultant for Adatis Consulting Limited a Microsoft Data & Analytics consultancy in the UK. Data Science Master's degree, organizer of the Data Science Exeter user group, frequent speaker at conferences across the world. 86 | 87 | You can contact Terry here: tpm@adatis.co.uk or via [@SQLShark](https://twitter.com/SQLShark) on Twitter 88 | 89 | ### Simon Whiteley | Chief Cloud Architect - Adatis 90 | Simon is technical lead for Adatis, driving their adoption of new architectures and leading Research & Development within the company. He has over a decade of analytics experience, largely within the Microsoft realm and has been pushing distributed cloud architectures for analytics for the past few years. 91 | 92 | A newly-minted Microsoft Data Platform MVP, Simon runs the SQLSurrey PASS Chapter, speaks at a variety of conferences and user groups throughout the UK and Europe and will happily talk your ear off about the various new approaches we're currently working on. 93 | 94 | You can contact Simon here: saw@adatis.co.uk or via [@MrSiWhiteley](https://twitter.com/MrSiWhiteley) on Twitter 95 | 96 | ### Links mentioned during the talk. 97 | 98 | - https://docs.microsoft.com/en-us/azure/sql-data-warehouse/resource-classes-for-workload-management 99 | - https://docs.microsoft.com/en-us/azure/sql-data-warehouse/sql-data-warehouse-manage-monitor 100 | - http://download.microsoft.com/download/F/8/6/F8654654-6784-48F5-83C0-2D46186EEC66/Data_Warehouse_Fast_Track_Reference_Guide_for_SQL_Server_2016_EN_US.pdf 101 | - https://www.amazon.co.uk/Big-Data-Principles-practices-scalable/dp/1617290343/ref=sr_1_1?ie=UTF8&qid=1519221273&sr=8-1&keywords=big+data+nathan+marz 102 | Simon Talking about the process of Lambda in Azure. 103 | - https://www.youtube.com/watch?v=lcFDrIbTyxE 104 | Additional links for CTAS statements 105 | - http://blogs.adatis.co.uk/simonwhiteley/post/Azure-SQLDW-CTAS-Statements 106 | - https://channel9.msdn.com/Shows/Cortana-Intelligence-Corner/Loading-data-into-Azure-SQL-Datawarehouse 107 | - https://azure.microsoft.com/en-gb/blog/introducing-select-into-in-azure-sql-data-warehouse/ 108 | When should I use Azure SQL Data Warehouse? 109 | - https://www.blue-granite.com/blog/is-azure-sql-data-warehouse-a-good-fit -------------------------------------------------------------------------------- /SQLDW Manager/.vs/ADW Manager/v15/.suo: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/SQLDW Manager/.vs/ADW Manager/v15/.suo -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager.sln: -------------------------------------------------------------------------------- 1 |  2 | Microsoft Visual Studio Solution File, Format Version 12.00 3 | # Visual Studio 14 4 | VisualStudioVersion = 14.0.24720.0 5 | MinimumVisualStudioVersion = 10.0.40219.1 6 | Project("{F14B399A-7131-4C87-9E4B-1186C45EF12D}") = "ADW Manager", "ADW Manager\ADW Manager.rptproj", "{9993B325-5D5B-4694-9435-CE65DAD1F825}" 7 | EndProject 8 | Global 9 | GlobalSection(SolutionConfigurationPlatforms) = preSolution 10 | Debug|Default = Debug|Default 11 | DebugLocal|Default = DebugLocal|Default 12 | Release|Default = Release|Default 13 | EndGlobalSection 14 | GlobalSection(ProjectConfigurationPlatforms) = postSolution 15 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.Debug|Default.ActiveCfg = Debug 16 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.Debug|Default.Build.0 = Debug 17 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.Debug|Default.Deploy.0 = Debug 18 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.DebugLocal|Default.ActiveCfg = DebugLocal 19 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.DebugLocal|Default.Build.0 = DebugLocal 20 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.Release|Default.ActiveCfg = Release 21 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.Release|Default.Build.0 = Release 22 | {9993B325-5D5B-4694-9435-CE65DAD1F825}.Release|Default.Deploy.0 = Release 23 | EndGlobalSection 24 | GlobalSection(SolutionProperties) = preSolution 25 | HideSolutionNode = FALSE 26 | EndGlobalSection 27 | GlobalSection(TeamFoundationVersionControl) = preSolution 28 | SccNumberOfProjects = 2 29 | SccEnterpriseProvider = {4CA58AB2-18FA-4F8D-95D4-32DDF27D184C} 30 | SccTeamFoundationServer = https://tfs.adatis.co.uk/tfs/adatis 31 | SccLocalPath0 = . 32 | SccProjectUniqueName1 = ADW\u0020Manager\\ADW\u0020Manager.rptproj 33 | SccProjectName1 = ADW\u0020Manager 34 | SccLocalPath1 = ADW\u0020Manager 35 | EndGlobalSection 36 | EndGlobal 37 | -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/ADW Manager.rptproj: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | Debug 5 | Win32 6 | bin\Debug 7 | 2 8 | False 9 | False 10 | SSRS2016 11 | ADW Manager 12 | Datasets 13 | Data Sources 14 | Report Parts 15 | http://20.190.57.212/reportserver 16 | 17 | 18 | DebugLocal 19 | Win32 20 | bin\DebugLocal 21 | 2 22 | False 23 | False 24 | SSRS2016 25 | ADW Manager 26 | Datasets 27 | Data Sources 28 | Report Parts 29 | http://localhost/reportserver 30 | 31 | 32 | Release 33 | Win32 34 | bin\Release 35 | 2 36 | False 37 | False 38 | SSRS2016 39 | ADW Manager 40 | Datasets 41 | Data Sources 42 | Report Parts 43 | http://localhost/reportserver 44 | 45 | 46 | $base64$PFNvdXJjZUNvbnRyb2xJbmZvIHhtbG5zOnhzZD0iaHR0cDovL3d3dy53My5vcmcvMjAwMS9YTUxTY2hlbWEiIHhtbG5zOnhzaT0iaHR0cDovL3d3dy53My5vcmcvMjAwMS9YTUxTY2hlbWEtaW5zdGFuY2UiIHhtbG5zOmRkbDI9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDAzL2VuZ2luZS8yIiB4bWxuczpkZGwyXzI9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDAzL2VuZ2luZS8yLzIiIHhtbG5zOmRkbDEwMF8xMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDA4L2VuZ2luZS8xMDAvMTAwIiB4bWxuczpkZGwyMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEwL2VuZ2luZS8yMDAiIHhtbG5zOmRkbDIwMF8yMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEwL2VuZ2luZS8yMDAvMjAwIiB4bWxuczpkZGwzMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDExL2VuZ2luZS8zMDAiIHhtbG5zOmRkbDMwMF8zMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDExL2VuZ2luZS8zMDAvMzAwIiB4bWxuczpkZGw0MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEyL2VuZ2luZS80MDAiIHhtbG5zOmRkbDQwMF80MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEyL2VuZ2luZS80MDAvNDAwIiB4bWxuczpkZGw1MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEzL2VuZ2luZS81MDAiIHhtbG5zOmRkbDUwMF81MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEzL2VuZ2luZS81MDAvNTAwIiB4bWxuczpkd2Q9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vRGF0YVdhcmVob3VzZS9EZXNpZ25lci8xLjAiPg0KICA8RW5hYmxlZD5mYWxzZTwvRW5hYmxlZD4NCiAgPFByb2plY3ROYW1lPjwvUHJvamVjdE5hbWU+DQogIDxBdXhQYXRoPjwvQXV4UGF0aD4NCiAgPExvY2FsUGF0aD48L0xvY2FsUGF0aD4NCiAgPFByb3ZpZGVyPjwvUHJvdmlkZXI+DQo8L1NvdXJjZUNvbnRyb2xJbmZvPg== 47 | @(DataSource) 48 | @(DataSet) 49 | @(Report) 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/ADW Manager.rptproj.bak: -------------------------------------------------------------------------------- 1 | 2 | 3 | $base64$PFNvdXJjZUNvbnRyb2xJbmZvIHhtbG5zOnhzZD0iaHR0cDovL3d3dy53My5vcmcvMjAwMS9YTUxTY2hlbWEiIHhtbG5zOnhzaT0iaHR0cDovL3d3dy53My5vcmcvMjAwMS9YTUxTY2hlbWEtaW5zdGFuY2UiIHhtbG5zOmRkbDI9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDAzL2VuZ2luZS8yIiB4bWxuczpkZGwyXzI9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDAzL2VuZ2luZS8yLzIiIHhtbG5zOmRkbDEwMF8xMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDA4L2VuZ2luZS8xMDAvMTAwIiB4bWxuczpkZGwyMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEwL2VuZ2luZS8yMDAiIHhtbG5zOmRkbDIwMF8yMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEwL2VuZ2luZS8yMDAvMjAwIiB4bWxuczpkZGwzMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDExL2VuZ2luZS8zMDAiIHhtbG5zOmRkbDMwMF8zMDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDExL2VuZ2luZS8zMDAvMzAwIiB4bWxuczpkZGw0MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEyL2VuZ2luZS80MDAiIHhtbG5zOmRkbDQwMF80MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEyL2VuZ2luZS80MDAvNDAwIiB4bWxuczpkZGw1MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEzL2VuZ2luZS81MDAiIHhtbG5zOmRkbDUwMF81MDA9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vYW5hbHlzaXNzZXJ2aWNlcy8yMDEzL2VuZ2luZS81MDAvNTAwIiB4bWxuczpkd2Q9Imh0dHA6Ly9zY2hlbWFzLm1pY3Jvc29mdC5jb20vRGF0YVdhcmVob3VzZS9EZXNpZ25lci8xLjAiPg0KICA8RW5hYmxlZD50cnVlPC9FbmFibGVkPg0KICA8UHJvamVjdE5hbWU+U0FLPC9Qcm9qZWN0TmFtZT4NCiAgPEF1eFBhdGg+U0FLPC9BdXhQYXRoPg0KICA8TG9jYWxQYXRoPlNBSzwvTG9jYWxQYXRoPg0KICA8UHJvdmlkZXI+U0FLPC9Qcm92aWRlcj4NCjwvU291cmNlQ29udHJvbEluZm8+ 4 | 5 | 6 | ADW.rds 7 | ADW.rds 8 | 9 | 10 | 11 | 12 | DWSize.rsd 13 | DWSize.rsd 14 | 15 | 16 | 17 | 18 | ActivityMonitor.rdl 19 | ActivityMonitor.rdl 20 | 21 | 22 | DistributionDetails.rdl 23 | DistributionDetails.rdl 24 | 25 | 26 | ExecutionExplorer.rdl 27 | ExecutionExplorer.rdl 28 | 29 | 30 | Overview.rdl 31 | Overview.rdl 32 | 33 | 34 | PolybaseReader.rdl 35 | PolybaseReader.rdl 36 | 37 | 38 | subExecutionSteps.rdl 39 | subExecutionSteps.rdl 40 | 41 | 42 | TableDetails.rdl 43 | TableDetails.rdl 44 | 45 | 46 | TableManager.rdl 47 | TableManager.rdl 48 | 49 | 50 | 51 | 52 | Debug 53 | Win32 54 | 55 | bin\Debug 56 | SSRS2016 57 | http://52.178.137.192/reportserver 58 | ADW Manager 59 | Data Sources 60 | Datasets 61 | Report Parts 62 | 63 | 64 | 65 | DebugLocal 66 | Win32 67 | 68 | bin\DebugLocal 69 | SSRS2016 70 | http://localhost/reportserver 71 | ADW Manager 72 | Data Sources 73 | Datasets 74 | Report Parts 75 | 76 | 77 | 78 | Release 79 | Win32 80 | 81 | bin\Release 82 | SSRS2016 83 | http://localhost/reportserver 84 | ADW Manager 85 | Data Sources 86 | Datasets 87 | Report Parts 88 | 89 | 90 | 91 | -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/ADW Manager.rptproj.rsuser: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/SQLDW Manager/ADW Manager/ADW Manager.rptproj.rsuser -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/ADW.rds: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | SQLAZURE 5 | Data Source=magicadventure.database.windows.net;Initial Catalog=sqlbits2018;Encrypt=True;TrustServerCertificate=False;Authentication="Sql Password" 6 | 7 | 645d76c9-873d-4541-868e-6869131bb183 8 | -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/ActivityMonitor.rdl.data: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/SQLDW Manager/ADW Manager/ActivityMonitor.rdl.data -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/DWSize.rsd: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | ADW 6 | SELECT COUNT(*) Nodes, 7 | COUNT(*)/8*100 IndicitiveSize 8 | 9 | FROM sys.dm_pdw_nodes_resource_governor_workload_groups wg 10 | JOIN sys.dm_pdw_nodes_resource_governor_resource_pools rp 11 | ON wg.pdw_node_id = rp.pdw_node_id 12 | AND wg.pool_id = rp.pool_id 13 | JOIN sys.dm_pdw_nodes pn 14 | ON wg.pdw_node_id = pn.pdw_node_id 15 | WHERE wg.name like 'SloDWGroup%' 16 | AND rp.name = 'SloDWPool' 17 | AND pn.[type] = 'COMPUTE' 18 | 19 | 20 | 21 | Nodes 22 | System.Int32 23 | 24 | 25 | IndicitiveSize 26 | System.Int32 27 | 28 | 29 | 30 | -------------------------------------------------------------------------------- /SQLDW Manager/ADW Manager/Overview.rdl.data: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/SQLDW Manager/ADW Manager/Overview.rdl.data -------------------------------------------------------------------------------- /SQLDW Manager/README.md: -------------------------------------------------------------------------------- 1 | # Azure SQL DataWarehouse Manager 2 | 3 | This suite of reports pulls from several system views to provide performance monitoring and general management of an Azure SQL DataWarehouse server. 4 | 5 | In order to use them, you will need to deploy them to an SSRS instance, either in Azure or on-premise, and modify the central connection manager to point to your SQLDW instance. 6 | 7 | ## Overview 8 | 9 | This high-level report gives you some basic management information - how many people are currently using the server, what is the current service objective and how many slots are currently available. How well is data distributed on the server? 10 | 11 | ## Activity Monitor 12 | 13 | This report mirrors the traditional SSMS report many people will be familiar with. It shows recent expensive queries, queries with blockers and the top drains on the SQL and DMS engines respectively. 14 | 15 | ## Polybase Reader 16 | 17 | This report is designed specifically for load monitoring of external tables. It queries for any queries that are currently utilising external data readers and shows the total amount read so far, the approximate read speed and an estimated remaining load time. 18 | 19 | ## Execution Explorer 20 | 21 | Here we have simply put a wrapper around the performance management system views to show all recent query executions and the impact they had on each distribution. This can help identify recent performance issues and target the data movement responsible. 22 | -------------------------------------------------------------------------------- /Slides/000.Intro.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Slides/000.Intro.pdf -------------------------------------------------------------------------------- /Slides/001.Service Architecture.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Slides/001.Service Architecture.pdf -------------------------------------------------------------------------------- /Slides/002.Designing Tables.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Slides/002.Designing Tables.pdf -------------------------------------------------------------------------------- /Slides/003.Data Loading Performance.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Slides/003.Data Loading Performance.pdf -------------------------------------------------------------------------------- /Slides/004.Querying data.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Slides/004.Querying data.pdf -------------------------------------------------------------------------------- /Slides/005.Extending the data warehouse.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/Slides/005.Extending the data warehouse.pdf -------------------------------------------------------------------------------- /asdwprecon_settings.json: -------------------------------------------------------------------------------- 1 | { 2 | "defaultContext": { 3 | "account": null, 4 | "database": null, 5 | "schema": null 6 | }, 7 | "scripts": [] 8 | } -------------------------------------------------------------------------------- /images/ActivityMonitor.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/ActivityMonitor.png -------------------------------------------------------------------------------- /images/AzureSQLDW.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/AzureSQLDW.png -------------------------------------------------------------------------------- /images/AzureSQLDW_Config.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/AzureSQLDW_Config.png -------------------------------------------------------------------------------- /images/AzureSQLDW_Config2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/AzureSQLDW_Config2.png -------------------------------------------------------------------------------- /images/AzureSQLDW_Config3.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/AzureSQLDW_Config3.png -------------------------------------------------------------------------------- /images/AzureSQLDW_Config4.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/AzureSQLDW_Config4.png -------------------------------------------------------------------------------- /images/Overview Report.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/Overview Report.png -------------------------------------------------------------------------------- /images/PolybaseLoader.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/PolybaseLoader.png -------------------------------------------------------------------------------- /images/Table Details.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/Table Details.png -------------------------------------------------------------------------------- /images/usersanddesks.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SQLShark/ASDWPrecon/28a041afc93e8024c9de8242f26c75d982cacecd/images/usersanddesks.png --------------------------------------------------------------------------------