From 15be636568ebcc8f30f191f03b1790a250e8a33c Mon Sep 17 00:00:00 2001 From: Simon Delamare <simon.delamare@ens-lyon.fr> Date: Mon, 21 Mar 2022 14:05:55 +0100 Subject: [PATCH] db: Add api.available_metrics function --- kwollect/tools/kwollect_setup_db.py | 54 +++++++++++++++++++++++++++++ 1 file changed, 54 insertions(+) diff --git a/kwollect/tools/kwollect_setup_db.py b/kwollect/tools/kwollect_setup_db.py index 4f54969..7411d67 100644 --- a/kwollect/tools/kwollect_setup_db.py +++ b/kwollect/tools/kwollect_setup_db.py @@ -391,6 +391,60 @@ except spiexceptions.QueryCanceled: $$ LANGUAGE 'plpython3u' IMMUTABLE; + +DROP FUNCTION IF EXISTS api.available_metrics; +CREATE OR REPLACE FUNCTION api.available_metrics( + at TIMESTAMPTZ DEFAULT NOW(), + params JSONB DEFAULT '{{}}' +) +RETURNS TABLE (device_id TEXT, metric_id TEXT) AS $$ +DECLARE +from_devices TEXT[] := NULL; +from_job_id INT := NULL; +from_job_id_end TIMESTAMP := NULL; +BEGIN +IF params->>'job_id' IS NOT NULL THEN + SELECT nullif(substring(params->>'job_id' FROM '^\d+$'), '')::int INTO from_job_id; + IF from_job_id IS NOT NULL THEN + SELECT MAX(stop_time) FROM nodetime_by_job WHERE job_id = from_job_id INTO from_job_id_end; + SELECT ARRAY(SELECT DISTINCT node FROM nodetime_by_job WHERE nodetime_by_job.job_id = from_job_id) INTO from_devices; + RETURN QUERY SELECT * FROM api.available_metrics(at => LEAST(from_job_id_end, at), params => jsonb_build_object('devices', array_to_json(from_devices))); + RETURN; + END IF; +END IF; +IF params->'devices' IS NOT NULL THEN + IF jsonb_typeof(params->'devices') = 'array' THEN + SELECT ARRAY(SELECT jsonb_array_elements_text(params->'devices')) INTO STRICT from_devices; + ELSE + RAISE EXCEPTION 'Cannot parse params->devices, should be JSON array'; + END IF; +END IF; +RETURN QUERY +WITH av_metrics AS ( + SELECT metrics.device_id, metrics.metric_id + FROM metrics AS metrics WHERE + timestamp < at AND timestamp > at - INTERVAL '1m' + AND CASE WHEN from_devices IS NOT NULL THEN metrics.device_id = ANY (from_devices) ELSE true END + UNION + SELECT metrics.labels ->> '_device_alias'::text AS device_id, metrics.metric_id + FROM metrics AS metrics + WHERE metrics.labels ? '_device_alias' + AND timestamp < at AND timestamp > at - INTERVAL '1m' + AND CASE WHEN from_devices IS NOT NULL THEN metrics.labels->>'_device_alias' = ANY (from_devices) ELSE true END +), +ordered_metrics AS ( + SELECT DISTINCT ON (idx1, idx2, idx3, metric_id) + metrics.device_id, metrics.metric_id, + CASE WHEN metrics.device_id ~ '^[a-z]+-\d+$' THEN '1' ELSE '2' END AS idx1, + (STRING_TO_ARRAY(metrics.device_id, '-'))[1] AS idx2, + COALESCE(SUBSTRING((STRING_TO_ARRAY(metrics.device_id, '-'))[2] FROM '([0-9]+)')::INTEGER, 0) as idx3 + FROM av_metrics AS metrics +) +SELECT m.device_id, m.metric_id FROM ordered_metrics AS m; +END; +$$ LANGUAGE plpgsql IMMUTABLE; + + CREATE OR REPLACE FUNCTION api.insert_metrics( device_id TEXT, metric_id TEXT, -- GitLab