|
3 | 3 |
|
4 | 4 | CREATE SCHEMA IF NOT EXISTS SCHEMA_CATALOG; -- catalog tables + internal functions
|
5 | 5 | 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 | + |
6 | 9 |
|
7 | 10 | CREATE EXTENSION IF NOT EXISTS timescaledb WITH SCHEMA public;
|
8 | 11 | -----------------------
|
@@ -105,35 +108,34 @@ CREATE TRIGGER make_metric_table_trigger
|
105 | 108 | -- Internal functions --
|
106 | 109 | ------------------------
|
107 | 110 |
|
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) |
112 | 116 | RETURNS name
|
113 | 117 | 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 |
115 | 119 | $func$
|
116 | 120 | LANGUAGE sql IMMUTABLE PARALLEL SAFE;
|
117 | 121 |
|
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) |
125 | 127 | RETURNS name
|
126 | 128 | AS $func$
|
127 | 129 | 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 |
130 | 132 | 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 |
133 | 135 | )
|
134 | 136 | END
|
135 | 137 | $func$
|
136 |
| -LANGUAGE sql VOLATILE PARALLEL SAFE; |
| 138 | +LANGUAGE sql IMMUTABLE PARALLEL SAFE; |
137 | 139 |
|
138 | 140 | --Creates a new table for a given metric name.
|
139 | 141 | --This uses up some sequences so should only be called
|
|
149 | 151 | INSERT INTO SCHEMA_CATALOG.metric (id, metric_name, table_name)
|
150 | 152 | SELECT new_id,
|
151 | 153 | 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) |
153 | 155 | ON CONFLICT DO NOTHING
|
154 | 156 | RETURNING SCHEMA_CATALOG.metric.id, SCHEMA_CATALOG.metric.table_name
|
155 | 157 | INTO id, table_name;
|
@@ -235,6 +237,10 @@ BEGIN
|
235 | 237 | IF NOT FOUND THEN
|
236 | 238 | RAISE 'Could not find a new position';
|
237 | 239 | END IF;
|
| 240 | + |
| 241 | + PERFORM SCHEMA_CATALOG.create_series_view(metric_name); |
| 242 | + PERFORM SCHEMA_CATALOG.create_metric_view(metric_name); |
| 243 | + |
238 | 244 | RETURN position;
|
239 | 245 | END
|
240 | 246 | $func$
|
@@ -755,3 +761,124 @@ BEGIN
|
755 | 761 | END LOOP;
|
756 | 762 | END;
|
757 | 763 | $$;
|
| 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; |
0 commit comments