Real-time collaboration for Jupyter Notebooks, Linux Terminals, LaTeX, VS Code, R IDE, and more,
all in one place.
Real-time collaboration for Jupyter Notebooks, Linux Terminals, LaTeX, VS Code, R IDE, and more,
all in one place.
Path: blob/master/src/packages/database/postgres/site-license/usage-log.ts
Views: 687
/*1* This file is part of CoCalc: Copyright © 2020 Sagemath, Inc.2* License: MS-RSL – see LICENSE.md for details3*/45/*6The update_site_license_usage_log function exported from this file should be called7periodically to make the site_license_usage_log table contain useful information8about how site licenses are being used.910This function is not *automatically* called periodically by all possible ways11of running CoCalc! Probably (hopefully?) only cocalc.com actually manages or sells12site license, and in kucalc (the backend used by cocalc.com) this function happens13to get called periodically from one of the manage-* services.1415It's also enabled in dev mode by the hub so that cc-in-cc hub developemnt is easier.16*/17import { PostgreSQL } from "../types";18import { query } from "../query";19import { TIMEOUT_S } from "./const";2021export async function update_site_license_usage_log(22db: PostgreSQL23): Promise<void> {24// don't run this in parallel – timeout_s triggers a transaction and as of now, we have only one client<->db connection25await update_site_license_usage_log_running_projects(db);26await update_site_license_usage_log_not_running_projects(db);27}2829/*30This function ensures that for every running project P using a site license L,31there is exactly one entry (P,L,time,null) in the table site_license_usage_log.32*/33async function update_site_license_usage_log_running_projects(34db: PostgreSQL35): Promise<void> {36const dbg = db._dbg("update_site_license_usage_log_running_projects");37dbg();3839/*40In the comment below I explain how I figured out the two big queries we do below...4142This is a reasonably efficient way to get all pairs (project_id, license_id) where43the license is applied and the project is running (and was actually edited in the last week).44The last_edited is a cheat to make this massively faster by not requiring a scan45through all projects (or an index).4647Set A:4849WITH 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')50SELECT project_id, key AS license_id FROM running_license_info WHERE value != '{}';5152This query gets all pairs (project_id, license_id) that are currently running53with that license according to the the site_license_usage_log:5455Set B:5657SELECT project_id, license_id, start FROM site_license_usage_log WHERE stop IS NULL;5859We want to sync these two sets by:6061- For each element (project_id, license_id) of set A that is not in set B,62add a new entry to the site_license_usage_log table of the63form (project_id, license_id, NOW()).64- For each element (project_id, license_id, start) of set B that is not in set A,65modify that element to be of the form66(project_id, license_id, start, NOW())67thus removing it from set B.6869What can be done with SQL to accomplish this?7071This query computes set A minus set B:7273WITH 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')74SELECT running_license_info.project_id AS project_id, running_license_info.key::UUID AS license_id FROM running_license_info WHERE75running_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);7677So this query adds everything to site_license_usage_log that is missing:787980WITH 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')81SELECT running_license_info.project_id AS project_id, running_license_info.key::UUID AS license_id FROM running_license_info WHERE82running_license_info.value != '{}' AND83NOT 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))84INSERT INTO site_license_usage_log(project_id, license_id, start) SELECT project_id, license_id, NOW() FROM missing;858687In the other direction, we need to fill out everything in set B that is missing from set A:8889This query computes set B minus set A:9091WITH running_license_info92AS (SELECT project_id, (jsonb_each_text(site_license)).*93FROM projects WHERE94last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running'95)96SELECT site_license_usage_log.license_id AS license_id, site_license_usage_log.project_id AS project_id, site_license_usage_log.start AS start97FROM site_license_usage_log WHERE98stop IS NULL AND99NOT EXISTS100(SELECT FROM running_license_info101WHERE running_license_info.value != '{}'102AND running_license_info.project_id=site_license_usage_log.project_id103AND site_license_usage_log.license_id=running_license_info.key::UUID)104105106And now modify the entries of site_license_usage_log using set B minus set A:107108109WITH stopped AS (110WITH running_license_info111AS (SELECT project_id, (jsonb_each_text(site_license)).*112FROM projects WHERE113last_edited >= NOW() - INTERVAL '1 day' AND state#>>'{state}'='running'114)115SELECT site_license_usage_log.license_id AS license_id, site_license_usage_log.project_id AS project_id, site_license_usage_log.start AS start116FROM site_license_usage_log WHERE117stop IS NULL AND118NOT EXISTS119(SELECT FROM running_license_info120WHERE running_license_info.value != '{}'121AND running_license_info.project_id=site_license_usage_log.project_id122AND site_license_usage_log.license_id=running_license_info.key::UUID)123)124UPDATE site_license_usage_log SET stop=NOW()125FROM stopped126WHERE site_license_usage_log.license_id=stopped.license_id AND127site_license_usage_log.project_id=stopped.project_id AND128site_license_usage_log.start = stopped.start;129130*/131132const q = `133WITH missing AS134(135WITH running_license_info AS136(137SELECT138project_id,139(140jsonb_each_text(site_license)141)142.*143FROM144projects145WHERE146state #>> '{state}' = 'running'147)148SELECT149running_license_info.project_id AS project_id,150running_license_info.key::UUID AS license_id151FROM152running_license_info153WHERE154running_license_info.value != '{}'155AND NOT EXISTS156(157SELECT158FROM159site_license_usage_log160WHERE161site_license_usage_log.stop IS NULL162AND site_license_usage_log.project_id = running_license_info.project_id163AND site_license_usage_log.license_id = running_license_info.key::UUID164)165)166INSERT INTO167site_license_usage_log(project_id, license_id, start)168SELECT169project_id,170license_id,171NOW()172FROM173missing;174175`;176await query({ db, query: q, timeout_s: TIMEOUT_S });177}178179/*180This function ensures that there are no entries of the form181(P,L,time,null) in the site_license_usage_log table with182the project P NOT running. It does this by replacing the null183value in all such cases by NOW().184*/185async function update_site_license_usage_log_not_running_projects(186db: PostgreSQL187): Promise<void> {188const dbg = db._dbg("update_site_license_usage_log_not_running_projects");189dbg();190const q = `191WITH stopped AS192(193WITH running_license_info AS194(195SELECT196project_id,197(198jsonb_each_text(site_license)199)200.*201FROM202projects203WHERE204state #>> '{state}' = 'running'205)206SELECT207site_license_usage_log.license_id AS license_id,208site_license_usage_log.project_id AS project_id,209site_license_usage_log.start AS start210FROM211site_license_usage_log212WHERE213stop IS NULL214AND NOT EXISTS215(216SELECT217FROM218running_license_info219WHERE220running_license_info.value != '{}'221AND running_license_info.project_id = site_license_usage_log.project_id222AND site_license_usage_log.license_id = running_license_info.key::UUID223)224)225UPDATE226site_license_usage_log227SET228stop = NOW()229FROM230stopped231WHERE232site_license_usage_log.license_id = stopped.license_id233AND site_license_usage_log.project_id = stopped.project_id234AND site_license_usage_log.start = stopped.start;235`;236await query({ db, query: q, timeout_s: TIMEOUT_S });237}238239/* Answer questions about active usage of a site license by projects */240241// An interval of time.242export interface Interval {243begin: Date;244end: Date;245}246247// Return the number of distinct projects that used the license during the given248// interval of time.249export async function number_of_projects_that_used_license(250db: PostgreSQL,251license_id: string,252interval: Interval253): Promise<number> {254const dbg = db._dbg(255`number_of_projects_that_used_license("${license_id}",${interval.begin},${interval.end})`256);257dbg();258return -1;259}260261// Return the total number of hours of usage of the given license by projects during262// the given interval of time.263export async function number_of_hours_projects_used_license(264db: PostgreSQL,265license_id: string,266interval: Interval267): Promise<number> {268const dbg = db._dbg(269`number_of_hours_projects_used_license("${license_id}",${interval.begin},${interval.end})`270);271dbg();272return -1;273}274275// Given a license_id and an interval of time [begin, end], returns276// all projects that used the license during an interval that overlaps with [begin, end].277// Projects are returned as a list of objects:278// {project_id, [any other fields from the projects table (e.g., title)]}279export async function projects_that_used_license(280db: PostgreSQL,281license_id: string,282interval: Interval,283fields: string[] = ["project_id"],284limit: number = 500 // at most this many results; results are ordered by project_id.285): Promise<object[]> {286const dbg = db._dbg(287`projects_that_used_license("${license_id}",${interval.begin},${interval.end})`288);289dbg([fields, limit]);290return [];291292/*293After restricting to a given license, the site_license_usage_log table gives us a set of triples294(project_id, start, stop)295where stop may be null in case the project is still running.296297298[begin ----------------------- end]299300[start ------------- stop]301[start --------------------------------------------- stop]302[start ----------- stop]303[start ----------------stop]304305One of these triples overlaps with the interval from begin to end if:306307- start <= begin and begin <= stop, i.e. begin is in the interval [start, stop]308- begin = start and start <= end , i.e. starts is in the interval [begin, end]309310*/311}312313314