Skip to content
This repository was archived by the owner on Apr 2, 2024. It is now read-only.

Commit a6394e0

Browse files
committed
Add SQL views
Add SQL views for the prom_series.* and prom_metric.* views. They are described in detail in sql_schema.md. The point of these views is to make working with prom data in SQL easier. This PR also moves all SQL code to 1_base_schema.up.sql since we aren't supporting upgrades yet.
1 parent 29c84d6 commit a6394e0

File tree

8 files changed

+426
-44
lines changed

8 files changed

+426
-44
lines changed

pkg/docs/sql_schema.md

Lines changed: 98 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,98 @@
1+
# Data Model Schema
2+
3+
## Views
4+
5+
We define several views to make working with prometheus data easier.
6+
7+
### Metric Views
8+
9+
Metric views allows access to the full time-series prometheus data for a
10+
given metric. By default, these views are found in the `prom_metric` schema.
11+
Each metric has a view named after the metric name (.e.g. the `cpu_usage`
12+
metric would have a `prom_metric.cpu_usage` view). The view contains a the
13+
following column:
14+
15+
- time - The timestamp of the measurement
16+
- value - The value of the measurement
17+
- series_id - The ID of the series
18+
- labels - The array of label ids
19+
- plus a column for each label name's id in the metric's label set
20+
21+
For example:
22+
```
23+
# \d+ prom_metric.cpu_usage
24+
View "prom_metric.cpu_usage"
25+
Column | Type | Collation | Nullable | Default | Storage | Description
26+
--------------+--------------------------+-----------+----------+---------+----------+-------------
27+
time | timestamp with time zone | | | | plain |
28+
value | double precision | | | | plain |
29+
series_id | integer | | | | plain |
30+
labels | integer[] | | | | extended |
31+
namespace_id | integer | | | | plain |
32+
node_id | integer | | | | plain |
33+
```
34+
35+
Example query for single point with their labels:
36+
SELECT
37+
label_array_to_jsonb(labels) as labels,
38+
value
39+
FROM prom_metric.cpu_usage
40+
WHERE time < now();
41+
42+
```
43+
labels | value
44+
----------------------------------------------+-------
45+
{"node": "brain", "namespace": "production"} | 0.5
46+
{"node": "brain", "namespace": "production"} | 0.6
47+
{"node": "pinky", "namespace": "dev"} | 0.1
48+
{"node": "pinky", "namespace": "dev"} | 0.2
49+
```
50+
51+
Example query for a rollup:
52+
53+
SELECT
54+
get_label_value(node_id) as node,
55+
avg(value)
56+
FROM prom_metric.cpu_usage
57+
WHERE time < now()
58+
GROUP BY node_id
59+
60+
```
61+
node | avg
62+
-------+------
63+
brain | 0.55
64+
pinky | 0.15
65+
```
66+
67+
### Series Views
68+
69+
The series views allows exploration of the series present for a given metric.
70+
By default, these views are found in the `prom_series` schema. Each metric
71+
has a view named after the metric name (.e.g. the `cpu_usage` metric would
72+
have a `prom_series.cpu_usage` view). The view contains a the following
73+
column:
74+
75+
- series_id
76+
- labels
77+
- plus a column for each label name's value in the metric's label set
78+
79+
For example:
80+
```
81+
# \d+ prom_series.cpu_usage
82+
View "prom_series.cpu_usage"
83+
Column | Type | Collation | Nullable | Default | Storage | Description
84+
-----------+-----------+-----------+----------+---------+----------+-------------
85+
series_id | bigint | | | | plain |
86+
labels | integer[] | | | | extended |
87+
namespace | text | | | | extended |
88+
node | text | | | | extended |
89+
```
90+
91+
Example query to look at all the series:
92+
```
93+
# SELECT * FROM prom_series.cpu_usage;
94+
series_id | labels | namespace | node
95+
-----------+---------+------------+-------
96+
4 | {3,4} | dev | pinky
97+
5 | {5,6} | production | brain
98+
```

pkg/pgmodel/migrate.go

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -36,6 +36,8 @@ func (t *mySrc) replaceSchemaNames(r io.ReadCloser) (io.ReadCloser, error) {
3636
s := buf.String()
3737
s = strings.ReplaceAll(s, "SCHEMA_CATALOG", catalogSchema)
3838
s = strings.ReplaceAll(s, "SCHEMA_PROM", promSchema)
39+
s = strings.ReplaceAll(s, "SCHEMA_SERIES", seriesViewSchema)
40+
s = strings.ReplaceAll(s, "SCHEMA_METRIC", metricViewSchema)
3941
r = ioutil.NopCloser(strings.NewReader(s))
4042
return r, err
4143
}

pkg/pgmodel/migrate_test.go

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -30,7 +30,7 @@ var (
3030
)
3131

3232
const (
33-
expectedVersion = 2
33+
expectedVersion = 1
3434
)
3535

3636
func TestMigrate(t *testing.T) {

pkg/pgmodel/migrations/migration_files_generated.go

Lines changed: 2 additions & 10 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

pkg/pgmodel/migrations/sql/1_base_schema.up.sql

Lines changed: 145 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -3,6 +3,9 @@
33

44
CREATE SCHEMA IF NOT EXISTS SCHEMA_CATALOG; -- catalog tables + internal functions
55
CREATE SCHEMA IF NOT EXISTS SCHEMA_PROM; -- data tables + public functions
6+
CREATE SCHEMA IF NOT EXISTS SCHEMA_SERIES;
7+
CREATE SCHEMA IF NOT EXISTS SCHEMA_METRIC;
8+
69

710
CREATE EXTENSION IF NOT EXISTS timescaledb WITH SCHEMA public;
811
-----------------------
@@ -105,35 +108,34 @@ CREATE TRIGGER make_metric_table_trigger
105108
-- Internal functions --
106109
------------------------
107110

108-
-- Return a table name built from a metric_name and a suffix.
109-
-- The metric name is truncated so that the suffix could fit in full.
110-
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.metric_table_name_with_suffix(
111-
metric_name text, suffix text)
111+
-- Return a table name built from a full_name and a suffix.
112+
-- The full name is truncated so that the suffix could fit in full.
113+
-- name size will always be 63 chars.
114+
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.pg_name_with_suffix(
115+
full_name text, suffix text)
112116
RETURNS name
113117
AS $func$
114-
SELECT (substring(metric_name for 63-(char_length(suffix)+1)) || '_' || suffix)::name
118+
SELECT (substring(full_name for 63-(char_length(suffix)+1)) || '_' || suffix)::name
115119
$func$
116120
LANGUAGE sql IMMUTABLE PARALLEL SAFE;
117121

118-
-- Return a new name for a metric table.
119-
-- This tries to use the metric table in full. But if the
120-
-- metric name doesn't fit, generates a new unique name.
121-
-- Note that this can use up the next val of SCHEMA_CATALOG.metric_name_suffx
122-
-- so it should be called only if a table does not yet exist.
123-
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.new_metric_table_name(
124-
metric_name_arg text, metric_id int)
122+
-- Return a new unique name from a name and id.
123+
-- This tries to use the full_name in full. But if the
124+
-- full name doesn't fit, generates a new unique name.
125+
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.pg_name_unique(
126+
full_name_arg text, id int)
125127
RETURNS name
126128
AS $func$
127129
SELECT CASE
128-
WHEN char_length(metric_name_arg) < 63 THEN
129-
metric_name_arg::name
130+
WHEN char_length(full_name_arg) < 63 THEN
131+
full_name_arg::name
130132
ELSE
131-
SCHEMA_CATALOG.metric_table_name_with_suffix(
132-
metric_name_arg, metric_id::text
133+
SCHEMA_CATALOG.pg_name_with_suffix(
134+
full_name_arg, id::text
133135
)
134136
END
135137
$func$
136-
LANGUAGE sql VOLATILE PARALLEL SAFE;
138+
LANGUAGE sql IMMUTABLE PARALLEL SAFE;
137139

138140
--Creates a new table for a given metric name.
139141
--This uses up some sequences so should only be called
@@ -149,7 +151,7 @@ LOOP
149151
INSERT INTO SCHEMA_CATALOG.metric (id, metric_name, table_name)
150152
SELECT new_id,
151153
metric_name_arg,
152-
SCHEMA_CATALOG.new_metric_table_name(metric_name_arg, new_id)
154+
SCHEMA_CATALOG.pg_name_unique(metric_name_arg, new_id)
153155
ON CONFLICT DO NOTHING
154156
RETURNING SCHEMA_CATALOG.metric.id, SCHEMA_CATALOG.metric.table_name
155157
INTO id, table_name;
@@ -235,6 +237,10 @@ BEGIN
235237
IF NOT FOUND THEN
236238
RAISE 'Could not find a new position';
237239
END IF;
240+
241+
PERFORM SCHEMA_CATALOG.create_series_view(metric_name);
242+
PERFORM SCHEMA_CATALOG.create_metric_view(metric_name);
243+
238244
RETURN position;
239245
END
240246
$func$
@@ -755,3 +761,124 @@ BEGIN
755761
END LOOP;
756762
END;
757763
$$;
764+
765+
CREATE OR REPLACE FUNCTION SCHEMA_PROM.is_stale_marker(value double precision)
766+
RETURNS BOOLEAN
767+
AS $func$
768+
SELECT float8send(value) = '\x7ff0000000000002'
769+
$func$
770+
LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
771+
772+
CREATE OR REPLACE FUNCTION SCHEMA_PROM.is_normal_nan(value double precision)
773+
RETURNS BOOLEAN
774+
AS $func$
775+
SELECT float8send(value) = '\x7ff8000000000001'
776+
$func$
777+
LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
778+
779+
CREATE OR REPLACE FUNCTION SCHEMA_PROM.get_label_value(
780+
label_id INT)
781+
RETURNS TEXT
782+
AS $$
783+
SELECT
784+
value
785+
FROM SCHEMA_CATALOG.label
786+
WHERE
787+
id = label_id
788+
$$
789+
LANGUAGE SQL STABLE PARALLEL SAFE;
790+
791+
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.get_label_key_column_name(label_key text, id int)
792+
returns NAME
793+
AS $func$
794+
DECLARE
795+
is_reserved boolean;
796+
BEGIN
797+
SELECT label_key = ANY(ARRAY['time', 'value', 'series_id', 'labels'])
798+
INTO STRICT is_reserved;
799+
800+
IF is_reserved THEN
801+
label_key := label_key || '_label';
802+
END IF;
803+
804+
RETURN SCHEMA_CATALOG.pg_name_unique(label_key, id);
805+
END
806+
$func$
807+
LANGUAGE PLPGSQL;
808+
809+
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.create_series_view(
810+
metric_name text)
811+
RETURNS BOOLEAN
812+
AS $func$
813+
DECLARE
814+
label_value_cols text;
815+
view_name text;
816+
metric_id int;
817+
BEGIN
818+
SELECT
819+
',' || string_agg(
820+
format ('SCHEMA_PROM.get_label_value(series.labels[%s]) AS %I',pos::int, SCHEMA_CATALOG.get_label_key_column_name(key, pos))
821+
, ', ' ORDER BY pos)
822+
INTO STRICT label_value_cols
823+
FROM SCHEMA_CATALOG.label_key_position lkp
824+
WHERE lkp.metric = metric_name and key != '__name__';
825+
826+
SELECT m.table_name, m.id
827+
INTO STRICT view_name, metric_id
828+
FROM SCHEMA_CATALOG.metric m
829+
WHERE m.metric_name = create_series_view.metric_name;
830+
831+
EXECUTE FORMAT($$
832+
CREATE OR REPLACE VIEW SCHEMA_SERIES.%I AS
833+
SELECT
834+
id AS series_id,
835+
labels
836+
%s
837+
FROM
838+
SCHEMA_CATALOG.series
839+
WHERE metric_id = %L
840+
$$, view_name, label_value_cols, metric_id);
841+
RETURN true;
842+
END
843+
$func$
844+
LANGUAGE PLPGSQL;
845+
846+
847+
CREATE OR REPLACE FUNCTION SCHEMA_CATALOG.create_metric_view(
848+
metric_name text)
849+
RETURNS BOOLEAN
850+
AS $func$
851+
DECLARE
852+
label_value_cols text;
853+
table_name text;
854+
metric_id int;
855+
BEGIN
856+
SELECT
857+
',' || string_agg(
858+
format ('series.labels[%s] AS %I',pos::int, SCHEMA_CATALOG.get_label_key_column_name(key||'_id', pos))
859+
, ', ' ORDER BY pos)
860+
INTO STRICT label_value_cols
861+
FROM SCHEMA_CATALOG.label_key_position lkp
862+
WHERE lkp.metric = metric_name and key != '__name__';
863+
864+
SELECT m.table_name, m.id
865+
INTO STRICT table_name, metric_id
866+
FROM SCHEMA_CATALOG.metric m
867+
WHERE m.metric_name = create_metric_view.metric_name;
868+
869+
EXECUTE FORMAT($$
870+
CREATE OR REPLACE VIEW SCHEMA_METRIC.%1$I AS
871+
SELECT
872+
data.time as time,
873+
data.value as value,
874+
data.series_id AS series_id,
875+
series.labels
876+
%2$s
877+
FROM
878+
SCHEMA_PROM.%1$I AS data
879+
LEFT JOIN SCHEMA_CATALOG.series AS series ON (series.id = data.series_id AND series.metric_id = %3$L)
880+
$$, table_name, label_value_cols, metric_id);
881+
RETURN true;
882+
END
883+
$func$
884+
LANGUAGE PLPGSQL;

pkg/pgmodel/migrations/sql/2_post-0.1.0-alpha.1.up.sql

Lines changed: 0 additions & 13 deletions
This file was deleted.

pkg/pgmodel/pgx.go

Lines changed: 4 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -24,8 +24,10 @@ import (
2424
)
2525

2626
const (
27-
promSchema = "prom"
28-
catalogSchema = "_prom_catalog"
27+
promSchema = "prom"
28+
seriesViewSchema = "prom_series"
29+
metricViewSchema = "prom_metric"
30+
catalogSchema = "_prom_catalog"
2931

3032
getMetricsTableSQL = "SELECT table_name FROM " + promSchema + ".get_metric_table_name_if_exists($1)"
3133
getCreateMetricsTableSQL = "SELECT table_name FROM " + promSchema + ".get_or_create_metric_table_name($1)"

0 commit comments

Comments
 (0)