CoCalc Logo Icon
StoreFeaturesDocsShareSupportNewsAboutSign UpSign In
sagemathinc

Real-time collaboration for Jupyter Notebooks, Linux Terminals, LaTeX, VS Code, R IDE, and more,
all in one place.

GitHub Repository: sagemathinc/cocalc
Path: blob/master/src/packages/database/postgres/site-license/usage-log.ts
Views: 687
1
/*
2
* This file is part of CoCalc: Copyright © 2020 Sagemath, Inc.
3
* License: MS-RSL – see LICENSE.md for details
4
*/
5
6
/*
7
The update_site_license_usage_log function exported from this file should be called
8
periodically to make the site_license_usage_log table contain useful information
9
about how site licenses are being used.
10
11
This function is not *automatically* called periodically by all possible ways
12
of running CoCalc! Probably (hopefully?) only cocalc.com actually manages or sells
13
site license, and in kucalc (the backend used by cocalc.com) this function happens
14
to get called periodically from one of the manage-* services.
15
16
It's also enabled in dev mode by the hub so that cc-in-cc hub developemnt is easier.
17
*/
18
import { PostgreSQL } from "../types";
19
import { query } from "../query";
20
import { TIMEOUT_S } from "./const";
21
22
export async function update_site_license_usage_log(
23
db: PostgreSQL
24
): Promise<void> {
25
// don't run this in parallel – timeout_s triggers a transaction and as of now, we have only one client<->db connection
26
await update_site_license_usage_log_running_projects(db);
27
await update_site_license_usage_log_not_running_projects(db);
28
}
29
30
/*
31
This function ensures that for every running project P using a site license L,
32
there is exactly one entry (P,L,time,null) in the table site_license_usage_log.
33
*/
34
async function update_site_license_usage_log_running_projects(
35
db: PostgreSQL
36
): Promise<void> {
37
const dbg = db._dbg("update_site_license_usage_log_running_projects");
38
dbg();
39
40
/*
41
In the comment below I explain how I figured out the two big queries we do below...
42
43
This is a reasonably efficient way to get all pairs (project_id, license_id) where
44
the license is applied and the project is running (and was actually edited in the last week).
45
The last_edited is a cheat to make this massively faster by not requiring a scan
46
through all projects (or an index).
47
48
Set A:
49
50
WITH running_license_info AS (SELECT project_id, (jsonb_each_text(site_license)).* FROM projects WHERE last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running')
51
SELECT project_id, key AS license_id FROM running_license_info WHERE value != '{}';
52
53
This query gets all pairs (project_id, license_id) that are currently running
54
with that license according to the the site_license_usage_log:
55
56
Set B:
57
58
SELECT project_id, license_id, start FROM site_license_usage_log WHERE stop IS NULL;
59
60
We want to sync these two sets by:
61
62
- For each element (project_id, license_id) of set A that is not in set B,
63
add a new entry to the site_license_usage_log table of the
64
form (project_id, license_id, NOW()).
65
- For each element (project_id, license_id, start) of set B that is not in set A,
66
modify that element to be of the form
67
(project_id, license_id, start, NOW())
68
thus removing it from set B.
69
70
What can be done with SQL to accomplish this?
71
72
This query computes set A minus set B:
73
74
WITH running_license_info AS (SELECT project_id, (jsonb_each_text(site_license)).* FROM projects WHERE last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running')
75
SELECT running_license_info.project_id AS project_id, running_license_info.key::UUID AS license_id FROM running_license_info WHERE
76
running_license_info.value != '{}' AND NOT EXISTS (SELECT FROM site_license_usage_log WHERE site_license_usage_log.stop IS NULL AND site_license_usage_log.project_id=running_license_info.project_id AND site_license_usage_log.license_id=running_license_info.key::UUID);
77
78
So this query adds everything to site_license_usage_log that is missing:
79
80
81
WITH missing AS (WITH running_license_info AS (SELECT project_id, (jsonb_each_text(site_license)).* FROM projects WHERE last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running')
82
SELECT running_license_info.project_id AS project_id, running_license_info.key::UUID AS license_id FROM running_license_info WHERE
83
running_license_info.value != '{}' AND
84
NOT EXISTS (SELECT FROM site_license_usage_log WHERE site_license_usage_log.stop IS NULL AND site_license_usage_log.project_id=running_license_info.project_id AND site_license_usage_log.license_id=running_license_info.key::UUID))
85
INSERT INTO site_license_usage_log(project_id, license_id, start) SELECT project_id, license_id, NOW() FROM missing;
86
87
88
In the other direction, we need to fill out everything in set B that is missing from set A:
89
90
This query computes set B minus set A:
91
92
WITH running_license_info
93
AS (SELECT project_id, (jsonb_each_text(site_license)).*
94
FROM projects WHERE
95
last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running'
96
)
97
SELECT site_license_usage_log.license_id AS license_id, site_license_usage_log.project_id AS project_id, site_license_usage_log.start AS start
98
FROM site_license_usage_log WHERE
99
stop IS NULL AND
100
NOT EXISTS
101
(SELECT FROM running_license_info
102
WHERE running_license_info.value != '{}'
103
AND running_license_info.project_id=site_license_usage_log.project_id
104
AND site_license_usage_log.license_id=running_license_info.key::UUID)
105
106
107
And now modify the entries of site_license_usage_log using set B minus set A:
108
109
110
WITH stopped AS (
111
WITH running_license_info
112
AS (SELECT project_id, (jsonb_each_text(site_license)).*
113
FROM projects WHERE
114
last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running'
115
)
116
SELECT site_license_usage_log.license_id AS license_id, site_license_usage_log.project_id AS project_id, site_license_usage_log.start AS start
117
FROM site_license_usage_log WHERE
118
stop IS NULL AND
119
NOT EXISTS
120
(SELECT FROM running_license_info
121
WHERE running_license_info.value != '{}'
122
AND running_license_info.project_id=site_license_usage_log.project_id
123
AND site_license_usage_log.license_id=running_license_info.key::UUID)
124
)
125
UPDATE site_license_usage_log SET stop=NOW()
126
FROM stopped
127
WHERE site_license_usage_log.license_id=stopped.license_id AND
128
site_license_usage_log.project_id=stopped.project_id AND
129
site_license_usage_log.start = stopped.start;
130
131
*/
132
133
const q = `
134
WITH missing AS
135
(
136
WITH running_license_info AS
137
(
138
SELECT
139
project_id,
140
(
141
jsonb_each_text(site_license)
142
)
143
.*
144
FROM
145
projects
146
WHERE
147
state #>> '{state}' = 'running'
148
)
149
SELECT
150
running_license_info.project_id AS project_id,
151
running_license_info.key::UUID AS license_id
152
FROM
153
running_license_info
154
WHERE
155
running_license_info.value != '{}'
156
AND NOT EXISTS
157
(
158
SELECT
159
FROM
160
site_license_usage_log
161
WHERE
162
site_license_usage_log.stop IS NULL
163
AND site_license_usage_log.project_id = running_license_info.project_id
164
AND site_license_usage_log.license_id = running_license_info.key::UUID
165
)
166
)
167
INSERT INTO
168
site_license_usage_log(project_id, license_id, start)
169
SELECT
170
project_id,
171
license_id,
172
NOW()
173
FROM
174
missing;
175
176
`;
177
await query({ db, query: q, timeout_s: TIMEOUT_S });
178
}
179
180
/*
181
This function ensures that there are no entries of the form
182
(P,L,time,null) in the site_license_usage_log table with
183
the project P NOT running. It does this by replacing the null
184
value in all such cases by NOW().
185
*/
186
async function update_site_license_usage_log_not_running_projects(
187
db: PostgreSQL
188
): Promise<void> {
189
const dbg = db._dbg("update_site_license_usage_log_not_running_projects");
190
dbg();
191
const q = `
192
WITH stopped AS
193
(
194
WITH running_license_info AS
195
(
196
SELECT
197
project_id,
198
(
199
jsonb_each_text(site_license)
200
)
201
.*
202
FROM
203
projects
204
WHERE
205
state #>> '{state}' = 'running'
206
)
207
SELECT
208
site_license_usage_log.license_id AS license_id,
209
site_license_usage_log.project_id AS project_id,
210
site_license_usage_log.start AS start
211
FROM
212
site_license_usage_log
213
WHERE
214
stop IS NULL
215
AND NOT EXISTS
216
(
217
SELECT
218
FROM
219
running_license_info
220
WHERE
221
running_license_info.value != '{}'
222
AND running_license_info.project_id = site_license_usage_log.project_id
223
AND site_license_usage_log.license_id = running_license_info.key::UUID
224
)
225
)
226
UPDATE
227
site_license_usage_log
228
SET
229
stop = NOW()
230
FROM
231
stopped
232
WHERE
233
site_license_usage_log.license_id = stopped.license_id
234
AND site_license_usage_log.project_id = stopped.project_id
235
AND site_license_usage_log.start = stopped.start;
236
`;
237
await query({ db, query: q, timeout_s: TIMEOUT_S });
238
}
239
240
/* Answer questions about active usage of a site license by projects */
241
242
// An interval of time.
243
export interface Interval {
244
begin: Date;
245
end: Date;
246
}
247
248
// Return the number of distinct projects that used the license during the given
249
// interval of time.
250
export async function number_of_projects_that_used_license(
251
db: PostgreSQL,
252
license_id: string,
253
interval: Interval
254
): Promise<number> {
255
const dbg = db._dbg(
256
`number_of_projects_that_used_license("${license_id}",${interval.begin},${interval.end})`
257
);
258
dbg();
259
return -1;
260
}
261
262
// Return the total number of hours of usage of the given license by projects during
263
// the given interval of time.
264
export async function number_of_hours_projects_used_license(
265
db: PostgreSQL,
266
license_id: string,
267
interval: Interval
268
): Promise<number> {
269
const dbg = db._dbg(
270
`number_of_hours_projects_used_license("${license_id}",${interval.begin},${interval.end})`
271
);
272
dbg();
273
return -1;
274
}
275
276
// Given a license_id and an interval of time [begin, end], returns
277
// all projects that used the license during an interval that overlaps with [begin, end].
278
// Projects are returned as a list of objects:
279
// {project_id, [any other fields from the projects table (e.g., title)]}
280
export async function projects_that_used_license(
281
db: PostgreSQL,
282
license_id: string,
283
interval: Interval,
284
fields: string[] = ["project_id"],
285
limit: number = 500 // at most this many results; results are ordered by project_id.
286
): Promise<object[]> {
287
const dbg = db._dbg(
288
`projects_that_used_license("${license_id}",${interval.begin},${interval.end})`
289
);
290
dbg([fields, limit]);
291
return [];
292
293
/*
294
After restricting to a given license, the site_license_usage_log table gives us a set of triples
295
(project_id, start, stop)
296
where stop may be null in case the project is still running.
297
298
299
[begin ----------------------- end]
300
301
[start ------------- stop]
302
[start --------------------------------------------- stop]
303
[start ----------- stop]
304
[start ----------------stop]
305
306
One of these triples overlaps with the interval from begin to end if:
307
308
- start <= begin and begin <= stop, i.e. begin is in the interval [start, stop]
309
- begin = start and start <= end , i.e. starts is in the interval [begin, end]
310
311
*/
312
}
313
314