SQL Server 2019 PolyBase

1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 |
--PolyBaseインストール状況確認 SELECT SERVERPROPERTY ('IsPolybaseInstalled') AS IsPolybaseInstalled; --HadoopやAzureストレージにアクセスできるようにする USE master; GO EXEC sp_configure 'show advanced option', '1' RECONFIGURE GO EXEC sp_configure 'hadoop connectivity', 7 GO RECONFIGURE GO --SQL Server 2019 USE master; GO EXEC sp_configure 'polybase enabled', 1 RECONFIGURE GO --PolyBase エラーを確認するクエリ USE DWDiagnostics GO SELECT TOP 100 * FROM [DWDiagnostics].[dbo].[pdw_errors] ORDER BY [DateTimePublished] DESC /********************************** *Load Data From Twitter Demo **********************************/ --Create Database USE [master] GO CREATE DATABASE [PolyBase_Twitter] CONTAINMENT = NONE ON PRIMARY ( NAME = N'PolyBase_Twitter', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\PolyBase_Twitter.mdf' , SIZE = 8192KB , FILEGROWTH = 65536KB ) LOG ON ( NAME = N'PolyBase_Twitter_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\PolyBase_Twitter_log.ldf' , SIZE = 8192KB , FILEGROWTH = 65536KB ) GO ALTER DATABASE [PolyBase_Twitter] SET RECOVERY SIMPLE GO --マスタキーを作成 USE [PolyBase_Twitter] GO CREATE MASTER KEY ENCRYPTION BY PASSWORD = '{password}' GO --ツイッター資格情報作成 USE [PolyBase_Twitter] GO CREATE DATABASE SCOPED CREDENTIAL [TwitterCredential] WITH IDENTITY = 'MyTwitter', Secret = '' GO --資格情報を確認 select * from sys.database_scoped_credentials --外部データソースを作成する。 CREATE EXTERNAL DATA SOURCE [TwitterInstance] WITH ( LOCATION = 'odbc://PolyBaseVM', CONNECTION_OPTIONS ='DRIVER={CData ODBC Driver for Twitter};DSN=CData Twitter Sys', CREDENTIAL = [TwitterCredential]) GO --外部データソースを確認する select * from sys.external_data_sources CREATE EXTERNAL TABLE [extTwitter_Tweets]( [ID] NVARCHAR(60) COLLATE Japanese_CI_AS, [IDLong] NVARCHAR(4000) COLLATE Japanese_CI_AS, [SearchTerms] NVARCHAR(400) COLLATE Japanese_CI_AS, [Created_At] DATETIME2(0), [Text] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Lang] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Source] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Favorited] BIT, [Favorite_Count] INT, [Retweeted] BIT, [Retweet_Count] INT, [Retweeted_Status_Id] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Truncated] BIT, [Filter_Level] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Possibly_Sensitive] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Withheld_Copyright] BIT, [Withheld_Scope] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Withheld_In_Countries] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Contributors] NVARCHAR(MAX) COLLATE Japanese_CI_AS, [Coordinates_Coordinates] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Coordinates_Type] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Place_Full_Name] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Place_Country] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Current_User_Retweet_Id] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Scopes] NVARCHAR(4000) COLLATE Japanese_CI_AS, [In_Reply_To_Status_Id] NVARCHAR(4000) COLLATE Japanese_CI_AS, [From_User_Id] NVARCHAR(510) COLLATE Japanese_CI_AS, [From_User_Screen_Name] NVARCHAR(510) COLLATE Japanese_CI_AS, [From_User_Name] NVARCHAR(510) COLLATE Japanese_CI_AS, [From_User_Location] NVARCHAR(4000) COLLATE Japanese_CI_AS, [From_User_Profile_URL] NVARCHAR(4000) COLLATE Japanese_CI_AS, [From_User_Profile_Image_Url] NVARCHAR(4000) COLLATE Japanese_CI_AS, [To_User_Id] NVARCHAR(510) COLLATE Japanese_CI_AS, [To_User_Screen_Name] NVARCHAR(510) COLLATE Japanese_CI_AS, [User_Mentions] NVARCHAR(MAX) COLLATE Japanese_CI_AS, [URLs] NVARCHAR(MAX) COLLATE Japanese_CI_AS, [Hashtags] NVARCHAR(MAX) COLLATE Japanese_CI_AS, [Media] NVARCHAR(MAX) COLLATE Japanese_CI_AS, [NextPageToken] NVARCHAR(4000) COLLATE Japanese_CI_AS) WITH (LOCATION = 'Tweets',DATA_SOURCE = [TwitterInstance]) GO --データを確認する SELECT [From_User_Name], [Text], [Created_At] FROM [PolyBase_Twitter].[dbo].[extTwitter_Tweets] ORDER BY [Created_At] DESC --データを確認する SELECT [From_User_Name], [Text], [Created_At] FROM [PolyBase_Twitter].[dbo].[extTwitter_Tweets] WHERE [Text] LIKE '%#jssug%' OR [Text] LIKE '%#dbts2019%' ORDER BY [Created_At] DESC /********************************** *Load Data From Excel and MySQL Demo **********************************/ --Create Database USE [master] GO CREATE DATABASE [PolyBase_MySQL_Excel] CONTAINMENT = NONE ON PRIMARY ( NAME = N'PolyBase_MySQL_Excel', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\PolyBase_MySQL_Excel.mdf' , SIZE = 8192KB , FILEGROWTH = 65536KB ) LOG ON ( NAME = N'PolyBase_MySQL_Excel_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\PolyBase_MySQL_Excel_log.ldf' , SIZE = 8192KB , FILEGROWTH = 65536KB ) GO ALTER DATABASE [PolyBase_MySQL_Excel] SET RECOVERY SIMPLE GO --マスタキーを作成 USE [PolyBase_MySQL_Excel] GO CREATE MASTER KEY ENCRYPTION BY PASSWORD = '{password}' GO /******************* External MySQL *******************/ --現時点のSQL Server 2019 CTP2.1では、 --'<vendor>://<server>[:<port>]' --の接続方法のなかに、vendorのパラメータには、「MySQL」が使えません。ODBC経由で接続しなければならない。 --あらかじめにODBC(64bit)のMySQL接続ドライバーを設定しておくこと。 --クエリのパフォーマンスを向上させるために、ドライバーで接続プールを有効にしていることを確認する。 --この操作は [ODBC データ ソースの管理者] から実現できる --MySQLのログイン資格情報を作成する USE [PolyBase_MySQL_Excel] GO CREATE DATABASE SCOPED CREDENTIAL [MySQLCredential] WITH IDENTITY = 'yangjiayi', Secret = '{password}' GO --Credentialsを確認 select * from sys.database_scoped_credentials --外部データソースを作成する。 CREATE EXTERNAL DATA SOURCE [MySQLInstance] WITH ( LOCATION = 'odbc://PolyBaseVM', CONNECTION_OPTIONS ='Driver={MySQL ODBC 8.0 Unicode Driver};DSN=MySQL', CREDENTIAL = [MySQLCredential]) GO --外部データソースを確認する select * from sys.external_data_sources --外部テーブルを作成する CREATE EXTERNAL TABLE [extMySQL_Address]( [PostCode] [nvarchar](8) NOT NULL, [Location] [nvarchar](100) NOT NULL) WITH (LOCATION = 'PolyBaseDB.Address',DATA_SOURCE = [MySQLInstance]) GO --統計作成、おすすめ、パフォーマンス向上 CREATE STATISTICS [Statistics_PostCode] ON [extMySQL_Address]([PostCode]) WITH FULLSCAN GO --データ確認 SELECT [PostCode],[Location] FROM [PolyBase_MySQL_Excel].[dbo].[extMySQL_Address] /******************* External Excel Files *******************/ --EXCELの資格情報を作成する --資格情報はダミーだが、外部データソースを作成するときに、文法合わせるため、必要である。 --クエリのパフォーマンスを向上させるために、ドライバーで接続プールを有効にしていることを確認する。 --この操作は [ODBC データ ソースの管理者] から実現できる USE [PolyBase_MySQL_Excel] GO CREATE DATABASE SCOPED CREDENTIAL [ExcelCredential] WITH IDENTITY = 'MyExcel', Secret = '' GO --Credentialsを確認 select * from sys.database_scoped_credentials --外部データソースを作成する。 CREATE EXTERNAL DATA SOURCE [ExcelInstance] WITH ( LOCATION = 'odbc://PolyBaseVM', CONNECTION_OPTIONS ='DRIVER={CData ODBC Driver for Excel};DSN=CData Excel Sys', CREDENTIAL = [ExcelCredential]) GO --外部データソースを確認する select * from sys.external_data_sources --外部テーブルを作成する(Person) CREATE EXTERNAL TABLE [extExcel_Person]( [RowId] INT NOT NULL, [PersonID] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Name] NVARCHAR(4000) COLLATE Japanese_CI_AS, [CorpCode] NVARCHAR(4000) COLLATE Japanese_CI_AS, [PostCode] NVARCHAR(4000) COLLATE Japanese_CI_AS) WITH (LOCATION = 'PersonTbl',DATA_SOURCE = [ExcelInstance]) GO --統計作成、おすすめ、パフォーマンス向上 CREATE STATISTICS [Statistics_PersonID] ON [extExcel_Person]([PersonID]) WITH FULLSCAN GO --データ確認 SELECT [PersonID],[Name],[CorpCode],[PostCode] FROM [PolyBase_MySQL_Excel].[dbo].[extExcel_Person] --外部テーブルを作成する(Sales) CREATE EXTERNAL TABLE [extExcel_Sales]( [RowId] INT NOT NULL, [PersonID] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Qty] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Price] NVARCHAR(4000) COLLATE Japanese_CI_AS, [Total] NVARCHAR(4000) COLLATE Japanese_CI_AS) WITH (LOCATION = 'SalesTbl',DATA_SOURCE = [ExcelInstance]) GO --データ確認 SELECT [PersonID],[Qty],[Price],[Total] FROM [PolyBase_MySQL_Excel].[dbo].[extExcel_Sales] --各テーブル結合クエリ SELECT tblExcel1.PersonID,tblExcel1.[Name],tblMysql.[Location],tblExcel2.Total FROM [PolyBase_MySQL_Excel].[dbo].[extExcel_Person] AS tblExcel1 INNER JOIN [PolyBase_MySQL_Excel].[dbo].[extExcel_Sales] AS tblExcel2 ON tblExcel1.PersonID COLLATE Japanese_CI_AS = tblExcel2.PersonID COLLATE Japanese_CI_AS INNER JOIN [PolyBase_MySQL_Excel].[dbo].[extMySQL_Address] AS tblMysql ON tblExcel1.PostCode COLLATE Japanese_CI_AS = tblMysql.PostCode COLLATE Japanese_CI_AS ORDER BY tblExcel1.PersonID /******************* 削除する場合 *******************/ --DROP EXTERNAL TABLE [extDocker_Corp] --DROP EXTERNAL DATA SOURCE [DockerSQLServerInstance] --DROP DATABASE SCOPED CREDENTIAL [DockerSQLServerCredential] --DROP EXTERNAL TABLE [extMySQL_Address] --DROP EXTERNAL DATA SOURCE [MySQLInstance] --DROP DATABASE SCOPED CREDENTIAL [MySQLCredential] --DROP EXTERNAL TABLE [extExcel_Person] --DROP EXTERNAL DATA SOURCE [ExcelInstance] --DROP DATABASE SCOPED CREDENTIAL [ExcelCredential] USE [master] GO ALTER DATABASE [PolyBase_MySQL_Excel] SET SINGLE_USER WITH ROLLBACK IMMEDIATE GO USE [master] GO DROP DATABASE [PolyBase_MySQL_Excel] GO USE [master] GO ALTER DATABASE [PolyBase_Twitter] SET SINGLE_USER WITH ROLLBACK IMMEDIATE GO USE [master] GO DROP DATABASE [PolyBase_Twitter] GO |