forked from lorint/AdventureWorks-for-Postgres
-
Notifications
You must be signed in to change notification settings - Fork 0
/
install.sql
3316 lines (2982 loc) · 190 KB
/
install.sql
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
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
-- AdventureWorks for Postgres
-- by Lorin Thwaits
-- How to use this script:
-- Download "Adventure Works 2014 OLTP Script" from:
-- https://msftdbprodsamples.codeplex.com/downloads/get/880662
-- Extract the .zip and copy all of the CSV files into the same folder containing
-- this install.sql file and the update_csvs.rb file.
-- Modify the CSVs to work with Postgres by running:
-- ruby update_csvs.rb
-- Create the database and tables, import the data, and set up the views and keys with:
-- psql -c "CREATE DATABASE \"Adventureworks\";"
-- psql -d Adventureworks < install.sql
-- All 68 tables are properly set up.
-- All 20 views are established.
-- 68 additional convenience views are added which:
-- * Provide a shorthand to refer to tables.
-- * Add an "id" column to a primary key or primary-ish key if it makes sense.
--
-- For example, with the convenience views you can simply do:
-- SELECT pe.p.firstname, hr.e.jobtitle
-- FROM pe.p
-- INNER JOIN hr.e ON pe.p.id = hr.e.id;
-- Instead of:
-- SELECT p.firstname, e.jobtitle
-- FROM person.person AS p
-- INNER JOIN humanresources.employee AS e ON p.businessentityid = e.businessentityid;
--
-- Schemas for these views:
-- pe = person
-- hr = humanresources
-- pr = production
-- pu = purchasing
-- sa = sales
-- Easily get a list of all of these with: \dv (pe|hr|pr|pu|sa).*
-- Enjoy!
-- -- Disconnect all other existing connections
-- SELECT pg_terminate_backend(pid)
-- FROM pg_stat_activity
-- WHERE pid <> pg_backend_pid() AND datname='Adventureworks';
\pset tuples_only on
-- Support to auto-generate UUIDs (aka GUIDs)
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Support crosstab function to do PIVOT thing for Sales.vSalesPersonSalesByFiscalYears
CREATE EXTENSION tablefunc;
-------------------------------------
-- Custom data types
-------------------------------------
CREATE DOMAIN "OrderNumber" varchar(25) NULL;
CREATE DOMAIN "AccountNumber" varchar(15) NULL;
CREATE DOMAIN "Flag" boolean NOT NULL;
CREATE DOMAIN "NameStyle" boolean NOT NULL;
CREATE DOMAIN "Name" varchar(50) NULL;
CREATE DOMAIN "Phone" varchar(25) NULL;
-------------------------------------
-- Five schemas, with tables and data
-------------------------------------
CREATE SCHEMA Person
CREATE TABLE BusinessEntity(
BusinessEntityID SERIAL, -- NOT FOR REPLICATION
rowguid uuid NOT NULL CONSTRAINT "DF_BusinessEntity_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_BusinessEntity_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Person(
BusinessEntityID INT NOT NULL,
PersonType char(2) NOT NULL,
NameStyle "NameStyle" NOT NULL CONSTRAINT "DF_Person_NameStyle" DEFAULT (false),
Title varchar(8) NULL,
FirstName "Name" NOT NULL,
MiddleName "Name" NULL,
LastName "Name" NOT NULL,
Suffix varchar(10) NULL,
EmailPromotion INT NOT NULL CONSTRAINT "DF_Person_EmailPromotion" DEFAULT (0),
AdditionalContactInfo XML NULL, -- XML("AdditionalContactInfoSchemaCollection"),
Demographics XML NULL, -- XML("IndividualSurveySchemaCollection"),
rowguid uuid NOT NULL CONSTRAINT "DF_Person_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Person_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_Person_EmailPromotion" CHECK (EmailPromotion BETWEEN 0 AND 2),
CONSTRAINT "CK_Person_PersonType" CHECK (PersonType IS NULL OR UPPER(PersonType) IN ('SC', 'VC', 'IN', 'EM', 'SP', 'GC'))
)
CREATE TABLE StateProvince(
StateProvinceID SERIAL,
StateProvinceCode char(3) NOT NULL,
CountryRegionCode varchar(3) NOT NULL,
IsOnlyStateProvinceFlag "Flag" NOT NULL CONSTRAINT "DF_StateProvince_IsOnlyStateProvinceFlag" DEFAULT (true),
Name "Name" NOT NULL,
TerritoryID INT NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_StateProvince_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_StateProvince_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Address(
AddressID SERIAL, -- NOT FOR REPLICATION
AddressLine1 varchar(60) NOT NULL,
AddressLine2 varchar(60) NULL,
City varchar(30) NOT NULL,
StateProvinceID INT NOT NULL,
PostalCode varchar(15) NOT NULL,
SpatialLocation bytea NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_Address_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Address_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE AddressType(
AddressTypeID SERIAL,
Name "Name" NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_AddressType_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_AddressType_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE BusinessEntityAddress(
BusinessEntityID INT NOT NULL,
AddressID INT NOT NULL,
AddressTypeID INT NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_BusinessEntityAddress_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_BusinessEntityAddress_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ContactType(
ContactTypeID SERIAL,
Name "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ContactType_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE BusinessEntityContact(
BusinessEntityID INT NOT NULL,
PersonID INT NOT NULL,
ContactTypeID INT NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_BusinessEntityContact_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_BusinessEntityContact_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE EmailAddress(
BusinessEntityID INT NOT NULL,
EmailAddressID SERIAL,
EmailAddress varchar(50) NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_EmailAddress_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_EmailAddress_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Password(
BusinessEntityID INT NOT NULL,
PasswordHash VARCHAR(128) NOT NULL,
PasswordSalt VARCHAR(10) NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_Password_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Password_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE PhoneNumberType(
PhoneNumberTypeID SERIAL,
Name "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_PhoneNumberType_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE PersonPhone(
BusinessEntityID INT NOT NULL,
PhoneNumber "Phone" NOT NULL,
PhoneNumberTypeID INT NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_PersonPhone_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE CountryRegion(
CountryRegionCode varchar(3) NOT NULL,
Name "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_CountryRegion_ModifiedDate" DEFAULT (NOW())
);
COMMENT ON SCHEMA Person IS 'Contains objects related to names and addresses of customers, vendors, and employees';
SELECT 'Copying data into Person.BusinessEntity';
\copy Person.BusinessEntity FROM './BusinessEntity.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.Person';
\copy Person.Person FROM './Person.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.StateProvince';
\copy Person.StateProvince FROM './StateProvince.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.Address';
\copy Person.Address FROM './Address.csv' DELIMITER E'\t' CSV ENCODING 'latin1';
SELECT 'Copying data into Person.AddressType';
\copy Person.AddressType FROM './AddressType.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.BusinessEntityAddress';
\copy Person.BusinessEntityAddress FROM './BusinessEntityAddress.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.ContactType';
\copy Person.ContactType FROM './ContactType.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.BusinessEntityContact';
\copy Person.BusinessEntityContact FROM './BusinessEntityContact.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.EmailAddress';
\copy Person.EmailAddress FROM './EmailAddress.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.Password';
\copy Person.Password FROM './Password.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.PhoneNumberType';
\copy Person.PhoneNumberType FROM './PhoneNumberType.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.PersonPhone';
\copy Person.PersonPhone FROM './PersonPhone.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Person.CountryRegion';
\copy Person.CountryRegion FROM './CountryRegion.csv' DELIMITER E'\t' CSV;
CREATE SCHEMA HumanResources
CREATE TABLE Department(
DepartmentID SERIAL NOT NULL, -- smallint
Name "Name" NOT NULL,
GroupName "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Department_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Employee(
BusinessEntityID INT NOT NULL,
NationalIDNumber varchar(15) NOT NULL,
LoginID varchar(256) NOT NULL,
Org varchar NULL,-- hierarchyid, will become OrganizationNode
OrganizationLevel INT NULL, -- AS OrganizationNode.GetLevel(),
JobTitle varchar(50) NOT NULL,
BirthDate DATE NOT NULL,
MaritalStatus char(1) NOT NULL,
Gender char(1) NOT NULL,
HireDate DATE NOT NULL,
SalariedFlag "Flag" NOT NULL CONSTRAINT "DF_Employee_SalariedFlag" DEFAULT (true),
VacationHours smallint NOT NULL CONSTRAINT "DF_Employee_VacationHours" DEFAULT (0),
SickLeaveHours smallint NOT NULL CONSTRAINT "DF_Employee_SickLeaveHours" DEFAULT (0),
CurrentFlag "Flag" NOT NULL CONSTRAINT "DF_Employee_CurrentFlag" DEFAULT (true),
rowguid uuid NOT NULL CONSTRAINT "DF_Employee_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Employee_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_Employee_BirthDate" CHECK (BirthDate BETWEEN '1930-01-01' AND NOW() - INTERVAL '18 years'),
CONSTRAINT "CK_Employee_MaritalStatus" CHECK (UPPER(MaritalStatus) IN ('M', 'S')), -- Married or Single
CONSTRAINT "CK_Employee_HireDate" CHECK (HireDate BETWEEN '1996-07-01' AND NOW() + INTERVAL '1 day'),
CONSTRAINT "CK_Employee_Gender" CHECK (UPPER(Gender) IN ('M', 'F')), -- Male or Female
CONSTRAINT "CK_Employee_VacationHours" CHECK (VacationHours BETWEEN -40 AND 240),
CONSTRAINT "CK_Employee_SickLeaveHours" CHECK (SickLeaveHours BETWEEN 0 AND 120)
)
CREATE TABLE EmployeeDepartmentHistory(
BusinessEntityID INT NOT NULL,
DepartmentID smallint NOT NULL,
ShiftID smallint NOT NULL, -- tinyint
StartDate DATE NOT NULL,
EndDate DATE NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_EmployeeDepartmentHistory_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_EmployeeDepartmentHistory_EndDate" CHECK ((EndDate >= StartDate) OR (EndDate IS NULL))
)
CREATE TABLE EmployeePayHistory(
BusinessEntityID INT NOT NULL,
RateChangeDate TIMESTAMP NOT NULL,
Rate numeric NOT NULL, -- money
PayFrequency smallint NOT NULL, -- tinyint
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_EmployeePayHistory_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_EmployeePayHistory_PayFrequency" CHECK (PayFrequency IN (1, 2)), -- 1 = monthly salary, 2 = biweekly salary
CONSTRAINT "CK_EmployeePayHistory_Rate" CHECK (Rate BETWEEN 6.50 AND 200.00)
)
CREATE TABLE JobCandidate(
JobCandidateID SERIAL NOT NULL, -- int
BusinessEntityID INT NULL,
Resume XML NULL, -- XML(HRResumeSchemaCollection)
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_JobCandidate_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Shift(
ShiftID SERIAL NOT NULL, -- tinyint
Name "Name" NOT NULL,
StartTime time NOT NULL,
EndTime time NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Shift_ModifiedDate" DEFAULT (NOW())
);
COMMENT ON SCHEMA HumanResources IS 'Contains objects related to employees and departments.';
SELECT 'Copying data into HumanResources.Department';
\copy HumanResources.Department FROM './Department.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into HumanResources.Employee';
\copy HumanResources.Employee FROM './Employee.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into HumanResources.EmployeeDepartmentHistory';
\copy HumanResources.EmployeeDepartmentHistory FROM './EmployeeDepartmentHistory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into HumanResources.EmployeePayHistory';
\copy HumanResources.EmployeePayHistory FROM './EmployeePayHistory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into HumanResources.JobCandidate';
\copy HumanResources.JobCandidate FROM './JobCandidate.csv' DELIMITER E'\t' CSV ENCODING 'latin1';
SELECT 'Copying data into HumanResources.Shift';
\copy HumanResources.Shift FROM './Shift.csv' DELIMITER E'\t' CSV;
-- Calculated column that needed to be there just for the CSV import
ALTER TABLE HumanResources.Employee DROP COLUMN OrganizationLevel;
-- Employee HierarchyID column
ALTER TABLE HumanResources.Employee ADD organizationnode VARCHAR DEFAULT '/';
-- Convert from all the hex to a stream of hierarchyid bits
WITH RECURSIVE hier AS (
SELECT businessentityid, org, get_byte(decode(substring(org, 1, 2), 'hex'), 0)::bit(8)::varchar AS bits, 2 AS i
FROM HumanResources.Employee
UNION ALL
SELECT e.businessentityid, e.org, hier.bits || get_byte(decode(substring(e.org, i + 1, 2), 'hex'), 0)::bit(8)::varchar, i + 2 AS i
FROM HumanResources.Employee AS e INNER JOIN
hier ON e.businessentityid = hier.businessentityid AND i < LENGTH(e.org)
)
UPDATE HumanResources.Employee AS emp
SET org = COALESCE(trim(trailing '0' FROM hier.bits::TEXT), '')
FROM hier
WHERE emp.businessentityid = hier.businessentityid
AND (hier.org IS NULL OR i = LENGTH(hier.org));
-- Convert bits to the real hieararchy paths
CREATE OR REPLACE FUNCTION f_ConvertOrgNodes()
RETURNS void AS
$func$
DECLARE
got_none BOOLEAN;
BEGIN
LOOP
got_none := true;
-- 01 = 0-3
UPDATE HumanResources.Employee
SET organizationnode = organizationnode || SUBSTRING(org, 3,2)::bit(2)::INTEGER::VARCHAR || CASE SUBSTRING(org, 5, 1) WHEN '0' THEN '.' ELSE '/' END,
org = SUBSTRING(org, 6, 9999)
WHERE org LIKE '01%';
IF FOUND THEN
got_none := false;
END IF;
-- 100 = 4-7
UPDATE HumanResources.Employee
SET organizationnode = organizationnode || (SUBSTRING(org, 4,2)::bit(2)::INTEGER + 4)::VARCHAR || CASE SUBSTRING(org, 6, 1) WHEN '0' THEN '.' ELSE '/' END,
org = SUBSTRING(org, 7, 9999)
WHERE org LIKE '100%';
IF FOUND THEN
got_none := false;
END IF;
-- 101 = 8-15
UPDATE HumanResources.Employee
SET organizationnode = organizationnode || (SUBSTRING(org, 4,3)::bit(3)::INTEGER + 8)::VARCHAR || CASE SUBSTRING(org, 7, 1) WHEN '0' THEN '.' ELSE '/' END,
org = SUBSTRING(org, 8, 9999)
WHERE org LIKE '101%';
IF FOUND THEN
got_none := false;
END IF;
-- 110 = 16-79
UPDATE HumanResources.Employee
SET organizationnode = organizationnode || ((SUBSTRING(org, 4,2)||SUBSTRING(org, 7,1)||SUBSTRING(org, 9,3))::bit(6)::INTEGER + 16)::VARCHAR || CASE SUBSTRING(org, 12, 1) WHEN '0' THEN '.' ELSE '/' END,
org = SUBSTRING(org, 13, 9999)
WHERE org LIKE '110%';
IF FOUND THEN
got_none := false;
END IF;
-- 1110 = 80-1103
UPDATE HumanResources.Employee
SET organizationnode = organizationnode || ((SUBSTRING(org, 5,3)||SUBSTRING(org, 9,3)||SUBSTRING(org, 13,1)||SUBSTRING(org, 15,3))::bit(10)::INTEGER + 80)::VARCHAR || CASE SUBSTRING(org, 18, 1) WHEN '0' THEN '.' ELSE '/' END,
org = SUBSTRING(org, 19, 9999)
WHERE org LIKE '1110%';
IF FOUND THEN
got_none := false;
END IF;
EXIT WHEN got_none;
END LOOP;
END
$func$ LANGUAGE plpgsql;
SELECT f_ConvertOrgNodes();
-- Drop the original binary hierarchyid column
ALTER TABLE HumanResources.Employee DROP COLUMN Org;
DROP FUNCTION f_ConvertOrgNodes();
CREATE SCHEMA Production
CREATE TABLE BillOfMaterials(
BillOfMaterialsID SERIAL NOT NULL, -- int
ProductAssemblyID INT NULL,
ComponentID INT NOT NULL,
StartDate TIMESTAMP NOT NULL CONSTRAINT "DF_BillOfMaterials_StartDate" DEFAULT (NOW()),
EndDate TIMESTAMP NULL,
UnitMeasureCode char(3) NOT NULL,
BOMLevel smallint NOT NULL,
PerAssemblyQty decimal(8, 2) NOT NULL CONSTRAINT "DF_BillOfMaterials_PerAssemblyQty" DEFAULT (1.00),
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_BillOfMaterials_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_BillOfMaterials_EndDate" CHECK ((EndDate > StartDate) OR (EndDate IS NULL)),
CONSTRAINT "CK_BillOfMaterials_ProductAssemblyID" CHECK (ProductAssemblyID <> ComponentID),
CONSTRAINT "CK_BillOfMaterials_BOMLevel" CHECK (((ProductAssemblyID IS NULL)
AND (BOMLevel = 0) AND (PerAssemblyQty = 1.00))
OR ((ProductAssemblyID IS NOT NULL) AND (BOMLevel >= 1))),
CONSTRAINT "CK_BillOfMaterials_PerAssemblyQty" CHECK (PerAssemblyQty >= 1.00)
)
CREATE TABLE Culture(
CultureID char(6) NOT NULL,
Name "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Culture_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Document(
Doc varchar NULL,-- hierarchyid, will become DocumentNode
DocumentLevel INTEGER, -- AS DocumentNode.GetLevel(),
Title varchar(50) NOT NULL,
Owner INT NOT NULL,
FolderFlag "Flag" NOT NULL CONSTRAINT "DF_Document_FolderFlag" DEFAULT (false),
FileName varchar(400) NOT NULL,
FileExtension varchar(8) NULL,
Revision char(5) NOT NULL,
ChangeNumber INT NOT NULL CONSTRAINT "DF_Document_ChangeNumber" DEFAULT (0),
Status smallint NOT NULL, -- tinyint
DocumentSummary text NULL,
Document bytea NULL, -- varbinary
rowguid uuid NOT NULL UNIQUE CONSTRAINT "DF_Document_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Document_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_Document_Status" CHECK (Status BETWEEN 1 AND 3)
)
CREATE TABLE ProductCategory(
ProductCategoryID SERIAL NOT NULL, -- int
Name "Name" NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_ProductCategory_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductCategory_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductSubcategory(
ProductSubcategoryID SERIAL NOT NULL, -- int
ProductCategoryID INT NOT NULL,
Name "Name" NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_ProductSubcategory_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductSubcategory_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductModel(
ProductModelID SERIAL NOT NULL, -- int
Name "Name" NOT NULL,
CatalogDescription XML NULL, -- XML(Production.ProductDescriptionSchemaCollection)
Instructions XML NULL, -- XML(Production.ManuInstructionsSchemaCollection)
rowguid uuid NOT NULL CONSTRAINT "DF_ProductModel_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductModel_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Product(
ProductID SERIAL NOT NULL, -- int
Name "Name" NOT NULL,
ProductNumber varchar(25) NOT NULL,
MakeFlag "Flag" NOT NULL CONSTRAINT "DF_Product_MakeFlag" DEFAULT (true),
FinishedGoodsFlag "Flag" NOT NULL CONSTRAINT "DF_Product_FinishedGoodsFlag" DEFAULT (true),
Color varchar(15) NULL,
SafetyStockLevel smallint NOT NULL,
ReorderPoint smallint NOT NULL,
StandardCost numeric NOT NULL, -- money
ListPrice numeric NOT NULL, -- money
Size varchar(5) NULL,
SizeUnitMeasureCode char(3) NULL,
WeightUnitMeasureCode char(3) NULL,
Weight decimal(8, 2) NULL,
DaysToManufacture INT NOT NULL,
ProductLine char(2) NULL,
Class char(2) NULL,
Style char(2) NULL,
ProductSubcategoryID INT NULL,
ProductModelID INT NULL,
SellStartDate TIMESTAMP NOT NULL,
SellEndDate TIMESTAMP NULL,
DiscontinuedDate TIMESTAMP NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_Product_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Product_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_Product_SafetyStockLevel" CHECK (SafetyStockLevel > 0),
CONSTRAINT "CK_Product_ReorderPoint" CHECK (ReorderPoint > 0),
CONSTRAINT "CK_Product_StandardCost" CHECK (StandardCost >= 0.00),
CONSTRAINT "CK_Product_ListPrice" CHECK (ListPrice >= 0.00),
CONSTRAINT "CK_Product_Weight" CHECK (Weight > 0.00),
CONSTRAINT "CK_Product_DaysToManufacture" CHECK (DaysToManufacture >= 0),
CONSTRAINT "CK_Product_ProductLine" CHECK (UPPER(ProductLine) IN ('S', 'T', 'M', 'R') OR ProductLine IS NULL),
CONSTRAINT "CK_Product_Class" CHECK (UPPER(Class) IN ('L', 'M', 'H') OR Class IS NULL),
CONSTRAINT "CK_Product_Style" CHECK (UPPER(Style) IN ('W', 'M', 'U') OR Style IS NULL),
CONSTRAINT "CK_Product_SellEndDate" CHECK ((SellEndDate >= SellStartDate) OR (SellEndDate IS NULL))
)
CREATE TABLE ProductCostHistory(
ProductID INT NOT NULL,
StartDate TIMESTAMP NOT NULL,
EndDate TIMESTAMP NULL,
StandardCost numeric NOT NULL, -- money
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductCostHistory_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_ProductCostHistory_EndDate" CHECK ((EndDate >= StartDate) OR (EndDate IS NULL)),
CONSTRAINT "CK_ProductCostHistory_StandardCost" CHECK (StandardCost >= 0.00)
)
CREATE TABLE ProductDescription(
ProductDescriptionID SERIAL NOT NULL, -- int
Description varchar(400) NOT NULL,
rowguid uuid NOT NULL CONSTRAINT "DF_ProductDescription_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductDescription_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductDocument(
ProductID INT NOT NULL,
Doc varchar NOT NULL, -- hierarchyid, will become DocumentNode
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductDocument_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE Location(
LocationID SERIAL NOT NULL, -- smallint
Name "Name" NOT NULL,
CostRate numeric NOT NULL CONSTRAINT "DF_Location_CostRate" DEFAULT (0.00), -- smallmoney -- money
Availability decimal(8, 2) NOT NULL CONSTRAINT "DF_Location_Availability" DEFAULT (0.00),
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Location_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_Location_CostRate" CHECK (CostRate >= 0.00),
CONSTRAINT "CK_Location_Availability" CHECK (Availability >= 0.00)
)
CREATE TABLE ProductInventory(
ProductID INT NOT NULL,
LocationID smallint NOT NULL,
Shelf varchar(10) NOT NULL,
Bin smallint NOT NULL, -- tinyint
Quantity smallint NOT NULL CONSTRAINT "DF_ProductInventory_Quantity" DEFAULT (0),
rowguid uuid NOT NULL CONSTRAINT "DF_ProductInventory_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductInventory_ModifiedDate" DEFAULT (NOW()),
-- CONSTRAINT "CK_ProductInventory_Shelf" CHECK ((Shelf LIKE 'AZa-z]') OR (Shelf = 'N/A')),
CONSTRAINT "CK_ProductInventory_Bin" CHECK (Bin BETWEEN 0 AND 100)
)
CREATE TABLE ProductListPriceHistory(
ProductID INT NOT NULL,
StartDate TIMESTAMP NOT NULL,
EndDate TIMESTAMP NULL,
ListPrice numeric NOT NULL, -- money
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductListPriceHistory_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_ProductListPriceHistory_EndDate" CHECK ((EndDate >= StartDate) OR (EndDate IS NULL)),
CONSTRAINT "CK_ProductListPriceHistory_ListPrice" CHECK (ListPrice > 0.00)
)
CREATE TABLE Illustration(
IllustrationID SERIAL NOT NULL, -- int
Diagram XML NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Illustration_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductModelIllustration(
ProductModelID INT NOT NULL,
IllustrationID INT NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductModelIllustration_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductModelProductDescriptionCulture(
ProductModelID INT NOT NULL,
ProductDescriptionID INT NOT NULL,
CultureID char(6) NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductModelProductDescriptionCulture_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductPhoto(
ProductPhotoID SERIAL NOT NULL, -- int
ThumbNailPhoto bytea NULL,-- varbinary
ThumbnailPhotoFileName varchar(50) NULL,
LargePhoto bytea NULL,-- varbinary
LargePhotoFileName varchar(50) NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductPhoto_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductProductPhoto(
ProductID INT NOT NULL,
ProductPhotoID INT NOT NULL,
"primary" "Flag" NOT NULL CONSTRAINT "DF_ProductProductPhoto_Primary" DEFAULT (false),
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductProductPhoto_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE ProductReview(
ProductReviewID SERIAL NOT NULL, -- int
ProductID INT NOT NULL,
ReviewerName "Name" NOT NULL,
ReviewDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductReview_ReviewDate" DEFAULT (NOW()),
EmailAddress varchar(50) NOT NULL,
Rating INT NOT NULL,
Comments varchar(3850),
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductReview_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_ProductReview_Rating" CHECK (Rating BETWEEN 1 AND 5)
)
CREATE TABLE ScrapReason(
ScrapReasonID SERIAL NOT NULL, -- smallint
Name "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ScrapReason_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE TransactionHistory(
TransactionID SERIAL NOT NULL, -- INT IDENTITY (100000, 1)
ProductID INT NOT NULL,
ReferenceOrderID INT NOT NULL,
ReferenceOrderLineID INT NOT NULL CONSTRAINT "DF_TransactionHistory_ReferenceOrderLineID" DEFAULT (0),
TransactionDate TIMESTAMP NOT NULL CONSTRAINT "DF_TransactionHistory_TransactionDate" DEFAULT (NOW()),
TransactionType char(1) NOT NULL,
Quantity INT NOT NULL,
ActualCost numeric NOT NULL, -- money
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_TransactionHistory_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_TransactionHistory_TransactionType" CHECK (UPPER(TransactionType) IN ('W', 'S', 'P'))
)
CREATE TABLE TransactionHistoryArchive(
TransactionID INT NOT NULL,
ProductID INT NOT NULL,
ReferenceOrderID INT NOT NULL,
ReferenceOrderLineID INT NOT NULL CONSTRAINT "DF_TransactionHistoryArchive_ReferenceOrderLineID" DEFAULT (0),
TransactionDate TIMESTAMP NOT NULL CONSTRAINT "DF_TransactionHistoryArchive_TransactionDate" DEFAULT (NOW()),
TransactionType char(1) NOT NULL,
Quantity INT NOT NULL,
ActualCost numeric NOT NULL, -- money
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_TransactionHistoryArchive_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_TransactionHistoryArchive_TransactionType" CHECK (UPPER(TransactionType) IN ('W', 'S', 'P'))
)
CREATE TABLE UnitMeasure(
UnitMeasureCode char(3) NOT NULL,
Name "Name" NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_UnitMeasure_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE WorkOrder(
WorkOrderID SERIAL NOT NULL, -- int
ProductID INT NOT NULL,
OrderQty INT NOT NULL,
StockedQty INT, -- AS ISNULL(OrderQty - ScrappedQty, 0),
ScrappedQty smallint NOT NULL,
StartDate TIMESTAMP NOT NULL,
EndDate TIMESTAMP NULL,
DueDate TIMESTAMP NOT NULL,
ScrapReasonID smallint NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_WorkOrder_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_WorkOrder_OrderQty" CHECK (OrderQty > 0),
CONSTRAINT "CK_WorkOrder_ScrappedQty" CHECK (ScrappedQty >= 0),
CONSTRAINT "CK_WorkOrder_EndDate" CHECK ((EndDate >= StartDate) OR (EndDate IS NULL))
)
CREATE TABLE WorkOrderRouting(
WorkOrderID INT NOT NULL,
ProductID INT NOT NULL,
OperationSequence smallint NOT NULL,
LocationID smallint NOT NULL,
ScheduledStartDate TIMESTAMP NOT NULL,
ScheduledEndDate TIMESTAMP NOT NULL,
ActualStartDate TIMESTAMP NULL,
ActualEndDate TIMESTAMP NULL,
ActualResourceHrs decimal(9, 4) NULL,
PlannedCost numeric NOT NULL, -- money
ActualCost numeric NULL, -- money
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_WorkOrderRouting_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_WorkOrderRouting_ScheduledEndDate" CHECK (ScheduledEndDate >= ScheduledStartDate),
CONSTRAINT "CK_WorkOrderRouting_ActualEndDate" CHECK ((ActualEndDate >= ActualStartDate)
OR (ActualEndDate IS NULL) OR (ActualStartDate IS NULL)),
CONSTRAINT "CK_WorkOrderRouting_ActualResourceHrs" CHECK (ActualResourceHrs >= 0.0000),
CONSTRAINT "CK_WorkOrderRouting_PlannedCost" CHECK (PlannedCost > 0.00),
CONSTRAINT "CK_WorkOrderRouting_ActualCost" CHECK (ActualCost > 0.00)
);
COMMENT ON SCHEMA Production IS 'Contains objects related to products, inventory, and manufacturing.';
SELECT 'Copying data into Production.BillOfMaterials';
\copy Production.BillOfMaterials FROM 'BillOfMaterials.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.Culture';
\copy Production.Culture FROM 'Culture.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.Document';
\copy Production.Document FROM 'Document.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductCategory';
\copy Production.ProductCategory FROM 'ProductCategory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductSubcategory';
\copy Production.ProductSubcategory FROM 'ProductSubcategory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductModel';
\copy Production.ProductModel FROM 'ProductModel.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.Product';
\copy Production.Product FROM 'Product.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductCostHistory';
\copy Production.ProductCostHistory FROM 'ProductCostHistory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductDescription';
\copy Production.ProductDescription FROM 'ProductDescription.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductDocument';
\copy Production.ProductDocument FROM 'ProductDocument.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.Location';
\copy Production.Location FROM 'Location.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductInventory';
\copy Production.ProductInventory FROM 'ProductInventory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductListPriceHistory';
\copy Production.ProductListPriceHistory FROM 'ProductListPriceHistory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.Illustration';
\copy Production.Illustration FROM 'Illustration.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductModelIllustration';
\copy Production.ProductModelIllustration FROM 'ProductModelIllustration.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductModelProductDescriptionCulture';
\copy Production.ProductModelProductDescriptionCulture FROM 'ProductModelProductDescriptionCulture.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductPhoto';
\copy Production.ProductPhoto FROM 'ProductPhoto.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.ProductProductPhoto';
\copy Production.ProductProductPhoto FROM 'ProductProductPhoto.csv' DELIMITER E'\t' CSV;
-- This doesn't work:
-- SELECT 'Copying data into Production.ProductReview';
-- \copy Production.ProductReview FROM 'ProductReview.csv' DELIMITER ' ' CSV;
-- so instead ...
INSERT INTO Production.ProductReview (ProductReviewID, ProductID, ReviewerName, ReviewDate, EmailAddress, Rating, Comments, ModifiedDate) VALUES
(1, 709, 'John Smith', '2013-09-18 00:00:00', '[email protected]', 5, 'I can''t believe I''m singing the praises of a pair of socks, but I just came back from a grueling
3-day ride and these socks really helped make the trip a blast. They''re lightweight yet really cushioned my feet all day.
The reinforced toe is nearly bullet-proof and I didn''t experience any problems with rubbing or blisters like I have with
other brands. I know it sounds silly, but it''s always the little stuff (like comfortable feet) that makes or breaks a long trip.
I won''t go on another trip without them!', '2013-09-18 00:00:00'),
(2, 937, 'David', '2013-11-13 00:00:00', '[email protected]', 4, 'A little on the heavy side, but overall the entry/exit is easy in all conditions. I''ve used these pedals for
more than 3 years and I''ve never had a problem. Cleanup is easy. Mud and sand don''t get trapped. I would like
them even better if there was a weight reduction. Maybe in the next design. Still, I would recommend them to a friend.', '2013-11-13 00:00:00'),
(3, 937, 'Jill', '2013-11-15 00:00:00', '[email protected]', 2, 'Maybe it''s just because I''m new to mountain biking, but I had a terrible time getting use
to these pedals. In my first outing, I wiped out trying to release my foot. Any suggestions on
ways I can adjust the pedals, or is it just a learning curve thing?', '2013-11-15 00:00:00'),
(4, 798, 'Laura Norman', '2013-11-15 00:00:00', '[email protected]', 5, 'The Road-550-W from Adventure Works Cycles is everything it''s advertised to be. Finally, a quality bike that
is actually built for a woman and provides control and comfort in one neat package. The top tube is shorter, the suspension is weight-tuned and there''s a much shorter reach to the brake
levers. All this adds up to a great mountain bike that is sure to accommodate any woman''s anatomy. In addition to getting the size right, the saddle is incredibly comfortable.
Attention to detail is apparent in every aspect from the frame finish to the careful design of each component. Each component is a solid performer without any fluff.
The designers clearly did their homework and thought about size, weight, and funtionality throughout. And at less than 19 pounds, the bike is manageable for even the most petite cyclist.
We had 5 riders take the bike out for a spin and really put it to the test. The results were consistent and very positive. Our testers loved the manuverability
and control they had with the redesigned frame on the 550-W. A definite improvement over the 2012 design. Four out of five testers listed quick handling
and responsivness were the key elements they noticed. Technical climbing and on the flats, the bike just cruises through the rough. Tight corners and obstacles were handled effortlessly. The fifth tester was more impressed with the smooth ride. The heavy-duty shocks absorbed even the worst bumps and provided a soft ride on all but the
nastiest trails and biggest drops. The shifting was rated superb and typical of what we''ve come to expect from Adventure Works Cycles. On descents, the bike handled flawlessly and tracked very well. The bike is well balanced front-to-rear and frame flex was minimal. In particular, the testers
noted that the brake system had a unique combination of power and modulation. While some brake setups can be overly touchy, these brakes had a good
amount of power, but also a good feel that allows you to apply as little or as much braking power as is needed. Second is their short break-in period. We found that they tend to break-in well before
the end of the first ride; while others take two to three rides (or more) to come to full power.
On the negative side, the pedals were not quite up to our tester''s standards.
Just for fun, we experimented with routine maintenance tasks. Overall we found most operations to be straight forward and easy to complete. The only exception was replacing the front wheel. The maintenance manual that comes
with the bike say to install the front wheel with the axle quick release or bolt, then compress the fork a few times before fastening and tightening the two quick-release mechanisms on the bottom of the dropouts. This is to seat the axle in the dropouts, and if you do not
do this, the axle will become seated after you tightened the two bottom quick releases, which will then become loose. It''s better to test the tightness carefully or you may notice that the two bottom quick releases have come loose enough to fall completely open. And that''s something you don''t want to experience
while out on the road!
The Road-550-W frame is available in a variety of sizes and colors and has the same durable, high-quality aluminum that AWC is known for. At a MSRP of just under $1125.00, it''s comparable in price to its closest competitors and
we think that after a test drive you''l find the quality and performance above and beyond . You''ll have a grin on your face and be itching to get out on the road for more. While designed for serious road racing, the Road-550-W would be an excellent choice for just about any terrain and
any level of experience. It''s a huge step in the right direction for female cyclists and well worth your consideration and hard-earned money.', '2013-11-15 00:00:00');
SELECT 'Copying data into Production.ScrapReason';
\copy Production.ScrapReason FROM 'ScrapReason.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.TransactionHistory';
\copy Production.TransactionHistory FROM 'TransactionHistory.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.TransactionHistoryArchive';
\copy Production.TransactionHistoryArchive FROM 'TransactionHistoryArchive.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.UnitMeasure';
\copy Production.UnitMeasure FROM 'UnitMeasure.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.WorkOrder';
\copy Production.WorkOrder FROM 'WorkOrder.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Production.WorkOrderRouting';
\copy Production.WorkOrderRouting FROM 'WorkOrderRouting.csv' DELIMITER E'\t' CSV;
-- Calculated columns that needed to be there just for the CSV import
ALTER TABLE Production.WorkOrder DROP COLUMN StockedQty;
ALTER TABLE Production.Document DROP COLUMN DocumentLevel;
-- Document HierarchyID column
ALTER TABLE Production.Document ADD DocumentNode VARCHAR DEFAULT '/';
-- Convert from all the hex to a stream of hierarchyid bits
WITH RECURSIVE hier AS (
SELECT rowguid, doc, get_byte(decode(substring(doc, 1, 2), 'hex'), 0)::bit(8)::varchar AS bits, 2 AS i
FROM Production.Document
UNION ALL
SELECT e.rowguid, e.doc, hier.bits || get_byte(decode(substring(e.doc, i + 1, 2), 'hex'), 0)::bit(8)::varchar, i + 2 AS i
FROM Production.Document AS e INNER JOIN
hier ON e.rowguid = hier.rowguid AND i < LENGTH(e.doc)
)
UPDATE Production.Document AS emp
SET doc = COALESCE(trim(trailing '0' FROM hier.bits::TEXT), '')
FROM hier
WHERE emp.rowguid = hier.rowguid
AND (hier.doc IS NULL OR i = LENGTH(hier.doc));
-- Convert bits to the real hieararchy paths
CREATE OR REPLACE FUNCTION f_ConvertDocNodes()
RETURNS void AS
$func$
DECLARE
got_none BOOLEAN;
BEGIN
LOOP
got_none := true;
-- 01 = 0-3
UPDATE Production.Document
SET DocumentNode = DocumentNode || SUBSTRING(doc, 3,2)::bit(2)::INTEGER::VARCHAR || CASE SUBSTRING(doc, 5, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 6, 9999)
WHERE doc LIKE '01%';
IF FOUND THEN
got_none := false;
END IF;
-- 100 = 4-7
UPDATE Production.Document
SET DocumentNode = DocumentNode || (SUBSTRING(doc, 4,2)::bit(2)::INTEGER + 4)::VARCHAR || CASE SUBSTRING(doc, 6, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 7, 9999)
WHERE doc LIKE '100%';
IF FOUND THEN
got_none := false;
END IF;
-- 101 = 8-15
UPDATE Production.Document
SET DocumentNode = DocumentNode || (SUBSTRING(doc, 4,3)::bit(3)::INTEGER + 8)::VARCHAR || CASE SUBSTRING(doc, 7, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 8, 9999)
WHERE doc LIKE '101%';
IF FOUND THEN
got_none := false;
END IF;
-- 110 = 16-79
UPDATE Production.Document
SET DocumentNode = DocumentNode || ((SUBSTRING(doc, 4,2)||SUBSTRING(doc, 7,1)||SUBSTRING(doc, 9,3))::bit(6)::INTEGER + 16)::VARCHAR || CASE SUBSTRING(doc, 12, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 13, 9999)
WHERE doc LIKE '110%';
IF FOUND THEN
got_none := false;
END IF;
-- 1110 = 80-1103
UPDATE Production.Document
SET DocumentNode = DocumentNode || ((SUBSTRING(doc, 5,3)||SUBSTRING(doc, 9,3)||SUBSTRING(doc, 13,1)||SUBSTRING(doc, 15,3))::bit(10)::INTEGER + 80)::VARCHAR || CASE SUBSTRING(doc, 18, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 19, 9999)
WHERE doc LIKE '1110%';
IF FOUND THEN
got_none := false;
END IF;
EXIT WHEN got_none;
END LOOP;
END
$func$ LANGUAGE plpgsql;
SELECT f_ConvertDocNodes();
-- Drop the original binary hierarchyid column
ALTER TABLE Production.Document DROP COLUMN Doc;
DROP FUNCTION f_ConvertDocNodes();
-- ProductDocument HierarchyID column
ALTER TABLE Production.ProductDocument ADD DocumentNode VARCHAR DEFAULT '/';
ALTER TABLE Production.ProductDocument ADD rowguid uuid NOT NULL CONSTRAINT "DF_ProductDocument_rowguid" DEFAULT (uuid_generate_v1());
-- Convert from all the hex to a stream of hierarchyid bits
WITH RECURSIVE hier AS (
SELECT rowguid, doc, get_byte(decode(substring(doc, 1, 2), 'hex'), 0)::bit(8)::varchar AS bits, 2 AS i
FROM Production.ProductDocument
UNION ALL
SELECT e.rowguid, e.doc, hier.bits || get_byte(decode(substring(e.doc, i + 1, 2), 'hex'), 0)::bit(8)::varchar, i + 2 AS i
FROM Production.ProductDocument AS e INNER JOIN
hier ON e.rowguid = hier.rowguid AND i < LENGTH(e.doc)
)
UPDATE Production.ProductDocument AS emp
SET doc = COALESCE(trim(trailing '0' FROM hier.bits::TEXT), '')
FROM hier
WHERE emp.rowguid = hier.rowguid
AND (hier.doc IS NULL OR i = LENGTH(hier.doc));
-- Convert bits to the real hieararchy paths
CREATE OR REPLACE FUNCTION f_ConvertDocNodes()
RETURNS void AS
$func$
DECLARE
got_none BOOLEAN;
BEGIN
LOOP
got_none := true;
-- 01 = 0-3
UPDATE Production.ProductDocument
SET DocumentNode = DocumentNode || SUBSTRING(doc, 3,2)::bit(2)::INTEGER::VARCHAR || CASE SUBSTRING(doc, 5, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 6, 9999)
WHERE doc LIKE '01%';
IF FOUND THEN
got_none := false;
END IF;
-- 100 = 4-7
UPDATE Production.ProductDocument
SET DocumentNode = DocumentNode || (SUBSTRING(doc, 4,2)::bit(2)::INTEGER + 4)::VARCHAR || CASE SUBSTRING(doc, 6, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 7, 9999)
WHERE doc LIKE '100%';
IF FOUND THEN
got_none := false;
END IF;
-- 101 = 8-15
UPDATE Production.ProductDocument
SET DocumentNode = DocumentNode || (SUBSTRING(doc, 4,3)::bit(3)::INTEGER + 8)::VARCHAR || CASE SUBSTRING(doc, 7, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 8, 9999)
WHERE doc LIKE '101%';
IF FOUND THEN
got_none := false;
END IF;
-- 110 = 16-79
UPDATE Production.ProductDocument
SET DocumentNode = DocumentNode || ((SUBSTRING(doc, 4,2)||SUBSTRING(doc, 7,1)||SUBSTRING(doc, 9,3))::bit(6)::INTEGER + 16)::VARCHAR || CASE SUBSTRING(doc, 12, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 13, 9999)
WHERE doc LIKE '110%';
IF FOUND THEN
got_none := false;
END IF;
-- 1110 = 80-1103
UPDATE Production.ProductDocument
SET DocumentNode = DocumentNode || ((SUBSTRING(doc, 5,3)||SUBSTRING(doc, 9,3)||SUBSTRING(doc, 13,1)||SUBSTRING(doc, 15,3))::bit(10)::INTEGER + 80)::VARCHAR || CASE SUBSTRING(doc, 18, 1) WHEN '0' THEN '.' ELSE '/' END,
doc = SUBSTRING(doc, 19, 9999)
WHERE doc LIKE '1110%';
IF FOUND THEN
got_none := false;
END IF;
EXIT WHEN got_none;
END LOOP;
END
$func$ LANGUAGE plpgsql;
SELECT f_ConvertDocNodes();
-- Drop the original binary hierarchyid column
ALTER TABLE Production.ProductDocument DROP COLUMN Doc;
DROP FUNCTION f_ConvertDocNodes();
ALTER TABLE Production.ProductDocument DROP COLUMN rowguid;
CREATE SCHEMA Purchasing
CREATE TABLE ProductVendor(
ProductID INT NOT NULL,
BusinessEntityID INT NOT NULL,
AverageLeadTime INT NOT NULL,
StandardPrice numeric NOT NULL, -- money
LastReceiptCost numeric NULL, -- money
LastReceiptDate TIMESTAMP NULL,
MinOrderQty INT NOT NULL,
MaxOrderQty INT NOT NULL,
OnOrderQty INT NULL,
UnitMeasureCode char(3) NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ProductVendor_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_ProductVendor_AverageLeadTime" CHECK (AverageLeadTime >= 1),
CONSTRAINT "CK_ProductVendor_StandardPrice" CHECK (StandardPrice > 0.00),
CONSTRAINT "CK_ProductVendor_LastReceiptCost" CHECK (LastReceiptCost > 0.00),
CONSTRAINT "CK_ProductVendor_MinOrderQty" CHECK (MinOrderQty >= 1),
CONSTRAINT "CK_ProductVendor_MaxOrderQty" CHECK (MaxOrderQty >= 1),
CONSTRAINT "CK_ProductVendor_OnOrderQty" CHECK (OnOrderQty >= 0)
)
CREATE TABLE PurchaseOrderDetail(
PurchaseOrderID INT NOT NULL,
PurchaseOrderDetailID SERIAL NOT NULL, -- int
DueDate TIMESTAMP NOT NULL,
OrderQty smallint NOT NULL,
ProductID INT NOT NULL,
UnitPrice numeric NOT NULL, -- money
LineTotal numeric, -- AS ISNULL(OrderQty * UnitPrice, 0.00),
ReceivedQty decimal(8, 2) NOT NULL,
RejectedQty decimal(8, 2) NOT NULL,
StockedQty numeric, -- AS ISNULL(ReceivedQty - RejectedQty, 0.00),
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_PurchaseOrderDetail_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_PurchaseOrderDetail_OrderQty" CHECK (OrderQty > 0),
CONSTRAINT "CK_PurchaseOrderDetail_UnitPrice" CHECK (UnitPrice >= 0.00),
CONSTRAINT "CK_PurchaseOrderDetail_ReceivedQty" CHECK (ReceivedQty >= 0.00),
CONSTRAINT "CK_PurchaseOrderDetail_RejectedQty" CHECK (RejectedQty >= 0.00)
)
CREATE TABLE PurchaseOrderHeader(
PurchaseOrderID SERIAL NOT NULL, -- int
RevisionNumber smallint NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_RevisionNumber" DEFAULT (0), -- tinyint
Status smallint NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_Status" DEFAULT (1), -- tinyint
EmployeeID INT NOT NULL,
VendorID INT NOT NULL,
ShipMethodID INT NOT NULL,
OrderDate TIMESTAMP NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_OrderDate" DEFAULT (NOW()),
ShipDate TIMESTAMP NULL,
SubTotal numeric NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_SubTotal" DEFAULT (0.00), -- money
TaxAmt numeric NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_TaxAmt" DEFAULT (0.00), -- money
Freight numeric NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_Freight" DEFAULT (0.00), -- money
TotalDue numeric, -- AS ISNULL(SubTotal + TaxAmt + Freight, 0) PERSISTED NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_PurchaseOrderHeader_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_PurchaseOrderHeader_Status" CHECK (Status BETWEEN 1 AND 4), -- 1 = Pending; 2 = Approved; 3 = Rejected; 4 = Complete
CONSTRAINT "CK_PurchaseOrderHeader_ShipDate" CHECK ((ShipDate >= OrderDate) OR (ShipDate IS NULL)),
CONSTRAINT "CK_PurchaseOrderHeader_SubTotal" CHECK (SubTotal >= 0.00),
CONSTRAINT "CK_PurchaseOrderHeader_TaxAmt" CHECK (TaxAmt >= 0.00),
CONSTRAINT "CK_PurchaseOrderHeader_Freight" CHECK (Freight >= 0.00)
)
CREATE TABLE ShipMethod(
ShipMethodID SERIAL NOT NULL, -- int
Name "Name" NOT NULL,
ShipBase numeric NOT NULL CONSTRAINT "DF_ShipMethod_ShipBase" DEFAULT (0.00), -- money
ShipRate numeric NOT NULL CONSTRAINT "DF_ShipMethod_ShipRate" DEFAULT (0.00), -- money
rowguid uuid NOT NULL CONSTRAINT "DF_ShipMethod_rowguid" DEFAULT (uuid_generate_v1()), -- ROWGUIDCOL
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_ShipMethod_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_ShipMethod_ShipBase" CHECK (ShipBase > 0.00),
CONSTRAINT "CK_ShipMethod_ShipRate" CHECK (ShipRate > 0.00)
)
CREATE TABLE Vendor(
BusinessEntityID INT NOT NULL,
AccountNumber "AccountNumber" NOT NULL,
Name "Name" NOT NULL,
CreditRating smallint NOT NULL, -- tinyint
PreferredVendorStatus "Flag" NOT NULL CONSTRAINT "DF_Vendor_PreferredVendorStatus" DEFAULT (true),
ActiveFlag "Flag" NOT NULL CONSTRAINT "DF_Vendor_ActiveFlag" DEFAULT (true),
PurchasingWebServiceURL varchar(1024) NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_Vendor_ModifiedDate" DEFAULT (NOW()),
CONSTRAINT "CK_Vendor_CreditRating" CHECK (CreditRating BETWEEN 1 AND 5)
);
COMMENT ON SCHEMA Purchasing IS 'Contains objects related to vendors and purchase orders.';
SELECT 'Copying data into Purchasing.ProductVendor';
\copy Purchasing.ProductVendor FROM 'ProductVendor.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Purchasing.PurchaseOrderDetail';
\copy Purchasing.PurchaseOrderDetail FROM 'PurchaseOrderDetail.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Purchasing.PurchaseOrderHeader';
\copy Purchasing.PurchaseOrderHeader FROM 'PurchaseOrderHeader.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Purchasing.ShipMethod';
\copy Purchasing.ShipMethod FROM 'ShipMethod.csv' DELIMITER E'\t' CSV;
SELECT 'Copying data into Purchasing.Vendor';
\copy Purchasing.Vendor FROM 'Vendor.csv' DELIMITER E'\t' CSV;
-- Calculated columns that needed to be there just for the CSV import
ALTER TABLE Purchasing.PurchaseOrderDetail DROP COLUMN LineTotal;
ALTER TABLE Purchasing.PurchaseOrderDetail DROP COLUMN StockedQty;
ALTER TABLE Purchasing.PurchaseOrderHeader DROP COLUMN TotalDue;
CREATE SCHEMA Sales
CREATE TABLE CountryRegionCurrency(
CountryRegionCode varchar(3) NOT NULL,
CurrencyCode char(3) NOT NULL,
ModifiedDate TIMESTAMP NOT NULL CONSTRAINT "DF_CountryRegionCurrency_ModifiedDate" DEFAULT (NOW())
)
CREATE TABLE CreditCard(
CreditCardID SERIAL NOT NULL, -- int
CardType varchar(50) NOT NULL,