|
| 1 | +--------------------------------------------------------------------- |
| 2 | +-- Script that creates the sample database PerformanceV3 |
| 3 | +-- |
| 4 | +-- Last updated: 20141125 |
| 5 | +-- |
| 6 | +-- © Itzik Ben-Gan |
| 7 | +--------------------------------------------------------------------- |
| 8 | + |
| 9 | +-- creation script for sample database and tables |
| 10 | +SET NOCOUNT ON; |
| 11 | +USE master; |
| 12 | +IF DB_ID(N'PerformanceV3') IS NULL CREATE DATABASE PerformanceV3; |
| 13 | +GO |
| 14 | +USE PerformanceV3; |
| 15 | +GO |
| 16 | + |
| 17 | +-- drop objects if exist |
| 18 | +IF OBJECT_ID(N'dbo.GetNums', N'IF') IS NOT NULL DROP FUNCTION dbo.GetNums; |
| 19 | + |
| 20 | +IF OBJECT_ID(N'dbo.VEmpOrders', N'V') IS NOT NULL DROP VIEW dbo.VEmpOrders; |
| 21 | + |
| 22 | +IF OBJECT_ID(N'dbo.Orders' , N'U') IS NOT NULL DROP TABLE dbo.Orders; |
| 23 | +IF OBJECT_ID(N'dbo.Customers', N'U') IS NOT NULL DROP TABLE dbo.Customers; |
| 24 | +IF OBJECT_ID(N'dbo.Employees', N'U') IS NOT NULL DROP TABLE dbo.Employees; |
| 25 | +IF OBJECT_ID(N'dbo.Shippers' , N'U') IS NOT NULL DROP TABLE dbo.Shippers; |
| 26 | + |
| 27 | +IF OBJECT_ID(N'dbo.Fact' , N'U') IS NOT NULL DROP TABLE dbo.Fact; |
| 28 | +IF OBJECT_ID(N'dbo.FactCS', N'U') IS NOT NULL DROP TABLE dbo.FactCS; |
| 29 | +IF OBJECT_ID(N'dbo.Dim1' , N'U') IS NOT NULL DROP TABLE dbo.Dim1; |
| 30 | +IF OBJECT_ID(N'dbo.Dim2' , N'U') IS NOT NULL DROP TABLE dbo.Dim2; |
| 31 | +IF OBJECT_ID(N'dbo.Dim3' , N'U') IS NOT NULL DROP TABLE dbo.Dim3; |
| 32 | +GO |
| 33 | + |
| 34 | +-- definition of GetNums function |
| 35 | +CREATE FUNCTION dbo.GetNums(@low AS BIGINT, @high AS BIGINT) RETURNS TABLE |
| 36 | +AS |
| 37 | +RETURN |
| 38 | + WITH |
| 39 | + L0 AS (SELECT c FROM (VALUES(1),(1)) AS D(c)), |
| 40 | + L1 AS (SELECT 1 AS c FROM L0 AS A CROSS JOIN L0 AS B), |
| 41 | + L2 AS (SELECT 1 AS c FROM L1 AS A CROSS JOIN L1 AS B), |
| 42 | + L3 AS (SELECT 1 AS c FROM L2 AS A CROSS JOIN L2 AS B), |
| 43 | + L4 AS (SELECT 1 AS c FROM L3 AS A CROSS JOIN L3 AS B), |
| 44 | + L5 AS (SELECT 1 AS c FROM L4 AS A CROSS JOIN L4 AS B), |
| 45 | + Nums AS (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS rownum |
| 46 | + FROM L5) |
| 47 | + SELECT TOP(@high - @low + 1) @low + rownum - 1 AS n |
| 48 | + FROM Nums |
| 49 | + ORDER BY rownum; |
| 50 | +GO |
| 51 | + |
| 52 | +-- data distribution settings for orders |
| 53 | +DECLARE |
| 54 | + @numorders AS INT = 1000000, |
| 55 | + @numcusts AS INT = 20000, |
| 56 | + @numemps AS INT = 500, |
| 57 | + @numshippers AS INT = 5, |
| 58 | + @numyears AS INT = 4, |
| 59 | + @startdate AS DATE = '20110101'; |
| 60 | + |
| 61 | +-- creating and populating the Customers table |
| 62 | +CREATE TABLE dbo.Customers |
| 63 | +( |
| 64 | + custid CHAR(11) NOT NULL, |
| 65 | + custname NVARCHAR(50) NOT NULL |
| 66 | +); |
| 67 | + |
| 68 | +INSERT INTO dbo.Customers(custid, custname) |
| 69 | + SELECT |
| 70 | + 'C' + RIGHT('000000000' + CAST(n AS VARCHAR(10)), 10) AS custid, |
| 71 | + N'Cust_' + CAST(n AS VARCHAR(10)) AS custname |
| 72 | + FROM dbo.GetNums(1, @numcusts); |
| 73 | + |
| 74 | +ALTER TABLE dbo.Customers ADD |
| 75 | + CONSTRAINT PK_Customers PRIMARY KEY(custid); |
| 76 | + |
| 77 | +-- creating and populating the Employees table |
| 78 | +CREATE TABLE dbo.Employees |
| 79 | +( |
| 80 | + empid INT NOT NULL, |
| 81 | + firstname NVARCHAR(25) NOT NULL, |
| 82 | + lastname NVARCHAR(25) NOT NULL |
| 83 | +); |
| 84 | + |
| 85 | +INSERT INTO dbo.Employees(empid, firstname, lastname) |
| 86 | + SELECT n AS empid, |
| 87 | + N'Fname_' + CAST(n AS NVARCHAR(10)) AS firstname, |
| 88 | + N'Lname_' + CAST(n AS NVARCHAR(10)) AS lastname |
| 89 | + FROM dbo.GetNums(1, @numemps); |
| 90 | + |
| 91 | +ALTER TABLE dbo.Employees ADD |
| 92 | + CONSTRAINT PK_Employees PRIMARY KEY(empid); |
| 93 | + |
| 94 | +-- creating and populating the Shippers table |
| 95 | +CREATE TABLE dbo.Shippers |
| 96 | +( |
| 97 | + shipperid VARCHAR(5) NOT NULL, |
| 98 | + shippername NVARCHAR(50) NOT NULL |
| 99 | +); |
| 100 | + |
| 101 | +INSERT INTO dbo.Shippers(shipperid, shippername) |
| 102 | + SELECT shipperid, N'Shipper_' + shipperid AS shippername |
| 103 | + FROM (SELECT CHAR(ASCII('A') - 2 + 2 * n) AS shipperid |
| 104 | + FROM dbo.GetNums(1, @numshippers)) AS D; |
| 105 | + |
| 106 | +ALTER TABLE dbo.Shippers ADD |
| 107 | + CONSTRAINT PK_Shippers PRIMARY KEY(shipperid); |
| 108 | + |
| 109 | +-- creating and populating the Orders table |
| 110 | +CREATE TABLE dbo.Orders |
| 111 | +( |
| 112 | + orderid INT NOT NULL, |
| 113 | + custid CHAR(11) NOT NULL, |
| 114 | + empid INT NOT NULL, |
| 115 | + shipperid VARCHAR(5) NOT NULL, |
| 116 | + orderdate DATE NOT NULL, |
| 117 | + filler CHAR(160) NOT NULL DEFAULT('a') |
| 118 | +); |
| 119 | + |
| 120 | +INSERT INTO dbo.Orders(orderid, custid, empid, shipperid, orderdate) |
| 121 | + SELECT n AS orderid, |
| 122 | + 'C' + RIGHT('000000000' |
| 123 | + + CAST( |
| 124 | + 1 + ABS(CHECKSUM(NEWID())) % @numcusts |
| 125 | + AS VARCHAR(10)), 10) AS custid, |
| 126 | + 1 + ABS(CHECKSUM(NEWID())) % @numemps AS empid, |
| 127 | + CHAR(ASCII('A') - 2 |
| 128 | + + 2 * (1 + ABS(CHECKSUM(NEWID())) % @numshippers)) AS shipperid, |
| 129 | + DATEADD(day, n / (@numorders / (@numyears * 365.25)) |
| 130 | + -- late arrival with earlier date |
| 131 | + - CASE WHEN n % 10 = 0 |
| 132 | + THEN 1 + ABS(CHECKSUM(NEWID())) % 30 |
| 133 | + ELSE 0 |
| 134 | + END, @startdate) |
| 135 | + AS orderdate |
| 136 | + FROM dbo.GetNums(1, @numorders) |
| 137 | + ORDER BY CHECKSUM(NEWID()) |
| 138 | +OPTION(MAXDOP 1); |
| 139 | + |
| 140 | +CREATE CLUSTERED INDEX idx_cl_od ON dbo.Orders(orderdate); |
| 141 | + |
| 142 | +CREATE NONCLUSTERED INDEX idx_nc_sid_od_cid |
| 143 | + ON dbo.Orders(shipperid, orderdate, custid); |
| 144 | + |
| 145 | +CREATE UNIQUE INDEX idx_unc_od_oid_i_cid_eid |
| 146 | + ON dbo.Orders(orderdate, orderid) |
| 147 | + INCLUDE(custid, empid); |
| 148 | + |
| 149 | +ALTER TABLE dbo.Orders ADD |
| 150 | + CONSTRAINT PK_Orders PRIMARY KEY NONCLUSTERED(orderid), |
| 151 | + CONSTRAINT FK_Orders_Customers |
| 152 | + FOREIGN KEY(custid) REFERENCES dbo.Customers(custid), |
| 153 | + CONSTRAINT FK_Orders_Employees |
| 154 | + FOREIGN KEY(empid) REFERENCES dbo.Employees(empid), |
| 155 | + CONSTRAINT FK_Orders_Shippers |
| 156 | + FOREIGN KEY(shipperid) REFERENCES dbo.Shippers(shipperid); |
| 157 | +GO |
| 158 | + |
| 159 | +-- data distribution settings for dw (2,500,000 rows) |
| 160 | +DECLARE |
| 161 | + @dim1rows AS INT = 250, |
| 162 | + @dim2rows AS INT = 50, |
| 163 | + @dim3rows AS INT = 200; |
| 164 | + |
| 165 | +CREATE TABLE dbo.Dim1 |
| 166 | +( |
| 167 | + key1 INT NOT NULL CONSTRAINT PK_Dim1 PRIMARY KEY, |
| 168 | + attr1 INT NOT NULL, |
| 169 | + filler BINARY(100) NOT NULL DEFAULT (0x) |
| 170 | +); |
| 171 | + |
| 172 | +CREATE TABLE dbo.Dim2 |
| 173 | +( |
| 174 | + key2 INT NOT NULL CONSTRAINT PK_Dim2 PRIMARY KEY, |
| 175 | + attr1 INT NOT NULL, |
| 176 | + filler BINARY(100) NOT NULL DEFAULT (0x) |
| 177 | +); |
| 178 | + |
| 179 | +CREATE TABLE dbo.Dim3 |
| 180 | +( |
| 181 | + key3 INT NOT NULL CONSTRAINT PK_Dim3 PRIMARY KEY, |
| 182 | + attr1 INT NOT NULL, |
| 183 | + filler BINARY(100) NOT NULL DEFAULT (0x) |
| 184 | +); |
| 185 | + |
| 186 | +CREATE TABLE dbo.Fact |
| 187 | +( |
| 188 | + key1 INT NOT NULL, |
| 189 | + key2 INT NOT NULL, |
| 190 | + key3 INT NOT NULL, |
| 191 | + measure1 INT NOT NULL, |
| 192 | + measure2 INT NOT NULL, |
| 193 | + measure3 INT NOT NULL, |
| 194 | + measure4 NVARCHAR(50) NULL, |
| 195 | + filler BINARY(100) NOT NULL DEFAULT (0x), |
| 196 | + CONSTRAINT PK_Fact PRIMARY KEY(key1, key2, key3) |
| 197 | +); |
| 198 | + |
| 199 | +INSERT INTO dbo.Dim1(key1, attr1) |
| 200 | + SELECT n, ABS(CHECKSUM(NEWID())) % 20 + 1 |
| 201 | + FROM dbo.GetNums(1, @dim1rows); |
| 202 | + |
| 203 | +INSERT INTO dbo.Dim2(key2, attr1) |
| 204 | + SELECT n, ABS(CHECKSUM(NEWID())) % 10 + 1 |
| 205 | + FROM dbo.GetNums(1, @dim2rows); |
| 206 | + |
| 207 | +INSERT INTO dbo.Dim3(key3, attr1) |
| 208 | + SELECT n, ABS(CHECKSUM(NEWID())) % 40 + 1 |
| 209 | + FROM dbo.GetNums(1, @dim3rows); |
| 210 | + |
| 211 | +INSERT INTO dbo.Fact WITH (TABLOCK) |
| 212 | + (key1, key2, key3, measure1, measure2, measure3, measure4) |
| 213 | + SELECT D1.key1, D2.key2, D3.key3, |
| 214 | + ABS(CHECKSUM(NEWID())) % 10000 + 1, |
| 215 | + ABS(CHECKSUM(NEWID())) % 100000 + 1, |
| 216 | + ABS(CHECKSUM(NEWID())) % 1000000 + 1, |
| 217 | + N'S' + REPLICATE(CAST(ABS(CHECKSUM(NEWID())) % 100000 + 1 AS NVARCHAR(10)), 5) |
| 218 | + FROM dbo.Dim1 AS D1 |
| 219 | + CROSS JOIN dbo.Dim2 AS D2 |
| 220 | + CROSS JOIN dbo.Dim3 AS D3; |
0 commit comments