diff --git a/docker-compose/timescaledb/Dockerfile b/docker-compose/timescaledb/Dockerfile index f97faca9aaa8ab6f14299f64e9dbaa4fbe9ef599..8d250ae85724844d4e2ec34fa6eb4cce60943c96 100644 --- a/docker-compose/timescaledb/Dockerfile +++ b/docker-compose/timescaledb/Dockerfile @@ -1,10 +1,25 @@ FROM timescale/timescaledb:latest-pg12 - +# Set admin role to perform DB creation COPY resources/01_admin.sh docker-entrypoint-initdb.d/002_admin.sh +# Create DB schema (tables, indexes, etc.) COPY resources/02_hdb_schema.sql docker-entrypoint-initdb.d/003_hdb_schema.sql +# Create DB roles COPY resources/03_hdb_roles.sql docker-entrypoint-initdb.d/004_hdb_roles.sql -COPY resources/04_hdb_ext_aggregates.sql docker-entrypoint-initdb.d/005_hdb_ext_aggregates.sql -COPY resources/05_lofar_func.sh docker-entrypoint-initdb.d/006_lofar_func.sh -COPY resources/06_lofar_views.sql docker-entrypoint-initdb.d/007_lofar_views.sql -COPY resources/07_cleanup.sql docker-entrypoint-initdb.d/008_cleanup.sql +# Create further roles +COPY resources/04_hdb_ext_users.sql docker-entrypoint-initdb.d/005_hdb_ext_users.sql +# Create timescaledb aggregates +COPY resources/05_hdb_ext_aggregates.sql docker-entrypoint-initdb.d/006_hdb_ext_aggregates.sql +COPY resources/06_hdb_ext_arrays_aggregates_helper.sql docker-entrypoint-initdb.d/007_hdb_ext_arrays_aggregates_helper.sql +COPY resources/07_hdb_ext_arrays_aggregates.sql docker-entrypoint-initdb.d/008_hdb_ext_arrays_aggregates.sql +# Add compress policy +COPY resources/08_hdb_ext_compress_policy.sql docker-entrypoint-initdb.d/009_hdb_ext_compress_policy.sql +# Add further functions +COPY resources/09_hdb_ext_import.sql docker-entrypoint-initdb.d/010_hdb_ext_import.sql +# Add reorder policy +COPY resources/10_hdb_ext_reorder_policy.sql docker-entrypoint-initdb.d/011_hdb_ext_reorder_policy.sql +# Add LOFAR functions and views +COPY resources/11_lofar_func.sh docker-entrypoint-initdb.d/012_lofar_func.sh +COPY resources/12_lofar_views.sql docker-entrypoint-initdb.d/013_lofar_views.sql +# Cleanup admin role +COPY resources/13_cleanup.sql docker-entrypoint-initdb.d/014_cleanup.sql diff --git a/docker-compose/timescaledb/resources/04_hdb_ext_users.sql b/docker-compose/timescaledb/resources/04_hdb_ext_users.sql new file mode 100644 index 0000000000000000000000000000000000000000..1ce744e8675d4833f983cdf040107c4e1dd7c346 --- /dev/null +++ b/docker-compose/timescaledb/resources/04_hdb_ext_users.sql @@ -0,0 +1,32 @@ +-- ----------------------------------------------------------------------------- +-- This file is part of the hdbpp-timescale-project +-- +-- Copyright (C) : 2014-2019 +-- European Synchrotron Radiation Facility +-- BP 220, Grenoble 38043, FRANCE +-- +-- libhdb++timescale is free software: you can redistribute it and/or modify +-- it under the terms of the Lesser GNU General Public License as published by +-- the Free Software Foundation, either version 3 of the License, or +-- (at your option) any later version. +-- +-- libhdb++timescale is distributed in the hope that it will be useful, +-- but WITHOUT ANY WARRANTY; without even the implied warranty of +-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser +-- GNU General Public License for more details. +-- +-- You should have received a copy of the Lesser GNU General Public License +-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>. +-- ----------------------------------------------------------------------------- + +\c hdb + +-- Some useful users for a basic system +CREATE ROLE hdb_cfg_man WITH LOGIN PASSWORD 'hdbpp'; +GRANT readwrite TO hdb_cfg_man; + +CREATE ROLE hdb_event_sub WITH LOGIN PASSWORD 'hdbpp'; +GRANT readwrite TO hdb_event_sub; + +CREATE ROLE hdb_data_reporter WITH LOGIN PASSWORD 'hdbpp'; +GRANT readonly TO hdb_data_reporter; diff --git a/docker-compose/timescaledb/resources/04_hdb_ext_aggregates.sql b/docker-compose/timescaledb/resources/05_hdb_ext_aggregates.sql similarity index 99% rename from docker-compose/timescaledb/resources/04_hdb_ext_aggregates.sql rename to docker-compose/timescaledb/resources/05_hdb_ext_aggregates.sql index 7c3484299f5ab982be7021bd5d48491f08ec67e2..a253ccd04f3ef74728cdacc4884c7fb31806ab17 100644 --- a/docker-compose/timescaledb/resources/04_hdb_ext_aggregates.sql +++ b/docker-compose/timescaledb/resources/05_hdb_ext_aggregates.sql @@ -1290,3 +1290,4 @@ GRANT SELECT ON cagg_scalar_devushort_1day TO readonly; -- DROP VIEW cagg_scalar_devushort_1hour CASCADE; -- DROP VIEW cagg_scalar_devushort_8hour CASCADE; -- DROP VIEW cagg_scalar_devushort_1day CASCADE; + diff --git a/docker-compose/timescaledb/resources/06_hdb_ext_arrays_aggregates_helper.sql b/docker-compose/timescaledb/resources/06_hdb_ext_arrays_aggregates_helper.sql new file mode 100644 index 0000000000000000000000000000000000000000..7c67f65366984268f337133c938b9bda909e95fe --- /dev/null +++ b/docker-compose/timescaledb/resources/06_hdb_ext_arrays_aggregates_helper.sql @@ -0,0 +1,2336 @@ +-- ----------------------------------------------------------------------------- +-- This file is part of the hdbpp-timescale-project +-- +-- Copyright (C) : 2014-2019 +-- European Synchrotron Radiation Facility +-- BP 220, Grenoble 38043, FRANCE +-- +-- libhdb++timescale is free software: you can redistribute it and/or modify +-- it under the terms of the Lesser GNU General Public License as published by +-- the Free Software Foundation, either version 3 of the License, or +-- (at your option) any later version. +-- +-- libhdb++timescale is distributed in the hope that it will be useful, +-- but WITHOUT ANY WARRANTY; without even the implied warranty of +-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser +-- GNU General Public License for more details. +-- +-- You should have received a copy of the Lesser GNU General Public License +-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>. +-- ----------------------------------------------------------------------------- + +-- Aggregates function helper for the continuous aggregates views for the array attributes. + +\c hdb + +/* +NOT USED +Keep as a different approach, should be benchmarked for execution speed + +-- Special type to be used as input by compute_element_agg +-- It contains past aggregates result and the new values +create type double_agg_input as ( + value_r double precision, + value_w double precision, + count_r integer, + count_nan_r integer, + avg_r decimal, + min_r double precision, + max_r double precision, + stddev_r decimal, + count_w integer, + count_nan_w integer, + avg_w decimal, + min_w double precision, + max_w double precision, + stddev_w decimal +); + +-- Function to compute the aggregates from the new values and old aggregates +-- result. +-- It computes the result for an array of input and return a table so that it +-- can be used in a FROM clause +CREATE OR REPLACE FUNCTION compute_element_agg(inp_arr double_agg_input[] + ) RETURNS SETOF RECORD as $$ + +DECLARE + ret RECORD; + inp double_agg_input; + value_r double precision; + value_w double precision; + count_r integer; + count_nan_r integer; + avg_r decimal; + min_r double precision; + max_r double precision; + stddev_r decimal; + count_w integer; + count_nan_w integer; + avg_w decimal; + min_w double precision; + max_w double precision; + stddev_w decimal; + n_count_r integer; + n_count_nan_r integer; + n_avg_r decimal; + n_min_r double precision; + n_max_r double precision; + n_stddev_r decimal; + n_count_w integer; + n_count_nan_w integer; + n_avg_w decimal; + n_min_w double precision; + n_max_w double precision; + n_stddev_w decimal; + +BEGIN + FOREACH inp IN ARRAY inp_arr + LOOP + + value_r := inp.value_r; + value_w := inp.value_w; + count_r := inp.count_r; + count_nan_r := inp.count_nan_r; + avg_r := inp.avg_r; + min_r := inp.min_r; + max_r := inp.max_r; + stddev_r := inp.stddev_r; + count_w := inp.count_w; + count_nan_w := inp.count_nan_w; + avg_w := inp.avg_w; + min_w := inp.min_w; + stddev_w := inp.stddev_w; + + IF value_r IS NULL OR value_r='NaN'::float8 OR value_r='Infinity' OR value_r='-Infinity' + THEN + + IF count_r IS NULL + THEN + n_count_r = 0; + ELSE + n_count_r = count_r; + END IF; + + IF value_r IS NULL + THEN + + IF count_nan_r IS NULL + THEN + n_count_nan_r = 0; + ELSE + n_count_nan_r = count_nan_r; + END IF; + + ELSE + + IF count_nan_r IS NULL + THEN + n_count_nan_r = 1; + ELSE + n_count_nan_r = count_nan_r + 1; + END IF; + END IF; + + n_avg_r = avg_r; + n_min_r = min_r; + n_max_r = max_r; + n_stddev_r = stddev_r; + + ELSE + + IF count_nan_r IS NULL + THEN + n_count_nan_r = 0; + ELSE + n_count_nan_r = count_nan_r; + END IF; + + IF count_r IS NULL + THEN + n_count_r = 1; + ELSE + n_count_r = count_r + 1; + END IF; + + IF avg_r IS NULL + THEN + n_avg_r = value_r; + ELSE + n_avg_r = avg_r + (value_r-avg_r)/(count_r+1.)::decimal; + END IF; + + n_min_r = LEAST(value_r, min_r); + n_max_r = GREATEST(value_r, max_r); + + IF stddev_r IS NULL + THEN + n_stddev_r = 0; + ELSE + n_stddev_r = stddev_r + ((count_r + 0.)/(count_r+1.))*power(value_r - avg_r, 2); + END IF; + END IF; + + IF value_w IS NULL OR value_w='NaN'::float8 OR value_w='Infinity' OR value_w='-Infinity' + THEN + + IF count_w IS NULL + THEN + n_count_w = 0; + ELSE + n_count_w = count_w; + END IF; + + IF value_w IS NULL + THEN + + IF count_nan_w IS NULL + THEN + n_count_nan_w = 0; + ELSE + n_count_nan_w = count_nan_w; + END IF; + + ELSE + + IF count_nan_w IS NULL + THEN + n_count_nan_w = 1; + ELSE + n_count_nan_w = count_nan_w + 1; + END IF; + END IF; + + n_avg_w = avg_w; + n_min_w = min_w; + n_max_w = max_w; + n_stddev_w = stddev_w; + + ELSE + + IF count_nan_w IS NULL + THEN + n_count_nan_w = 0; + ELSE + n_count_nan_w = count_nan_w; + END IF; + + IF count_w IS NULL + THEN + n_count_w = 1; + ELSE + n_count_w = count_w + 1; + END IF; + + IF avg_w IS NULL + THEN + n_avg_w = value_w; + ELSE + n_avg_w = avg_w + (value_w-avg_w)/(count_w+1); + END IF; + + n_min_w = LEAST(value_w, min_w); + n_max_w = GREATEST(value_w, max_w); + + IF stddev_w IS NULL + THEN + n_stddev_w = 0; + ELSE + n_stddev_w = stddev_w + ((count_w + 0.)/(count_w+1.)*power(value_w - avg_w, 2)); + END IF; + END IF; + + ret := (n_count_r, n_count_nan_r, n_avg_r, n_min_r, n_max_r, n_stddev_r + , n_count_w, n_count_nan_w, n_avg_w, n_min_w, n_max_w, n_stddev_w); + + return next ret; + END LOOP; +END; +$$ +LANGUAGE 'plpgsql'; +*/ + + +-- Special types to store the aggregations data during computation +create type double_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + count_nan_r integer[], + avg_r decimal[], + min_r double precision[], + max_r double precision[], + stddev_r decimal[], + count_w integer[], + count_nan_w integer[], + avg_w decimal[], + min_w double precision[], + max_w double precision[], + stddev_w decimal[] +); + +create type float_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + count_nan_r integer[], + avg_r decimal[], + min_r real[], + max_r real[], + stddev_r decimal[], + count_w integer[], + count_nan_w integer[], + avg_w decimal[], + min_w real[], + max_w real[], + stddev_w decimal[] +); + +create type long_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + avg_r decimal[], + min_r integer[], + max_r integer[], + stddev_r decimal[], + count_w integer[], + avg_w decimal[], + min_w integer[], + max_w integer[], + stddev_w decimal[] +); + +create type long64_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + avg_r decimal[], + min_r bigint[], + max_r bigint[], + stddev_r decimal[], + count_w integer[], + avg_w decimal[], + min_w bigint[], + max_w bigint[], + stddev_w decimal[] +); + +create type short_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + avg_r decimal[], + min_r smallint[], + max_r smallint[], + stddev_r decimal[], + count_w integer[], + avg_w decimal[], + min_w smallint[], + max_w smallint[], + stddev_w decimal[] +); + +create type ulong_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + avg_r decimal[], + min_r ulong[], + max_r ulong[], + stddev_r decimal[], + count_w integer[], + avg_w decimal[], + min_w ulong[], + max_w ulong[], + stddev_w decimal[] +); + +create type ulong64_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + avg_r decimal[], + min_r ulong64[], + max_r ulong64[], + stddev_r decimal[], + count_w integer[], + avg_w decimal[], + min_w ulong64[], + max_w ulong64[], + stddev_w decimal[] +); + +create type ushort_array_agg_state as ( + count integer, + count_errors integer, + count_r integer[], + avg_r decimal[], + min_r ushort[], + max_r ushort[], + stddev_r decimal[], + count_w integer[], + avg_w decimal[], + min_w ushort[], + max_w ushort[], + stddev_w decimal[] +); + +-- Function to combine to aggregate state into a new one +-- needed for the aggregate function to be used for partial aggregation +CREATE OR REPLACE FUNCTION fn_double_combine(double_array_agg_state, double_array_agg_state) + RETURNS double_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result double_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::float8[], ARRAY[]::float8[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::float8[], ARRAY[]::float8[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.count_nan_r) AS nan_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.count_nan_w) AS nan_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.count_nan_r) AS nan_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.count_nan_w) AS nan_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), array_agg(count_nan_r1+count_nan_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), array_agg(count_nan_w1+count_nan_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_float_combine(float_array_agg_state, float_array_agg_state) + RETURNS float_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result float_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::real[], ARRAY[]::real[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::real[], ARRAY[]::real[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.count_nan_r) AS nan_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.count_nan_w) AS nan_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.count_nan_r) AS nan_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.count_nan_w) AS nan_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), array_agg(count_nan_r1+count_nan_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), array_agg(count_nan_w1+count_nan_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_long_combine(long_array_agg_state, long_array_agg_state) + RETURNS long_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result long_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.count_nan_r) AS nan_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.count_nan_w) AS nan_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.count_nan_r) AS nan_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.count_nan_w) AS nan_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_long64_combine(long64_array_agg_state, long64_array_agg_state) + RETURNS long64_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result long64_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::bigint[], ARRAY[]::bigint[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::bigint[], ARRAY[]::bigint[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_short_combine(short_array_agg_state, short_array_agg_state) + RETURNS short_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result short_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::smallint[], ARRAY[]::smallint[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::smallint[], ARRAY[]::smallint[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ulong_combine(ulong_array_agg_state, ulong_array_agg_state) + RETURNS ulong_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result ulong_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong[], ARRAY[]::ulong[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong[], ARRAY[]::ulong[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ulong64_combine(ulong64_array_agg_state, ulong64_array_agg_state) + RETURNS ulong64_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result ulong64_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong64[], ARRAY[]::ulong64[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong64[], ARRAY[]::ulong64[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ushort_combine(ushort_array_agg_state, ushort_array_agg_state) + RETURNS ushort_array_agg_state AS $$ + +DECLARE + state1 ALIAS FOR $1; + state2 ALIAS FOR $2; + count integer; + count_errors integer; + result ushort_array_agg_state%ROWTYPE; + +BEGIN + + -- Limit cases. + IF state1 is NULL + THEN + return state2; + END IF; + + IF state2 is NULL + THEN + return state1; + END IF; + + -- if there is a discrepancy in the arrays sizes + IF CARDINALITY(state1.avg_r) != CARDINALITY(state2.avg_r) OR CARDINALITY(state1.avg_w) != CARDINALITY(state2.avg_w) THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ushort[], ARRAY[]::ushort[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ushort[], ARRAY[]::ushort[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state1.count + state2.count; + count_errors := state1.count_errors + state2.count_errors; + + WITH arrays AS( + SELECT + UNNEST(state1.count_r) AS count_r1, UNNEST(state1.avg_r) AS avg_r1, + UNNEST(state1.min_r) AS min_r1, UNNEST(state1.max_r) AS max_r1, UNNEST(state1.stddev_r) AS stddev_r1, + UNNEST(state1.count_w) AS count_w1, UNNEST(state1.avg_w) AS avg_w1, + UNNEST(state1.min_w) AS min_w1, UNNEST(state1.max_w) AS max_w1, UNNEST(state1.stddev_w) AS stddev_w1, + UNNEST(state2.count_r) AS count_r2, UNNEST(state2.avg_r) AS avg_r2, + UNNEST(state2.min_r) AS min_r2, UNNEST(state2.max_r) AS max_r2, UNNEST(state2.stddev_r) AS stddev_r2, + UNNEST(state2.count_w) AS count_w2, UNNEST(state2.avg_w) AS avg_w2, + UNNEST(state2.min_w) AS min_w2, UNNEST(state2.max_w) AS max_w2, UNNEST(state2.stddev_w) AS stddev_w2 + ) + SELECT count, count_errors, + array_agg(count_r1+count_r2), + array_agg(avg_r1 + (count_r2/(count_r1+count_r2))*(avg_r2-avg_r1)), array_agg(LEAST(min_r1, min_r2)), array_agg(GREATEST(max_r1, max_r2)), + array_agg(stddev_r1 + (count_r2*count_r1/count_r1+count_r2)*power(avg_r2 - avg_r1, 2)), + array_agg(count_w1+count_w2), + array_agg(avg_w1 + (count_w2/(count_w1+count_w2))*(avg_w2-avg_w1)), array_agg(LEAST(min_w1, min_w2)), array_agg(GREATEST(max_w1, max_w2)), + array_agg(stddev_w1 + (count_w2*count_w1/count_w1+count_w2)*power(avg_w2 - avg_w1, 2)) + INTO result FROM arrays; + END IF; + + return result; +END; +$$ +LANGUAGE 'plpgsql'; + +-- Function to compute next aggregate from last state and current row +CREATE OR REPLACE FUNCTION fn_double_array_agg(double_array_agg_state,new_row att_array_devdouble) + RETURNS double_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result double_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read='NaN'::float8 THEN 0 + WHEN read='Infinity'::float8 THEN 0 + WHEN read='-Infinity'::float8 THEN 0 + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN read='NaN'::float8 THEN 1 + WHEN read='Infinity'::float8 THEN 1 + WHEN read='-Infinity'::float8 THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN read='NaN'::float8 THEN NULL + WHEN read='Infinity'::float8 THEN NULL + WHEN read='-Infinity'::float8 THEN NULL + ELSE read::decimal + END + ), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read='NaN'::float8 THEN NULL + WHEN read='Infinity'::float8 THEN NULL + WHEN read='-Infinity'::float8 THEN NULL + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write='NaN'::float8 THEN 0 + WHEN write='Infinity'::float8 THEN 0 + WHEN write='-Infinity'::float8 THEN 0 + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN write='NaN'::float8 THEN 1 + WHEN write='Infinity'::float8 THEN 1 + WHEN write='-Infinity'::float8 THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN write='NaN'::float8 THEN NULL + WHEN write='Infinity'::float8 THEN NULL + WHEN write='-Infinity'::float8 THEN NULL + ELSE write::decimal + END + ), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write='NaN'::float8 THEN NULL + WHEN write='Infinity'::float8 THEN NULL + WHEN write='-Infinity'::float8 THEN NULL + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::float8[], ARRAY[]::float8[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::float8[], ARRAY[]::float8[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.count_nan_r) AS nan_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.count_nan_w) AS nan_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read='NaN'::float8 THEN count_r + WHEN read='Infinity'::float8 THEN count_r + WHEN read='-Infinity'::float8 THEN count_r + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN nan_r + 1 + WHEN read='Infinity'::float8 THEN nan_r + 1 + WHEN read='-Infinity'::float8 THEN nan_r + 1 + ELSE nan_r + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN avg_r + WHEN read='Infinity'::float8 THEN avg_r + WHEN read='-Infinity'::float8 THEN avg_r + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read::decimal + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal::decimal + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN min_r + WHEN read='Infinity'::float8 THEN min_r + WHEN read='-Infinity'::float8 THEN min_r + ELSE LEAST(read, min_r) + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN max_r + WHEN read='Infinity'::float8 THEN max_r + WHEN read='-Infinity'::float8 THEN max_r + ELSE GREATEST(read, max_r) + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN stddev_r + WHEN read='Infinity'::float8 THEN stddev_r + WHEN read='-Infinity'::float8 THEN stddev_r + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN count_w + WHEN write='Infinity'::float8 THEN count_w + WHEN write='-Infinity'::float8 THEN count_w + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN nan_w + 1 + WHEN write='Infinity'::float8 THEN nan_w + 1 + WHEN write='-Infinity'::float8 THEN nan_w + 1 + ELSE nan_w + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN avg_w + WHEN write='Infinity'::float8 THEN avg_w + WHEN write='-Infinity'::float8 THEN avg_w + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN min_w + WHEN write='Infinity'::float8 THEN min_w + WHEN write='-Infinity'::float8 THEN min_w + ELSE LEAST(write, min_w) + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN max_w + WHEN write='Infinity'::float8 THEN max_w + WHEN write='-Infinity'::float8 THEN max_w + ELSE GREATEST(write, max_w) + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN stddev_w + WHEN write='Infinity'::float8 THEN stddev_w + WHEN write='-Infinity'::float8 THEN stddev_w + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; +/* +* Different method using compute_element_agg + + SELECT n_count_r, n_count_nan_r, n_avg_r, n_min_r, n_max_r, n_stddev_r + , n_count_w, n_count_nan_w, n_avg_w, n_min_w, n_max_w, n_stddev_w + FROM compute_element_agg( + ( SELECT array_agg(ROW(read, write + , count_r, nan_r, avg_r, min_r, max_r, stddev_r + , count_w, nan_w, avg_w, min_w, max_w, stddev_w)::double_agg_input) from arrays ) + ) as (n_count_r integer, n_count_nan_r integer, n_avg_r decimal, n_min_r double precision, n_max_r double precision, n_stddev_r decimal + , n_count_w integer, n_count_nan_w integer, n_avg_w decimal, n_min_w double precision, n_max_w double precision, n_stddev_w decimal) + ) + SELECT count, state.count_errors+count_err + , array_agg(aggregates.n_count_r), array_agg(aggregates.n_count_nan_r), array_agg(aggregates.n_avg_r), array_agg(aggregates.n_min_r), array_agg(aggregates.n_max_r), array_agg(aggregates.n_stddev_r) + , array_agg(aggregates.n_count_w), array_agg(aggregates.n_count_nan_w), array_agg(aggregates.n_avg_w), array_agg(aggregates.n_min_w), array_agg(aggregates.n_max_w), array_agg(aggregates.n_stddev_w) + into result from aggregates; +*/ + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_float_array_agg(float_array_agg_state,new_row att_array_devfloat) + RETURNS float_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result float_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read='NaN'::float8 THEN 0 + WHEN read='Infinity'::float8 THEN 0 + WHEN read='-Infinity'::float8 THEN 0 + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN read='NaN'::float8 THEN 1 + WHEN read='Infinity'::float8 THEN 1 + WHEN read='-Infinity'::float8 THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN read='NaN'::float8 THEN NULL + WHEN read='Infinity'::float8 THEN NULL + WHEN read='-Infinity'::float8 THEN NULL + ELSE read::decimal + END + ), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read='NaN'::float8 THEN NULL + WHEN read='Infinity'::float8 THEN NULL + WHEN read='-Infinity'::float8 THEN NULL + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write='NaN'::float8 THEN 0 + WHEN write='Infinity'::float8 THEN 0 + WHEN write='-Infinity'::float8 THEN 0 + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN write='NaN'::float8 THEN 1 + WHEN write='Infinity'::float8 THEN 1 + WHEN write='-Infinity'::float8 THEN 1 + ELSE 0 + END + ), array_agg( + CASE + WHEN write='NaN'::float8 THEN NULL + WHEN write='Infinity'::float8 THEN NULL + WHEN write='-Infinity'::float8 THEN NULL + ELSE write::decimal + END + ), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write='NaN'::float8 THEN NULL + WHEN write='Infinity'::float8 THEN NULL + WHEN write='-Infinity'::float8 THEN NULL + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::real[], ARRAY[]::real[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::real[], ARRAY[]::real[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.count_nan_r) AS nan_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.count_nan_w) AS nan_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read='NaN'::float8 THEN count_r + WHEN read='Infinity'::float8 THEN count_r + WHEN read='-Infinity'::float8 THEN count_r + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN nan_r + 1 + WHEN read='Infinity'::float8 THEN nan_r + 1 + WHEN read='-Infinity'::float8 THEN nan_r + 1 + ELSE nan_r + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN avg_r + WHEN read='Infinity'::float8 THEN avg_r + WHEN read='-Infinity'::float8 THEN avg_r + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN min_r + WHEN read='Infinity'::float8 THEN min_r + WHEN read='-Infinity'::float8 THEN min_r + ELSE LEAST(read, min_r) + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN max_r + WHEN read='Infinity'::float8 THEN max_r + WHEN read='-Infinity'::float8 THEN max_r + ELSE GREATEST(read, max_r) + END + ), array_agg(CASE + WHEN read='NaN'::float8 THEN stddev_r + WHEN read='Infinity'::float8 THEN stddev_r + WHEN read='-Infinity'::float8 THEN stddev_r + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN count_w + WHEN write='Infinity'::float8 THEN count_w + WHEN write='-Infinity'::float8 THEN count_w + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN nan_w + 1 + WHEN write='Infinity'::float8 THEN nan_w + 1 + WHEN write='-Infinity'::float8 THEN nan_w + 1 + ELSE nan_w + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN avg_w + WHEN write='Infinity'::float8 THEN avg_w + WHEN write='-Infinity'::float8 THEN avg_w + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN min_w + WHEN write='Infinity'::float8 THEN min_w + WHEN write='-Infinity'::float8 THEN min_w + ELSE LEAST(write, min_w) + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN max_w + WHEN write='Infinity'::float8 THEN max_w + WHEN write='-Infinity'::float8 THEN max_w + ELSE GREATEST(write, max_w) + END + ), array_agg(CASE + WHEN write='NaN'::float8 THEN stddev_w + WHEN write='Infinity'::float8 THEN stddev_w + WHEN write='-Infinity'::float8 THEN stddev_w + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_long_array_agg(long_array_agg_state,new_row att_array_devlong) + RETURNS long_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result long_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(read::decimal), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(write::decimal), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::integer[], ARRAY[]::integer[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(LEAST(read, min_r)), array_agg(GREATEST(read, max_r)) + , array_agg(CASE + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(LEAST(write, min_w)), array_agg(GREATEST(write, max_w)) + , array_agg(CASE + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_long64_array_agg(long64_array_agg_state,new_row att_array_devlong64) + RETURNS long64_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result long64_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(read::decimal), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(write::decimal), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::bigint[], ARRAY[]::bigint[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::bigint[], ARRAY[]::bigint[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(LEAST(read, min_r)), array_agg(GREATEST(read, max_r)) + , array_agg(CASE + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(LEAST(write, min_w)), array_agg(GREATEST(write, max_w)) + , array_agg(CASE + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_short_array_agg(short_array_agg_state,new_row att_array_devshort) + RETURNS short_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result short_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(read::decimal), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(write::decimal), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::smallint[], ARRAY[]::smallint[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::smallint[], ARRAY[]::smallint[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(LEAST(read, min_r)), array_agg(GREATEST(read, max_r)) + , array_agg(CASE + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(LEAST(write, min_w)), array_agg(GREATEST(write, max_w)) + , array_agg(CASE + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ulong_array_agg(ulong_array_agg_state,new_row att_array_devulong) + RETURNS ulong_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result ulong_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(read::decimal), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(write::decimal), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong[], ARRAY[]::ulong[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong[], ARRAY[]::ulong[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(LEAST(read, min_r)), array_agg(GREATEST(read, max_r)) + , array_agg(CASE + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(LEAST(write, min_w)), array_agg(GREATEST(write, max_w)) + , array_agg(CASE + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ulong64_array_agg(ulong64_array_agg_state,new_row att_array_devulong64) + RETURNS ulong64_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result ulong64_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(read::decimal), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(write::decimal), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong64[], ARRAY[]::ulong64[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ulong64[], ARRAY[]::ulong64[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(LEAST(read, min_r)), array_agg(GREATEST(read, max_r)) + , array_agg(CASE + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(LEAST(write, min_w)), array_agg(GREATEST(write, max_w)) + , array_agg(CASE + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ushort_array_agg(ushort_array_agg_state,new_row att_array_devushort) + RETURNS ushort_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + count integer; + count_err integer; + result ushort_array_agg_state%ROWTYPE; + +BEGIN + + -- Increment error count if needed + IF new_row.att_error_desc_id > 0 THEN + count_err = 1; + ELSE + count_err = 0; + END IF; + + IF state is NULL + THEN + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write) + SELECT 1, count_err, + array_agg( + CASE + WHEN read IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(read::decimal), array_agg(read), array_agg(read), array_agg( + CASE + WHEN read IS NOT NULL THEN 0 + ELSE read + END + ), + array_agg( + CASE + WHEN write IS NOT NULL THEN 1 + ELSE 0 + END + ), array_agg(write::decimal), array_agg(write), array_agg(write), array_agg( + CASE + WHEN write IS NOT NULL THEN 0 + ELSE write + END + ) + INTO result FROM arrays; + ELSE + + IF CARDINALITY(state.avg_r) != CARDINALITY(new_row.value_r) or CARDINALITY(state.avg_w) != CARDINALITY(new_row.value_w) + THEN + SELECT 0, 0, + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ushort[], ARRAY[]::ushort[], ARRAY[]::decimal[], + ARRAY[]::integer[], ARRAY[]::decimal[], ARRAY[]::ushort[], ARRAY[]::ushort[], ARRAY[]::decimal[] + INTO result; + ELSE + + count := state.count + 1; + WITH arrays AS( + SELECT UNNEST(new_row.value_r) AS read, UNNEST(new_row.value_w) AS write, + UNNEST(state.count_r) AS count_r, UNNEST(state.avg_r) AS avg_r, + UNNEST(state.min_r) AS min_r, UNNEST(state.max_r) AS max_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.avg_w) AS avg_w, + UNNEST(state.min_w) AS min_w, UNNEST(state.max_w) AS max_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT count, state.count_errors+count_err + , array_agg(CASE + WHEN read IS NOT NULL THEN count_r+1 + ELSE count_r + END + ), array_agg(CASE + WHEN read IS NULL THEN avg_r + WHEN avg_r IS NULL THEN read + ELSE avg_r + (read::decimal-avg_r)/(count_r+1.)::decimal + END + ), array_agg(LEAST(read, min_r)), array_agg(GREATEST(read, max_r)) + , array_agg(CASE + WHEN read IS NULL THEN stddev_r + WHEN stddev_r IS NULL THEN 0 + ELSE stddev_r + ((count_r+0.)/(count_r+1.))::decimal*power(read::decimal - avg_r, 2) + END + ), array_agg(CASE + WHEN write IS NOT NULL THEN count_w+1 + ELSE count_w + END + ), array_agg(CASE + WHEN write IS NULL THEN avg_w + WHEN avg_w IS NULL THEN write + ELSE avg_w + (write::decimal-avg_w)/(count_w+1.)::decimal + END + ), array_agg(LEAST(write, min_w)), array_agg(GREATEST(write, max_w)) + , array_agg(CASE + WHEN write IS NULL THEN stddev_w + WHEN stddev_w IS NULL THEN 0 + ELSE stddev_w + ((count_w+0.)/(count_w+1.))::decimal*power(write::decimal - avg_w, 2) + END + ) + INTO result FROM arrays; + END IF; + END IF; + + return result; + +END; +$$ +LANGUAGE 'plpgsql'; + +-- Function to compute the real aggregate results from the internal state +-- in this case only the stddev has to be computed +CREATE OR REPLACE FUNCTION fn_double_array_final(double_array_agg_state) + RETURNS double_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result double_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.count_nan_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.count_nan_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END + ) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_float_array_final(float_array_agg_state) + RETURNS float_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result float_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.count_nan_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.count_nan_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_long_array_final(long_array_agg_state) + RETURNS long_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result long_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_long64_array_final(long64_array_agg_state) + RETURNS long64_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result long64_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_short_array_final(short_array_agg_state) + RETURNS short_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result short_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ulong_array_final(ulong_array_agg_state) + RETURNS ulong_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result ulong_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ulong64_array_final(ulong64_array_agg_state) + RETURNS ulong64_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result ulong64_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION fn_ushort_array_final(ushort_array_agg_state) + RETURNS ushort_array_agg_state AS $$ + +DECLARE + state ALIAS FOR $1; + result ushort_array_agg_state%ROWTYPE; + +BEGIN + + IF state IS NULL + THEN + return NULL; + END IF; + + IF state.count = 0 THEN + return NULL; + + ELSE + WITH arrays AS( + SELECT UNNEST(state.count_r) AS count_r, UNNEST(state.stddev_r) AS stddev_r, + UNNEST(state.count_w) AS count_w, UNNEST(state.stddev_w) AS stddev_w + ) + SELECT state.count, state.count_errors, + state.count_r, state.avg_r, + state.min_r, state.max_r, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_r/(count_r)) + END + ), + state.count_w, state.avg_w, + state.min_w, state.max_w, array_agg(CASE + WHEN count_r=0 THEN NULL + WHEN count_r=1 THEN 0 + ELSE sqrt(stddev_w/(count_w)) + END) + INTO result FROM arrays; + + return result; + + END IF; +END; +$$ +LANGUAGE 'plpgsql'; + +-- Aggregate function declaration +CREATE AGGREGATE double_array_aggregate(att_array_devdouble) +( + sfunc = fn_double_array_agg, + stype = double_array_agg_state, + combinefunc = fn_double_combine, + finalfunc = fn_double_array_final +); + +CREATE AGGREGATE float_array_aggregate(att_array_devfloat) +( + sfunc = fn_float_array_agg, + stype = float_array_agg_state, + combinefunc = fn_float_combine, + finalfunc = fn_float_array_final +); + +CREATE AGGREGATE long_array_aggregate(att_array_devlong) +( + sfunc = fn_long_array_agg, + stype = long_array_agg_state, + combinefunc = fn_long_combine, + finalfunc = fn_long_array_final +); + +CREATE AGGREGATE long64_array_aggregate(att_array_devlong64) +( + sfunc = fn_long64_array_agg, + stype = long64_array_agg_state, + combinefunc = fn_long64_combine, + finalfunc = fn_long64_array_final +); + +CREATE AGGREGATE short_array_aggregate(att_array_devshort) +( + sfunc = fn_short_array_agg, + stype = short_array_agg_state, + combinefunc = fn_short_combine, + finalfunc = fn_short_array_final +); + +CREATE AGGREGATE ulong_array_aggregate(att_array_devulong) +( + sfunc = fn_ulong_array_agg, + stype = ulong_array_agg_state, + combinefunc = fn_ulong_combine, + finalfunc = fn_ulong_array_final +); + +CREATE AGGREGATE ulong64_array_aggregate(att_array_devulong64) +( + sfunc = fn_ulong64_array_agg, + stype = ulong64_array_agg_state, + combinefunc = fn_ulong64_combine, + finalfunc = fn_ulong64_array_final +); + +CREATE AGGREGATE ushort_array_aggregate(att_array_devushort) +( + sfunc = fn_ushort_array_agg, + stype = ushort_array_agg_state, + combinefunc = fn_ushort_combine, + finalfunc = fn_ushort_array_final +); diff --git a/docker-compose/timescaledb/resources/07_hdb_ext_arrays_aggregates.sql b/docker-compose/timescaledb/resources/07_hdb_ext_arrays_aggregates.sql new file mode 100644 index 0000000000000000000000000000000000000000..028712989defdbd6f30bcdde61e98790a9940192 --- /dev/null +++ b/docker-compose/timescaledb/resources/07_hdb_ext_arrays_aggregates.sql @@ -0,0 +1,328 @@ +-- ----------------------------------------------------------------------------- +-- This file is part of the hdbpp-timescale-project +-- +-- Copyright (C) : 2014-2019 +-- European Synchrotron Radiation Facility +-- BP 220, Grenoble 38043, FRANCE +-- +-- libhdb++timescale is free software: you can redistribute it and/or modify +-- it under the terms of the Lesser GNU General Public License as published by +-- the Free Software Foundation, either version 3 of the License, or +-- (at your option) any later version. +-- +-- libhdb++timescale is distributed in the hope that it will be useful, +-- but WITHOUT ANY WARRANTY; without even the implied warranty of +-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser +-- GNU General Public License for more details. +-- +-- You should have received a copy of the Lesser GNU General Public License +-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>. +-- ----------------------------------------------------------------------------- + +-- Continuous aggregates views for the array attributes. +\c hdb +-- Double attributes +CREATE MATERIALIZED VIEW cagg_array_devdouble_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, count_nan_r, mean_r, min_r, max_r, stddev_r + , count_w, count_nan_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (double_array_aggregate(t)).count, (double_array_aggregate(t)).count_errors + , (double_array_aggregate(t)).count_r, (double_array_aggregate(t)).count_nan_r, (double_array_aggregate(t)).avg_r::float8[], (double_array_aggregate(t)).min_r, (double_array_aggregate(t)).max_r, (double_array_aggregate(t)).stddev_r::float8[] + , (double_array_aggregate(t)).count_w, (double_array_aggregate(t)).count_nan_w, (double_array_aggregate(t)).avg_w::float8[], (double_array_aggregate(t)).min_w, (double_array_aggregate(t)).max_w, (double_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devdouble as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devdouble_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, count_nan_r, mean_r, min_r, max_r, stddev_r + , count_w, count_nan_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (double_array_aggregate(t)).count, (double_array_aggregate(t)).count_errors + , (double_array_aggregate(t)).count_r, (double_array_aggregate(t)).count_nan_r, (double_array_aggregate(t)).avg_r::float8[], (double_array_aggregate(t)).min_r, (double_array_aggregate(t)).max_r, (double_array_aggregate(t)).stddev_r::float8[] + , (double_array_aggregate(t)).count_w, (double_array_aggregate(t)).count_nan_w, (double_array_aggregate(t)).avg_w::float8[], (double_array_aggregate(t)).min_w, (double_array_aggregate(t)).max_w, (double_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devdouble as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devdouble_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, count_nan_r, mean_r, min_r, max_r, stddev_r + , count_w, count_nan_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (double_array_aggregate(t)).count, (double_array_aggregate(t)).count_errors + , (double_array_aggregate(t)).count_r, (double_array_aggregate(t)).count_nan_r, (double_array_aggregate(t)).avg_r::float8[], (double_array_aggregate(t)).min_r, (double_array_aggregate(t)).max_r, (double_array_aggregate(t)).stddev_r::float8[] + , (double_array_aggregate(t)).count_w, (double_array_aggregate(t)).count_nan_w, (double_array_aggregate(t)).avg_w::float8[], (double_array_aggregate(t)).min_w, (double_array_aggregate(t)).max_w, (double_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devdouble as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Float attributes +CREATE MATERIALIZED VIEW cagg_array_devfloat_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, count_nan_r, mean_r, min_r, max_r, stddev_r + , count_w, count_nan_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (float_array_aggregate(t)).count, (float_array_aggregate(t)).count_errors + , (float_array_aggregate(t)).count_r, (float_array_aggregate(t)).count_nan_r, (float_array_aggregate(t)).avg_r::float8[], (float_array_aggregate(t)).min_r, (float_array_aggregate(t)).max_r, (float_array_aggregate(t)).stddev_r::float8[] + , (float_array_aggregate(t)).count_w, (float_array_aggregate(t)).count_nan_w, (float_array_aggregate(t)).avg_w::float8[], (float_array_aggregate(t)).min_w, (float_array_aggregate(t)).max_w, (float_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devfloat as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devfloat_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, count_nan_r, mean_r, min_r, max_r, stddev_r + , count_w, count_nan_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (float_array_aggregate(t)).count, (float_array_aggregate(t)).count_errors + , (float_array_aggregate(t)).count_r, (float_array_aggregate(t)).count_nan_r, (float_array_aggregate(t)).avg_r::float8[], (float_array_aggregate(t)).min_r, (float_array_aggregate(t)).max_r, (float_array_aggregate(t)).stddev_r::float8[] + , (float_array_aggregate(t)).count_w, (float_array_aggregate(t)).count_nan_w, (float_array_aggregate(t)).avg_w::float8[], (float_array_aggregate(t)).min_w, (float_array_aggregate(t)).max_w, (float_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devfloat as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devfloat_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, count_nan_r, mean_r, min_r, max_r, stddev_r + , count_w, count_nan_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (float_array_aggregate(t)).count, (float_array_aggregate(t)).count_errors + , (float_array_aggregate(t)).count_r, (float_array_aggregate(t)).count_nan_r, (float_array_aggregate(t)).avg_r::float8[], (float_array_aggregate(t)).min_r, (float_array_aggregate(t)).max_r, (float_array_aggregate(t)).stddev_r::float8[] + , (float_array_aggregate(t)).count_w, (float_array_aggregate(t)).count_nan_w, (float_array_aggregate(t)).avg_w::float8[], (float_array_aggregate(t)).min_w, (float_array_aggregate(t)).max_w, (float_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devfloat as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Long attributes +CREATE MATERIALIZED VIEW cagg_array_devlong_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (long_array_aggregate(t)).count, (long_array_aggregate(t)).count_errors + , (long_array_aggregate(t)).count_r, (long_array_aggregate(t)).avg_r::float8[], (long_array_aggregate(t)).min_r, (long_array_aggregate(t)).max_r, (long_array_aggregate(t)).stddev_r::float8[] + , (long_array_aggregate(t)).count_w, (long_array_aggregate(t)).avg_w::float8[], (long_array_aggregate(t)).min_w, (long_array_aggregate(t)).max_w, (long_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devlong as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devlong_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (long_array_aggregate(t)).count, (long_array_aggregate(t)).count_errors + , (long_array_aggregate(t)).count_r, (long_array_aggregate(t)).avg_r::float8[], (long_array_aggregate(t)).min_r, (long_array_aggregate(t)).max_r, (long_array_aggregate(t)).stddev_r::float8[] + , (long_array_aggregate(t)).count_w, (long_array_aggregate(t)).avg_w::float8[], (long_array_aggregate(t)).min_w, (long_array_aggregate(t)).max_w, (long_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devlong as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devlong_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (long_array_aggregate(t)).count, (long_array_aggregate(t)).count_errors + , (long_array_aggregate(t)).count_r, (long_array_aggregate(t)).avg_r::float8[], (long_array_aggregate(t)).min_r, (long_array_aggregate(t)).max_r, (long_array_aggregate(t)).stddev_r::float8[] + , (long_array_aggregate(t)).count_w, (long_array_aggregate(t)).avg_w::float8[], (long_array_aggregate(t)).min_w, (long_array_aggregate(t)).max_w, (long_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devlong as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Long 64 attributes +CREATE MATERIALIZED VIEW cagg_array_devlong64_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (long64_array_aggregate(t)).count, (long64_array_aggregate(t)).count_errors + , (long64_array_aggregate(t)).count_r, (long64_array_aggregate(t)).avg_r::float8[], (long64_array_aggregate(t)).min_r, (long64_array_aggregate(t)).max_r, (long64_array_aggregate(t)).stddev_r::float8[] + , (long64_array_aggregate(t)).count_w, (long64_array_aggregate(t)).avg_w::float8[], (long64_array_aggregate(t)).min_w, (long64_array_aggregate(t)).max_w, (long64_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devlong64 as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devlong64_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (long64_array_aggregate(t)).count, (long64_array_aggregate(t)).count_errors + , (long64_array_aggregate(t)).count_r, (long64_array_aggregate(t)).avg_r::float8[], (long64_array_aggregate(t)).min_r, (long64_array_aggregate(t)).max_r, (long64_array_aggregate(t)).stddev_r::float8[] + , (long64_array_aggregate(t)).count_w, (long64_array_aggregate(t)).avg_w::float8[], (long64_array_aggregate(t)).min_w, (long64_array_aggregate(t)).max_w, (long64_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devlong64 as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devlong64_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (long64_array_aggregate(t)).count, (long64_array_aggregate(t)).count_errors + , (long64_array_aggregate(t)).count_r, (long64_array_aggregate(t)).avg_r::float8[], (long64_array_aggregate(t)).min_r, (long64_array_aggregate(t)).max_r, (long64_array_aggregate(t)).stddev_r::float8[] + , (long64_array_aggregate(t)).count_w, (long64_array_aggregate(t)).avg_w::float8[], (long64_array_aggregate(t)).min_w, (long64_array_aggregate(t)).max_w, (long64_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devlong64 as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Short attributes +CREATE MATERIALIZED VIEW cagg_array_devshort_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (short_array_aggregate(t)).count, (short_array_aggregate(t)).count_errors + , (short_array_aggregate(t)).count_r, (short_array_aggregate(t)).avg_r::float8[], (short_array_aggregate(t)).min_r, (short_array_aggregate(t)).max_r, (short_array_aggregate(t)).stddev_r::float8[] + , (short_array_aggregate(t)).count_w, (short_array_aggregate(t)).avg_w::float8[], (short_array_aggregate(t)).min_w, (short_array_aggregate(t)).max_w, (short_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devshort as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devshort_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (short_array_aggregate(t)).count, (short_array_aggregate(t)).count_errors + , (short_array_aggregate(t)).count_r, (short_array_aggregate(t)).avg_r::float8[], (short_array_aggregate(t)).min_r, (short_array_aggregate(t)).max_r, (short_array_aggregate(t)).stddev_r::float8[] + , (short_array_aggregate(t)).count_w, (short_array_aggregate(t)).avg_w::float8[], (short_array_aggregate(t)).min_w, (short_array_aggregate(t)).max_w, (short_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devshort as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devshort_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (short_array_aggregate(t)).count, (short_array_aggregate(t)).count_errors + , (short_array_aggregate(t)).count_r, (short_array_aggregate(t)).avg_r::float8[], (short_array_aggregate(t)).min_r, (short_array_aggregate(t)).max_r, (short_array_aggregate(t)).stddev_r::float8[] + , (short_array_aggregate(t)).count_w, (short_array_aggregate(t)).avg_w::float8[], (short_array_aggregate(t)).min_w, (short_array_aggregate(t)).max_w, (short_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devshort as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Unsigned long attributes +CREATE MATERIALIZED VIEW cagg_array_devulong_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (ulong_array_aggregate(t)).count, (ulong_array_aggregate(t)).count_errors + , (ulong_array_aggregate(t)).count_r, (ulong_array_aggregate(t)).avg_r::float8[], (ulong_array_aggregate(t)).min_r, (ulong_array_aggregate(t)).max_r, (ulong_array_aggregate(t)).stddev_r::float8[] + , (ulong_array_aggregate(t)).count_w, (ulong_array_aggregate(t)).avg_w::float8[], (ulong_array_aggregate(t)).min_w, (ulong_array_aggregate(t)).max_w, (ulong_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devulong as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devulong_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (ulong_array_aggregate(t)).count, (ulong_array_aggregate(t)).count_errors + , (ulong_array_aggregate(t)).count_r, (ulong_array_aggregate(t)).avg_r::float8[], (ulong_array_aggregate(t)).min_r, (ulong_array_aggregate(t)).max_r, (ulong_array_aggregate(t)).stddev_r::float8[] + , (ulong_array_aggregate(t)).count_w, (ulong_array_aggregate(t)).avg_w::float8[], (ulong_array_aggregate(t)).min_w, (ulong_array_aggregate(t)).max_w, (ulong_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devulong as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devulong_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (ulong_array_aggregate(t)).count, (ulong_array_aggregate(t)).count_errors + , (ulong_array_aggregate(t)).count_r, (ulong_array_aggregate(t)).avg_r::float8[], (ulong_array_aggregate(t)).min_r, (ulong_array_aggregate(t)).max_r, (ulong_array_aggregate(t)).stddev_r::float8[] + , (ulong_array_aggregate(t)).count_w, (ulong_array_aggregate(t)).avg_w::float8[], (ulong_array_aggregate(t)).min_w, (ulong_array_aggregate(t)).max_w, (ulong_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devulong as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Unsigned long 64 attributes +CREATE MATERIALIZED VIEW cagg_array_devulong64_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (ulong64_array_aggregate(t)).count, (ulong64_array_aggregate(t)).count_errors + , (ulong64_array_aggregate(t)).count_r, (ulong64_array_aggregate(t)).avg_r::float8[], (ulong64_array_aggregate(t)).min_r, (ulong64_array_aggregate(t)).max_r, (ulong64_array_aggregate(t)).stddev_r::float8[] + , (ulong64_array_aggregate(t)).count_w, (ulong64_array_aggregate(t)).avg_w::float8[], (ulong64_array_aggregate(t)).min_w, (ulong64_array_aggregate(t)).max_w, (ulong64_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devulong64 as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devulong64_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (ulong64_array_aggregate(t)).count, (ulong64_array_aggregate(t)).count_errors + , (ulong64_array_aggregate(t)).count_r, (ulong64_array_aggregate(t)).avg_r::float8[], (ulong64_array_aggregate(t)).min_r, (ulong64_array_aggregate(t)).max_r, (ulong64_array_aggregate(t)).stddev_r::float8[] + , (ulong64_array_aggregate(t)).count_w, (ulong64_array_aggregate(t)).avg_w::float8[], (ulong64_array_aggregate(t)).min_w, (ulong64_array_aggregate(t)).max_w, (ulong64_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devulong64 as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devulong64_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (ulong64_array_aggregate(t)).count, (ulong64_array_aggregate(t)).count_errors + , (ulong64_array_aggregate(t)).count_r, (ulong64_array_aggregate(t)).avg_r::float8[], (ulong64_array_aggregate(t)).min_r, (ulong64_array_aggregate(t)).max_r, (ulong64_array_aggregate(t)).stddev_r::float8[] + , (ulong64_array_aggregate(t)).count_w, (ulong64_array_aggregate(t)).avg_w::float8[], (ulong64_array_aggregate(t)).min_w, (ulong64_array_aggregate(t)).max_w, (ulong64_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devulong64 as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Unsigned short attributes +CREATE MATERIALIZED VIEW cagg_array_devushort_1hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 hour', data_time), (ushort_array_aggregate(t)).count, (ushort_array_aggregate(t)).count_errors + , (ushort_array_aggregate(t)).count_r, (ushort_array_aggregate(t)).avg_r::float8[], (ushort_array_aggregate(t)).min_r, (ushort_array_aggregate(t)).max_r, (ushort_array_aggregate(t)).stddev_r::float8[] + , (ushort_array_aggregate(t)).count_w, (ushort_array_aggregate(t)).avg_w::float8[], (ushort_array_aggregate(t)).min_w, (ushort_array_aggregate(t)).max_w, (ushort_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devushort as t + GROUP BY time_bucket('1 hour', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devushort_8hour( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('8 hours', data_time), (ushort_array_aggregate(t)).count, (ushort_array_aggregate(t)).count_errors + , (ushort_array_aggregate(t)).count_r, (ushort_array_aggregate(t)).avg_r::float8[], (ushort_array_aggregate(t)).min_r, (ushort_array_aggregate(t)).max_r, (ushort_array_aggregate(t)).stddev_r::float8[] + , (ushort_array_aggregate(t)).count_w, (ushort_array_aggregate(t)).avg_w::float8[], (ushort_array_aggregate(t)).min_w, (ushort_array_aggregate(t)).max_w, (ushort_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devushort as t + GROUP BY time_bucket('8 hours', data_time), att_conf_id; + +CREATE MATERIALIZED VIEW cagg_array_devushort_1day( + att_conf_id, data_time, count_rows, count_errors + , count_r, mean_r, min_r, max_r, stddev_r + , count_w, mean_w, min_w, max_w, stddev_w + ) WITH (timescaledb.continuous) + AS SELECT att_conf_id, time_bucket('1 day', data_time), (ushort_array_aggregate(t)).count, (ushort_array_aggregate(t)).count_errors + , (ushort_array_aggregate(t)).count_r, (ushort_array_aggregate(t)).avg_r::float8[], (ushort_array_aggregate(t)).min_r, (ushort_array_aggregate(t)).max_r, (ushort_array_aggregate(t)).stddev_r::float8[] + , (ushort_array_aggregate(t)).count_w, (ushort_array_aggregate(t)).avg_w::float8[], (ushort_array_aggregate(t)).min_w, (ushort_array_aggregate(t)).max_w, (ushort_array_aggregate(t)).stddev_w::float8[] + FROM att_array_devushort as t + GROUP BY time_bucket('1 day', data_time), att_conf_id; + +-- Drop all the views +-- DROP VIEW cagg_array_devdouble_1hour CASCADE; +-- DROP VIEW cagg_array_devdouble_8hour CASCADE; +-- DROP VIEW cagg_array_devdouble_1day CASCADE; + +-- DROP VIEW cagg_array_devfloat_1hour CASCADE; +-- DROP VIEW cagg_array_devfloat_8hour CASCADE; +-- DROP VIEW cagg_array_devfloat_1day CASCADE; + +-- DROP VIEW cagg_array_devlong_1hour CASCADE; +-- DROP VIEW cagg_array_devlong_8hour CASCADE; +-- DROP VIEW cagg_array_devlong_1day CASCADE; + +-- DROP VIEW cagg_array_devlong64_1hour CASCADE; +-- DROP VIEW cagg_array_devlong64_8hour CASCADE; +-- DROP VIEW cagg_array_devlong64_1day CASCADE; + +-- DROP VIEW cagg_array_devshort_1hour CASCADE; +-- DROP VIEW cagg_array_devshort_8hour CASCADE; +-- DROP VIEW cagg_array_devshort_1day CASCADE; + +-- DROP VIEW cagg_array_devulong_1hour CASCADE; +-- DROP VIEW cagg_array_devulong_8hour CASCADE; +-- DROP VIEW cagg_array_devulong_1day CASCADE; + +-- DROP VIEW cagg_array_devulong64_1hour CASCADE; +-- DROP VIEW cagg_array_devulong64_8hour CASCADE; +-- DROP VIEW cagg_array_devulong64_1day CASCADE; + +-- DROP VIEW cagg_array_devushort_1hour CASCADE; +-- DROP VIEW cagg_array_devushort_8hour CASCADE; +-- DROP VIEW cagg_array_devushort_1day CASCADE; + diff --git a/docker-compose/timescaledb/resources/08_hdb_ext_compress_policy.sql b/docker-compose/timescaledb/resources/08_hdb_ext_compress_policy.sql new file mode 100644 index 0000000000000000000000000000000000000000..a815950e82b9d88d6e992fda23e8e3a5d5b84a26 --- /dev/null +++ b/docker-compose/timescaledb/resources/08_hdb_ext_compress_policy.sql @@ -0,0 +1,118 @@ +-- ----------------------------------------------------------------------------- +-- This file is part of the hdbpp-timescale-project +-- +-- Copyright (C) : 2014-2019 +-- European Synchrotron Radiation Facility +-- BP 220, Grenoble 38043, FRANCE +-- +-- libhdb++timescale is free software: you can redistribute it and/or modify +-- it under the terms of the Lesser GNU General Public License as published by +-- the Free Software Foundation, either version 3 of the License, or +-- (at your option) any later version. +-- +-- libhdb++timescale is distributed in the hope that it will be useful, +-- but WITHOUT ANY WARRANTY; without even the implied warranty of +-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser +-- GNU General Public License for more details. +-- +-- You should have received a copy of the Lesser GNU General Public License +-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>. +-- ----------------------------------------------------------------------------- +\c hdb +-- Compress chunk policy +-- Allow compression on the table +ALTER TABLE att_scalar_devboolean SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devdouble SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devfloat SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devencoded SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devenum SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devstate SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devstring SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devuchar SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devulong SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devulong64 SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devlong64 SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devlong SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devushort SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_scalar_devshort SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); + +ALTER TABLE att_array_devboolean SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devdouble SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devfloat SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devencoded SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devenum SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devstate SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devstring SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devuchar SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devulong SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devulong64 SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devlong64 SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devlong SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devushort SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); +ALTER TABLE att_array_devshort SET(timescaledb.compress, timescaledb.compress_segmentby = 'att_conf_id, att_error_desc_id', timescaledb.compress_orderby = 'data_time DESC'); + +DO $$ BEGIN + IF (SELECT extversion>'2.0.0' FROM pg_extension where extname = 'timescaledb') THEN + -- If using timescaledb v2 + PERFORM add_compression_policy('att_scalar_devboolean', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devdouble', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devfloat', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devencoded', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devenum', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devstate', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devstring', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devuchar', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devulong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devulong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devlong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devlong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devushort', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_scalar_devshort', INTERVAL '200d', if_not_exists => true); + + PERFORM add_compression_policy('att_array_devboolean', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devdouble', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devfloat', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devencoded', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devenum', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devstate', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devstring', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devuchar', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devulong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devulong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devlong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devlong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devushort', INTERVAL '200d', if_not_exists => true); + PERFORM add_compression_policy('att_array_devshort', INTERVAL '200d', if_not_exists => true); + ELSE + -- If using timescaledb v1.7 + PERFORM add_compress_chunks_policy('att_scalar_devboolean', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devdouble', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devfloat', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devencoded', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devenum', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devstate', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devstring', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devuchar', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devulong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devulong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devlong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devlong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devushort', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_scalar_devshort', INTERVAL '200d', if_not_exists => true); + + PERFORM add_compress_chunks_policy('att_array_devboolean', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devdouble', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devfloat', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devencoded', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devenum', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devstate', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devstring', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devuchar', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devulong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devulong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devlong64', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devlong', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devushort', INTERVAL '200d', if_not_exists => true); + PERFORM add_compress_chunks_policy('att_array_devshort', INTERVAL '200d', if_not_exists => true); + END IF; +END $$; diff --git a/docker-compose/timescaledb/resources/09_hdb_ext_import.sql b/docker-compose/timescaledb/resources/09_hdb_ext_import.sql new file mode 100644 index 0000000000000000000000000000000000000000..f08cc3610df1a96bb207eef24fca29e274c8e5d7 --- /dev/null +++ b/docker-compose/timescaledb/resources/09_hdb_ext_import.sql @@ -0,0 +1,19 @@ +\c hdb + +CREATE OR REPLACE FUNCTION expand_name() RETURNS TRIGGER AS $$ +DECLARE + len integer; +BEGIN + IF (NEW.cs_name <> '' AND NEW.domain <> '' AND NEW.family <> '' AND NEW.member <> '' AND NEW.name <> '') IS NOT TRUE THEN + len = (SELECT cardinality((SELECT regexp_split_to_array(NEW.att_name, E'/')))); + NEW.name := (SELECT split_part(NEW.att_name, '/', len)); + NEW.member := (SELECT split_part(NEW.att_name, '/', len - 1)); + NEW.family := (SELECT split_part(NEW.att_name, '/', len - 2)); + NEW.domain := (SELECT split_part(NEW.att_name, '/', len - 3)); + NEW.cs_name := (SELECT split_part(NEW.att_name, '/', len - 4)); + END IF; + RETURN NEW; +END +$$ LANGUAGE plpgsql; + +CREATE TRIGGER expand_name_trigger BEFORE INSERT ON att_conf FOR EACH ROW EXECUTE PROCEDURE expand_name(); diff --git a/docker-compose/timescaledb/resources/10_hdb_ext_reorder_policy.sql b/docker-compose/timescaledb/resources/10_hdb_ext_reorder_policy.sql new file mode 100644 index 0000000000000000000000000000000000000000..e8e0f3911b6945159945d8e9b0caafeaad1741e1 --- /dev/null +++ b/docker-compose/timescaledb/resources/10_hdb_ext_reorder_policy.sql @@ -0,0 +1,53 @@ +-- ----------------------------------------------------------------------------- +-- This file is part of the hdbpp-timescale-project +-- +-- Copyright (C) : 2014-2019 +-- European Synchrotron Radiation Facility +-- BP 220, Grenoble 38043, FRANCE +-- +-- libhdb++timescale is free software: you can redistribute it and/or modify +-- it under the terms of the Lesser GNU General Public License as published by +-- the Free Software Foundation, either version 3 of the License, or +-- (at your option) any later version. +-- +-- libhdb++timescale is distributed in the hope that it will be useful, +-- but WITHOUT ANY WARRANTY; without even the implied warranty of +-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser +-- GNU General Public License for more details. +-- +-- You should have received a copy of the Lesser GNU General Public License +-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>. +-- ----------------------------------------------------------------------------- + +\c hdb +-- Reorder chunk policy + +SELECT add_reorder_policy('att_scalar_devboolean', 'att_scalar_devboolean_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devdouble', 'att_scalar_devdouble_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devfloat', 'att_scalar_devfloat_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devencoded', 'att_scalar_devencoded_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devenum', 'att_scalar_devenum_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devstate', 'att_scalar_devstate_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devstring', 'att_scalar_devstring_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devuchar', 'att_scalar_devuchar_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devulong', 'att_scalar_devulong_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devulong64', 'att_scalar_devulong64_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devlong64', 'att_scalar_devlong64_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devlong', 'att_scalar_devlong_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devushort', 'att_scalar_devushort_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_scalar_devshort', 'att_scalar_devshort_att_conf_id_data_time_idx', if_not_exists => true); + +SELECT add_reorder_policy('att_array_devboolean', 'att_array_devboolean_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devdouble', 'att_array_devdouble_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devfloat', 'att_array_devfloat_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devencoded', 'att_array_devencoded_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devenum', 'att_array_devenum_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devstate', 'att_array_devstate_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devstring', 'att_array_devstring_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devuchar', 'att_array_devuchar_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devulong', 'att_array_devulong_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devulong64', 'att_array_devulong64_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devlong64', 'att_array_devlong64_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devlong', 'att_array_devlong_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devushort', 'att_array_devushort_att_conf_id_data_time_idx', if_not_exists => true); +SELECT add_reorder_policy('att_array_devshort', 'att_array_devshort_att_conf_id_data_time_idx', if_not_exists => true); diff --git a/docker-compose/timescaledb/resources/05_lofar_func.sh b/docker-compose/timescaledb/resources/11_lofar_func.sh similarity index 100% rename from docker-compose/timescaledb/resources/05_lofar_func.sh rename to docker-compose/timescaledb/resources/11_lofar_func.sh diff --git a/docker-compose/timescaledb/resources/06_lofar_views.sql b/docker-compose/timescaledb/resources/12_lofar_views.sql similarity index 100% rename from docker-compose/timescaledb/resources/06_lofar_views.sql rename to docker-compose/timescaledb/resources/12_lofar_views.sql diff --git a/docker-compose/timescaledb/resources/07_cleanup.sql b/docker-compose/timescaledb/resources/13_cleanup.sql similarity index 100% rename from docker-compose/timescaledb/resources/07_cleanup.sql rename to docker-compose/timescaledb/resources/13_cleanup.sql