89 lines
2.7 KiB
MySQL
89 lines
2.7 KiB
MySQL
|
CREATE OR REPLACE FUNCTION public.aggregate_autoselect(
|
||
|
root_table character varying,
|
||
|
data_interval interval,
|
||
|
filter_query character varying,
|
||
|
agg_pairs jsonb,
|
||
|
metric_statement character varying DEFAULT 'tags',
|
||
|
agg_basename character varying DEFAULT NULL,
|
||
|
agg_schema character varying DEFAULT 'public',
|
||
|
time_column character varying DEFAULT 'time')
|
||
|
RETURNS SETOF RECORD
|
||
|
LANGUAGE 'plpgsql'
|
||
|
STABLE
|
||
|
PARALLEL SAFE
|
||
|
AS $BODY$
|
||
|
DECLARE
|
||
|
selected_table record;
|
||
|
|
||
|
selected_column character varying;
|
||
|
selected_aggregator character varying;
|
||
|
BEGIN
|
||
|
agg_basename := coalesce(agg_basename, root_table);
|
||
|
|
||
|
WITH table_selection AS (
|
||
|
SELECT table_name, column_name,
|
||
|
coalesce(substring(table_name, agg_basename || '_\"%\"', '\'), '0')::interval AS table_interval
|
||
|
FROM information_schema.columns
|
||
|
WHERE table_schema=agg_schema
|
||
|
AND ((table_name = root_table) OR (table_name LIKE (agg_basename || '_%')))
|
||
|
AND agg_pairs?column_name
|
||
|
)
|
||
|
SELECT table_name, column_name
|
||
|
INTO selected_table
|
||
|
FROM table_selection
|
||
|
WHERE table_interval <= data_interval
|
||
|
ORDER BY table_interval DESC
|
||
|
LIMIT 1;
|
||
|
|
||
|
IF NOT FOUND THEN
|
||
|
RETURN;
|
||
|
END IF;
|
||
|
|
||
|
selected_aggregator := agg_pairs->>selected_table.column_name;
|
||
|
|
||
|
RAISE NOTICE 'Using table %, column %, aggreagtor %', selected_table.table_name, selected_table.column_name, selected_aggregator;
|
||
|
|
||
|
RETURN QUERY EXECUTE format($qry$
|
||
|
SELECT time_bucket($1, %I::timestamptz) AS time, (%s)::text AS metric, (%s) AS "value"
|
||
|
FROM %I.%I
|
||
|
WHERE %s
|
||
|
GROUP BY 1, (%s)::text
|
||
|
ORDER BY time
|
||
|
$qry$, time_column, metric_statement, selected_aggregator,
|
||
|
agg_schema, selected_table.table_name,
|
||
|
filter_query,
|
||
|
metric_statement)
|
||
|
USING data_interval;
|
||
|
END;
|
||
|
$BODY$;
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION public.percentile_autoselect(
|
||
|
root_table character varying,
|
||
|
data_interval interval,
|
||
|
percentiles double precision[],
|
||
|
filter_query text,
|
||
|
metric_statement character varying DEFAULT 'tags',
|
||
|
agg_basename character varying DEFAULT NULL,
|
||
|
agg_schema character varying DEFAULT 'public',
|
||
|
time_column character varying DEFAULT 'time')
|
||
|
RETURNS TABLE ("time" TIMESTAMPTZ, "metric" TEXT, "percentile" DOUBLE PRECISION, "value" DOUBLE PRECISION)
|
||
|
LANGUAGE 'plpgsql'
|
||
|
STABLE
|
||
|
PARALLEL SAFE
|
||
|
AS $body$
|
||
|
DECLARE
|
||
|
BEGIN
|
||
|
|
||
|
RETURN QUERY
|
||
|
WITH ts_data AS (
|
||
|
SELECT * FROM aggregate_autoselect(root_table, data_interval, filter_query,
|
||
|
$${"value": "tdigest(10, value)", "tdigest": "rollup(tdigest)"}$$::jsonb,
|
||
|
metric_statement, agg_basename, agg_schema, time_column)
|
||
|
r("time" TIMESTAMPTZ, metric TEXT, value tdigest)
|
||
|
)
|
||
|
SELECT ts_data."time", ts_data.metric, up.percentile, approx_percentile(up.percentile, ts_data.value) AS "value"
|
||
|
FROM ts_data
|
||
|
CROSS JOIN unnest(percentiles) AS up(percentile)
|
||
|
ORDER BY ts_data."time";
|
||
|
END;
|
||
|
$body$;
|