-
Notifications
You must be signed in to change notification settings - Fork 1
/
Copy pathapi.sql
211 lines (194 loc) · 7.43 KB
/
api.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
-- noinspection SqlResolveForFile
--
-- All active bikes
--
CREATE OR REPLACE VIEW v_active_bikes AS (
SELECT * FROM bikes
WHERE NOT miscellaneous
AND decommissioned_on IS NULL
ORDER BY name
);
--
-- All bikes, their last mileage and the years (as a list) in which they have been favoured over others.
--
CREATE OR REPLACE VIEW v_bikes AS (
WITH mileage_by_bike_and_year AS (
SELECT bike, year(month) AS year, sum(value) AS value
FROM v$_mileage_by_bike_and_month
GROUP BY all
), ranked_bikes AS (
SELECT bike, year, dense_rank() OVER (PARTITION BY year ORDER BY value DESC) AS rnk
FROM mileage_by_bike_and_year
QUALIFY rnk = 1
ORDER BY year
), years AS (
SELECT bike, list(year) AS value
FROM ranked_bikes
GROUP BY all
), lent AS (
SELECT bike_id, sum(amount) AS value FROM lent_milages GROUP BY ALL
), last_milage AS (
SELECT bike_id, last(amount) AS value
FROM milages GROUP BY bike_id ORDER BY last(recorded_on) ASC
)
SELECT bikes.*,
coalesce(last_milage.value, 0) + coalesce(lent.value, 0) AS last_milage,
coalesce(years.value, []) as favoured_in
FROM bikes
LEFT OUTER JOIN years ON years.bike = bikes.name
LEFT OUTER JOIN lent ON lent.bike_id = bikes.id
LEFT OUTER JOIN last_milage ON last_milage.bike_id = bikes.id
ORDER BY last_milage desc, bought_on, decommissioned_on, name
);
--
-- Summary over all bikes
--
CREATE OR REPLACE VIEW v_summary AS (
WITH sum_of_milages AS (
SELECT month,
sum(value) AS value
FROM v$_mileage_by_bike_and_month
GROUP BY ROLLUP (month)
), sum_of_assorted_trips AS (
SELECT date_trunc('month', covered_on) AS month,
sum(distance) AS value
FROM assorted_trips
GROUP BY ROLLUP (month)
),
summary AS (
SELECT min(m.month) AS since,
max(m.month) AS last_recording,
arg_min(m.month, m.value + coalesce(t.value, 0)) FILTER (WHERE m.value <> 0) AS worst_month,
min(m.value + coalesce(t.value, 0)) FILTER (WHERE m.value <> 0) AS worst_month_value,
arg_max(m.month, m.value + coalesce(t.value, 0)) AS best_month,
max(m.value + coalesce(t.value, 0)) AS best_month_value
FROM sum_of_milages m LEFT OUTER JOIN sum_of_assorted_trips t USING (month)
WHERE m.month IS NOT NULL
)
SELECT s.*,
m.value + t.value AS total,
total / date_diff('month', s.since, s.last_recording) AS avg_per_month
FROM sum_of_milages m,
sum_of_assorted_trips t,
summary s
WHERE m.month IS NULL
AND t.month IS NULL
AND s.last_recording IS NOT NULL
);
--
-- Mileages over all bikes and assorted trips in the current year (year-today)
--
CREATE OR REPLACE VIEW v_ytd_summary AS (
WITH sum_of_milages AS (
SELECT month,
sum(value) AS value
FROM v$_mileage_by_bike_and_month
WHERE month BETWEEN date_trunc('year', current_date()) AND date_trunc('month', current_date())
GROUP BY ROLLUP (month)
),
sum_of_assorted_trips AS (
SELECT date_trunc('month', covered_on) AS month,
sum(distance) AS value
FROM assorted_trips
WHERE month BETWEEN date_trunc('year', current_date()) AND date_trunc('month', current_date())
GROUP BY ROLLUP (month)
),
summary AS (
SELECT max(m.month) AS last_recording,
arg_min(m.month, m.value + coalesce(t.value, 0)) FILTER (WHERE m.value <> 0) AS worst_month,
min(m.value + coalesce(t.value, 0)) FILTER (WHERE m.value <> 0) AS worst_month_value,
arg_max(m.month, m.value + coalesce(t.value, 0)) AS best_month,
max(m.value + coalesce(t.value, 0)) AS best_month_value
FROM sum_of_milages m LEFT OUTER JOIN sum_of_assorted_trips t USING (month)
WHERE m.month IS NOT NULL
),
sum_of_milages_by_bike AS (
SELECT bike,
sum(value) AS value
FROM v$_mileage_by_bike_and_month
WHERE month BETWEEN date_trunc('year', current_date()) AND date_trunc('month', current_date())
GROUP BY bike
)
SELECT s.*,
(SELECT arg_max(bike, value) FROM sum_of_milages_by_bike) AS preferred_bike,
m.value + t.value AS total,
total / date_diff('month', date_trunc('year', current_date()), s.last_recording + interval 1 month) AS avg_per_month
FROM sum_of_milages m,
sum_of_assorted_trips t,
summary s
WHERE m.month IS NULL
AND t.month IS NULL
AND s.last_recording IS NOT NULL
);
--
-- Monthly totals in the current year.
--
CREATE OR REPLACE VIEW v_ytd_totals AS (
SELECT * replace(strftime(month, '%B') AS month)
FROM v$_total_mileage_by_month
WHERE month >= date_trunc('year', current_date())
AND month < date_trunc('month', current_date())
);
--
-- Monthly totals by bike in the current, can be safely pivoted on the bike.
--
CREATE OR REPLACE VIEW v_ytd_bikes AS (
SELECT mbbm.* replace(strftime(month, '%B') AS month)
FROM v$_mileage_by_bike_and_month mbbm
JOIN bikes b ON (b.name = mbbm.bike)
WHERE month >= date_trunc('year', current_date())
AND month < date_trunc('month', current_date())
AND NOT b.miscellaneous
);
--
-- Monthly average over all, including 0 values for months in which no ride was done.
--
CREATE OR REPLACE VIEW v_monthly_average AS (
WITH
months AS (SELECT range AS value FROM range('2023-01-01'::date, '2024-01-01'::date, INTERVAL 1 month)),
data AS (
SELECT monthname(month) AS month,
min(value) AS minimum,
max(value) AS maximum,
round(avg(value), 2) AS average
FROM v$_total_mileage_by_month x
GROUP BY ROLLUP(monthname(month))
)
SELECT monthname(months.value) AS month,
coalesce(data.minimum, 0) AS minimum,
coalesce(data.maximum, 0) AS maximum,
coalesce(data.average, 0) AS average
FROM months
FULL OUTER JOIN data
ON data.month = monthname(months.value)
ORDER BY month(months.value)
);
--
-- Reoccurring events and their results. Results will be a structured list object per row.
--
CREATE OR REPLACE VIEW v_reoccurring_events AS (
SELECT name, list({
achieved_at: achieved_at,
distance: distance,
time: lpad(duration//3600, 2, '0') || ':' || lpad((duration%3600)//60, 2, '0') || ':' || lpad(duration%3600%60, 2, '0'),
pace: cast(floor(duration/distance/60) AS int) || ':' || lpad(floor(duration/distance%60)::int, 2, '0')
})
FROM events e JOIN results r ON r.event_id = e.id
WHERE NOT one_time_only
GROUP BY ALL
ORDER BY name
);
--
-- One time only events and the explicit result therein.
--
CREATE OR REPLACE VIEW v_one_time_only_events AS (
SELECT name,
achieved_at,
distance,
lpad(duration//3600, 2, '0') || ':' || lpad((duration%3600)//60, 2, '0') || ':' || lpad(duration%3600%60, 2, '0') AS time,
cast(floor(duration/distance/60) AS int) || ':' || lpad(floor(duration/distance%60)::int, 2, '0') AS pace
FROM events e JOIN results r ON r.event_id = e.id
WHERE one_time_only
GROUP BY ALL
ORDER BY achieved_at, name
);