1+
2+ drop schema if exists dwh cascade;
3+ create schema dwh ;
4+
5+ -- ==================
6+ -- Product Dimension
7+ -- ==================
8+ create table dwh .dim_product as
9+ select
10+ p .product_id
11+ ,p .product_name
12+ ,p .list_price
13+ ,p .model_year
14+ ,b .brand_name
15+ ,c .category_name
16+ from bike_stores .products p
17+ join bike_stores .brands b
18+ on p .brand_id = b .brand_id
19+ join bike_stores .categories c
20+ on p .category_id = c .category_id
21+ ;
22+
23+ alter table dwh .dim_product
24+ add constraint dim_product_pk primary key (product_id)
25+ ;
26+
27+ -- ===================
28+ -- Customer Dimension
29+ -- ===================
30+ create table dwh .dim_customer as
31+ select
32+ c .customer_id
33+ ,c .first_name
34+ ,c .last_name
35+ ,coalesce (c .phone , ' Unknown' ) as phone
36+ ,coalesce (c .email , ' Unknown' ) as email
37+ ,coalesce (c .street , ' Unknown' ) as street
38+ ,coalesce (c .zip_code , ' Unknown' ) as zip_code
39+ ,coalesce (c .state , ' Unknown' ) as state
40+ from bike_stores .customers c
41+ ;
42+
43+ alter table dwh .dim_customer
44+ add constraint dim_customer_pk primary key (customer_id)
45+ ;
46+
47+ -- ================
48+ -- Store Dimension
49+ -- ================
50+ create table dwh .dim_store as
51+ select
52+ s .store_id
53+ ,s .store_name
54+ ,coalesce (s .phone , ' Unknown' ) as phone
55+ ,coalesce (s .email , ' Unknown' ) as email
56+ ,s .street
57+ ,s .zip_code
58+ ,s .city
59+ from bike_stores .stores s
60+ ;
61+
62+ alter table dwh .dim_store
63+ add constraint dim_store_pk primary key (store_id)
64+ ;
65+
66+ -- ================
67+ -- Staff Dimension
68+ -- ================
69+ create table dwh .dim_staff as
70+ select
71+ s .staff_id
72+ ,s .first_name
73+ ,s .last_name
74+ ,coalesce (s .phone , ' Unknown' ) as phone
75+ ,coalesce (s .email , ' Unknown' ) as email
76+ ,s .active
77+ ,s .manager_id
78+ ,s2 .first_name as manager_first_name
79+ ,s2 .last_name as manager_last_name
80+ from bike_stores .staffs s
81+ left join bike_stores .staffs s2
82+ on s .manager_id = s2 .staff_id
83+ ;
84+
85+ alter table dwh .dim_staff
86+ add constraint dim_staff_pk primary key (staff_id)
87+ ;
88+
89+ -- ==========================
90+ -- Staff Hierarchy Bridge
91+ -- ==========================
92+ create table dwh .staff_hierarchy as
93+ with recursive sh(staff_id, subordinate_id, hierarchy_depth) as
94+ (
95+ select
96+ staff_id
97+ ,staff_id as subordinate_id
98+ ,0 as hierarchy_depth
99+ from bike_stores .staffs
100+ union all
101+ select
102+ sh .staff_id as staff_id
103+ ,s .staff_id as subordinate_id
104+ ,sh .hierarchy_depth + 1 as hierarchy_depth
105+ from sh
106+ join bike_stores .staffs s
107+ on sh .subordinate_id = s .manager_id
108+ )
109+ select
110+ staff_id
111+ ,subordinate_id
112+ ,hierarchy_depth
113+ from sh
114+ ;
115+
116+ alter table dwh .staff_hierarchy
117+ add constraint statt_hierarchy_d_staff_fk
118+ foreign key (staff_id) references dwh .dim_staff (staff_id)
119+ ;
120+ alter table dwh .staff_hierarchy
121+ add constraint statt_hierarchy_d_subordinate_fk
122+ foreign key (subordinate_id) references dwh .dim_staff (staff_id)
123+ ;
124+
125+ -- ===============
126+ -- Date Dimension
127+ -- ===============
128+ create table dwh .dim_date (
129+ date_id int not null
130+ ,date date not null
131+ ,day_name text not null
132+ ,day_of_month int not null
133+ ,week_of_month int not null
134+ ,week_of_year int not null
135+ ,month int not null
136+ ,month_name text not null
137+ ,quarter int not null
138+ ,year int not null
139+ ,is_weekend boolean not null
140+ );
141+
142+ insert into dwh .dim_date
143+ select
144+ to_char(d, ' yyyymmdd' )::int as date_id
145+ ,d as date
146+ ,to_char(d, ' FMDay' ) as day_name
147+ ,extract(day from d) as day_of_month
148+ ,to_char(d, ' W' )::int as week_of_month
149+ ,extract(week from d) as week_of_year
150+ ,extract(month from d) as month
151+ ,to_char(d, ' FMMonth' ) as month_name
152+ ,extract(quarter from d) as quarter
153+ ,extract(year from d) as year
154+ ,case
155+ when extract(isodow from d) in (6 , 7 ) then true
156+ else false
157+ end as is_weekend
158+ from (select ' 2016-01-01' ::date + sequence .day as d
159+ from generate_series(0 , 2000 ) as sequence(day)
160+ ) date_seq
161+ order by 1 ;
162+
163+ alter table dwh .dim_date
164+ add constraint dim_date_pk primary key (date_id)
165+ ;
166+ alter table dwh .dim_date
167+ add constraint dim_date_date_u unique(date )
168+ ;
0 commit comments