-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy path02-create-views.sh
executable file
·168 lines (158 loc) · 5.53 KB
/
02-create-views.sh
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
#!/bin/bash
source variables.inc
gcloud config set project $PROJECT
PROJECT_ID=`gcloud config get-value project`
# Create Bigquery Views
# https://cloud.google.com/retail/docs/movie-rec-tutorial#create_views
# product catalog
bq mk --project_id=${PROJECT} \
--use_legacy_sql=false \
--view '
SELECT
CAST(movies.movieId AS string) AS id,
SUBSTR(title, 0, 128) AS title,
SPLIT(genres, "|") AS categories,
CONCAT("https://www.imdb.com/title/tt",links.imdbId) AS uri
FROM `'${PROJECT}'.movielens.movies` movies
LEFT JOIN `'${PROJECT}'.movielens.links` links
ON movies.movieID = links.movieid' \
movielens.products
# user_events - home-page-view - >=0
bq mk --project_id=${PROJECT} \
--use_legacy_sql=false \
--view '
WITH t AS (
SELECT
MIN(UNIX_SECONDS(time)) AS old_start,
MAX(UNIX_SECONDS(time)) AS old_end,
UNIX_SECONDS(TIMESTAMP_SUB(
CURRENT_TIMESTAMP(), INTERVAL 90 DAY)) AS new_start,
UNIX_SECONDS(CURRENT_TIMESTAMP()) AS new_end
FROM `'${PROJECT}'.movielens.ratings`)
SELECT
CAST(userId AS STRING) AS visitorId,
"home-page-view" AS eventType,
FORMAT_TIMESTAMP(
"%Y-%m-%dT%X%Ez",
TIMESTAMP_SECONDS(CAST(
(t.new_start + (UNIX_SECONDS(time) - t.old_start) *
(t.new_end - t.new_start) / (t.old_end - t.old_start))
AS int64))) AS eventTime,
[STRUCT(STRUCT(movieId AS id) AS product)] AS productDetails,
FROM `'${PROJECT}'.movielens.ratings`, t
WHERE rating >= 0' \
movielens.user_events_homepageview
# user_events - search - >=3.0
bq mk --project_id=${PROJECT} \
--use_legacy_sql=false \
--view '-- Search Event
WITH t AS (
SELECT
MIN(UNIX_SECONDS(time)) AS old_start,
MAX(UNIX_SECONDS(time)) AS old_end,
UNIX_SECONDS(TIMESTAMP_SUB(
CURRENT_TIMESTAMP(), INTERVAL 90 DAY)) AS new_start,
UNIX_SECONDS(CURRENT_TIMESTAMP()) AS new_end
FROM `temp-medium-recai052023.movielens.ratings`)
SELECT
CAST(userId AS STRING) AS visitorId,
"search" AS eventType,
FORMAT_TIMESTAMP(
"%Y-%m-%dT%X%Ez",
TIMESTAMP_SECONDS(CAST(
(t.new_start + (UNIX_SECONDS(time) - t.old_start) *
(t.new_end - t.new_start) / (t.old_end - t.old_start))
AS int64))) AS eventTime,
regexp_extract(title, r'^[^()]*') as searchQuery,
[STRUCT(STRUCT(r.movieId AS id) AS product)] AS productDetails,
STRUCT( GENERATE_UUID() AS completionAttributionToken,
CONCAT("https://www.imdb.com/title/tt",links.imdbId) AS selectedSuggestion,
0 as selectedPosition) AS completionDetail
FROM `temp-medium-recai052023.movielens.ratings` r, t
LEFT JOIN `temp-medium-recai052023.movielens.links` links
ON links.movieId = r.movieId
LEFT JOIN `temp-medium-recai052023.movielens.movies` movies
ON movies.movieId = r.movieId
WHERE rating >= 2' \
movielens.user_events_search
# user_events - detail-page-view - >=4.0
bq mk --project_id=${PROJECT} \
--use_legacy_sql=false \
--view '
WITH t AS (
SELECT
MIN(UNIX_SECONDS(time)) AS old_start,
MAX(UNIX_SECONDS(time)) AS old_end,
UNIX_SECONDS(TIMESTAMP_SUB(
CURRENT_TIMESTAMP(), INTERVAL 90 DAY)) AS new_start,
UNIX_SECONDS(CURRENT_TIMESTAMP()) AS new_end
FROM `'${PROJECT}'.movielens.ratings`)
SELECT
CAST(userId AS STRING) AS visitorId,
"detail-page-view" AS eventType,
FORMAT_TIMESTAMP(
"%Y-%m-%dT%X%Ez",
TIMESTAMP_SECONDS(CAST(
(t.new_start + (UNIX_SECONDS(time) - t.old_start) *
(t.new_end - t.new_start) / (t.old_end - t.old_start))
AS int64))) AS eventTime,
[STRUCT(STRUCT(movieId AS id) AS product)] AS productDetails,
FROM `'${PROJECT}'.movielens.ratings`, t
WHERE rating >= 4' \
movielens.user_events_detailpageview
# create add-to-cart for >= 4.5
bq mk --project_id=${PROJECT} \
--use_legacy_sql=false \
--view '
WITH t AS (
SELECT
MIN(UNIX_SECONDS(time)) AS old_start,
MAX(UNIX_SECONDS(time)) AS old_end,
UNIX_SECONDS(TIMESTAMP_SUB(
CURRENT_TIMESTAMP(), INTERVAL 90 DAY)) AS new_start,
UNIX_SECONDS(CURRENT_TIMESTAMP()) AS new_end
FROM `'${PROJECT}'.movielens.ratings`)
SELECT
CAST(userId AS STRING) AS visitorId,
"add-to-cart" AS eventType,
FORMAT_TIMESTAMP(
"%Y-%m-%dT%X%Ez",
TIMESTAMP_SECONDS(CAST(
(t.new_start + (UNIX_SECONDS(time) - t.old_start) *
(t.new_end - t.new_start) / (t.old_end - t.old_start))
AS int64))) AS eventTime,
[STRUCT(STRUCT(movieId AS id) AS product,1 as quantity)] AS productDetails,
FROM `'${PROJECT}'.movielens.ratings`, t
WHERE rating >= 4.5' \
movielens.user_events_addtocart
# purchase-complete >=5
bq mk --project_id=${PROJECT} \
--use_legacy_sql=false \
--view '
WITH t AS (
SELECT
MIN(UNIX_SECONDS(time)) AS old_start,
MAX(UNIX_SECONDS(time)) AS old_end,
UNIX_SECONDS(TIMESTAMP_SUB(
CURRENT_TIMESTAMP(), INTERVAL 90 DAY)) AS new_start,
UNIX_SECONDS(CURRENT_TIMESTAMP()) AS new_end
FROM `'${PROJECT}'.movielens.ratings`)
SELECT
CAST(userId AS STRING) AS visitorId,
"purchase-complete" AS eventType,
FORMAT_TIMESTAMP(
"%Y-%m-%dT%X%Ez",
TIMESTAMP_SECONDS(CAST(
(t.new_start + (UNIX_SECONDS(time) - t.old_start) *
(t.new_end - t.new_start) / (t.old_end - t.old_start))
AS int64))) AS eventTime,
[STRUCT(STRUCT(movieId AS id,STRUCT(1 as price,"USD" as currencyCode) AS priceInfo) AS product,1 as quantity)] AS productDetails,
STRUCT(
movieId as id,
1 as revenue,
null as tax,
null as cost,
"USD" as currencyCode ) AS purchaseTransaction
FROM `'${PROJECT}'.movielens.ratings`, t
WHERE rating >= 5' \
movielens.user_events_purchasecomplete