ERROR: only immutable functions supported in continuous aggregate view - Mailing list pgsql-general

From Martijn de Munnik
Subject ERROR: only immutable functions supported in continuous aggregate view
Date
Msg-id 0b21034b-3fa8-16b3-c65b-1ef6b67c4da2@protonmail.com
Whole thread Raw
Responses Re: ERROR: only immutable functions supported in continuous aggregate view  (Tom Lane <tgl@sss.pgh.pa.us>)
List pgsql-general
Hi List,


I'm trying to create a TimescaleDB continuous aggregate using the
following statement:

CREATE MATERIALIZED VIEW "navigation_data_5min_hidden" WITH
(timescaledb.continuous) AS
SELECT
   public.time_bucket(INTERVAL '5 min', "time") AS "time",
   "context",
   jsonb_build_object(
     'max', max("value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue'),
     'min', min("value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue'),
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.courseOverGroundTrue' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.courseOverGroundTrue' AND "value" IS NOT NULL),
     'average', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue')),
     'integral', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue')) * EXTRACT(EPOCH FROM INTERVAL '5 min'),
     'stddev', public.stddev(public.stats_agg("value"::double precision)
FILTER (WHERE "path" = 'navigation.courseOverGroundTrue')),
     'skewness', public.skewness(public.stats_agg("value"::double
precision) FILTER (WHERE "path" = 'navigation.courseOverGroundTrue')),
     'first_time', public.first_time(public.time_weight('Linear',
"time", "value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue')),
     'first_val', public.first_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue')),
     'last_time', public.last_time(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue')),
     'last_val', public.last_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.courseOverGroundTrue'))
   ) AS "navigation.courseOverGroundTrue",
   jsonb_build_object(
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.datetime' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.datetime' AND "value" IS NOT NULL),
     'first_time', public.first("time", "time") FILTER (WHERE "path" =
'navigation.datetime' AND "time" IS NOT NULL),
     'first_val', public.first("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.datetime' AND "time" IS NOT NULL),
     'last_time', public.last("time", "time") FILTER (WHERE "path" =
'navigation.datetime' AND "time" IS NOT NULL),
     'last_val', public.last("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.datetime' AND "time" IS NOT NULL)
   ) AS "navigation.datetime",
   jsonb_build_object(
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.gnss.methodQuality' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.gnss.methodQuality' AND "value" IS NOT NULL),
     'first_time', public.first("time", "time") FILTER (WHERE "path" =
'navigation.gnss.methodQuality' AND "time" IS NOT NULL),
     'first_val', public.first("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.gnss.methodQuality' AND "time" IS NOT NULL),
     'last_time', public.last("time", "time") FILTER (WHERE "path" =
'navigation.gnss.methodQuality' AND "time" IS NOT NULL),
     'last_val', public.last("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.gnss.methodQuality' AND "time" IS NOT NULL)
   ) AS "navigation.gnss.methodQuality",
   jsonb_build_object(
     'max', max("value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites'),
     'min', min("value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites'),
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.gnss.satellites' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.gnss.satellites' AND "value" IS NOT NULL),
     'average', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites')),
     'integral', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites')) * EXTRACT(EPOCH FROM INTERVAL '5 min'),
     'stddev', public.stddev(public.stats_agg("value"::double precision)
FILTER (WHERE "path" = 'navigation.gnss.satellites')),
     'skewness', public.skewness(public.stats_agg("value"::double
precision) FILTER (WHERE "path" = 'navigation.gnss.satellites')),
     'first_time', public.first_time(public.time_weight('Linear',
"time", "value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites')),
     'first_val', public.first_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites')),
     'last_time', public.last_time(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites')),
     'last_val', public.last_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.gnss.satellites'))
   ) AS "navigation.gnss.satellites",
   jsonb_build_object(
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.gnss.type' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.gnss.type' AND "value" IS NOT NULL),
     'first_time', public.first("time", "time") FILTER (WHERE "path" =
'navigation.gnss.type' AND "time" IS NOT NULL),
     'first_val', public.first("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.gnss.type' AND "time" IS NOT NULL),
     'last_time', public.last("time", "time") FILTER (WHERE "path" =
'navigation.gnss.type' AND "time" IS NOT NULL),
     'last_val', public.last("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.gnss.type' AND "time" IS NOT NULL)
   ) AS "navigation.gnss.type",
   jsonb_build_object(
     'max', max("value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue'),
     'min', min("value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue'),
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.headingTrue' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.headingTrue' AND "value" IS NOT NULL),
     'average', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue')),
     'integral', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue')) * EXTRACT(EPOCH FROM INTERVAL '5 min'),
     'stddev', public.stddev(public.stats_agg("value"::double precision)
FILTER (WHERE "path" = 'navigation.headingTrue')),
     'skewness', public.skewness(public.stats_agg("value"::double
precision) FILTER (WHERE "path" = 'navigation.headingTrue')),
     'first_time', public.first_time(public.time_weight('Linear',
"time", "value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue')),
     'first_val', public.first_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue')),
     'last_time', public.last_time(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.headingTrue')),
     'last_val', public.last_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" = 'navigation.headingTrue'))
   ) AS "navigation.headingTrue",
   jsonb_build_object(
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.position' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.position' AND "value" IS NOT NULL),
     'first_time', public.first("time", "time") FILTER (WHERE "path" =
'navigation.position' AND "time" IS NOT NULL),
     'first_val', public.first("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.position' AND "time" IS NOT NULL),
     'last_time', public.last("time", "time") FILTER (WHERE "path" =
'navigation.position' AND "time" IS NOT NULL),
     'last_val', public.last("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.position' AND "time" IS NOT NULL)
   ) AS "navigation.position",
   jsonb_build_object(
     'max', max("value"::double precision) FILTER (WHERE "path" =
'navigation.rateOfTurn'),
     'min', min("value"::double precision) FILTER (WHERE "path" =
'navigation.rateOfTurn'),
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.rateOfTurn' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.rateOfTurn' AND "value" IS NOT NULL),
     'average', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" = 'navigation.rateOfTurn')),
     'integral', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.rateOfTurn')) * EXTRACT(EPOCH FROM INTERVAL '5 min'),
     'stddev', public.stddev(public.stats_agg("value"::double precision)
FILTER (WHERE "path" = 'navigation.rateOfTurn')),
     'skewness', public.skewness(public.stats_agg("value"::double
precision) FILTER (WHERE "path" = 'navigation.rateOfTurn')),
     'first_time', public.first_time(public.time_weight('Linear',
"time", "value"::double precision) FILTER (WHERE "path" =
'navigation.rateOfTurn')),
     'first_val', public.first_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" = 'navigation.rateOfTurn')),
     'last_time', public.last_time(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" = 'navigation.rateOfTurn')),
     'last_val', public.last_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" = 'navigation.rateOfTurn'))
   ) AS "navigation.rateOfTurn",
   jsonb_build_object(
     'max', max("value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround'),
     'min', min("value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround'),
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.speedOverGround' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.speedOverGround' AND "value" IS NOT NULL),
     'average', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround')),
     'integral', public.average(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround')) * EXTRACT(EPOCH FROM INTERVAL '5 min'),
     'stddev', public.stddev(public.stats_agg("value"::double precision)
FILTER (WHERE "path" = 'navigation.speedOverGround')),
     'skewness', public.skewness(public.stats_agg("value"::double
precision) FILTER (WHERE "path" = 'navigation.speedOverGround')),
     'first_time', public.first_time(public.time_weight('Linear',
"time", "value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround')),
     'first_val', public.first_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround')),
     'last_time', public.last_time(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround')),
     'last_val', public.last_val(public.time_weight('Linear', "time",
"value"::double precision) FILTER (WHERE "path" =
'navigation.speedOverGround'))
   ) AS "navigation.speedOverGround",
   jsonb_build_object(
     'mode', mode() WITHIN GROUP (ORDER BY "value") FILTER (WHERE "path"
= 'navigation.state' AND "value" IS NOT NULL),
     'cardinality', COUNT(DISTINCT "value") FILTER (WHERE "path" =
'navigation.state' AND "value" IS NOT NULL),
     'first_time', public.first("time", "time") FILTER (WHERE "path" =
'navigation.state' AND "time" IS NOT NULL),
     'first_val', public.first("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.state' AND "time" IS NOT NULL),
     'last_time', public.last("time", "time") FILTER (WHERE "path" =
'navigation.state' AND "time" IS NOT NULL),
     'last_val', public.last("value"#>>'{}', "time") FILTER (WHERE
"path" = 'navigation.state' AND "time" IS NOT NULL)
   ) AS "navigation.state"
FROM
     "gosk"."mapped_data"
WHERE
     "path" IN (
         'navigation.courseOverGroundTrue',
         'navigation.datetime',
         'navigation.gnss.methodQuality',
         'navigation.gnss.satellites',
         'navigation.gnss.type',
         'navigation.headingTrue',
         'navigation.position',
         'navigation.rateOfTurn',
         'navigation.speedOverGround',
         'navigation.state'
     )
GROUP BY
     1, 2
WITH NO DATA;

And that results in an error:

ERROR:  only immutable functions supported in continuous aggregate view
HINT:  Make sure all functions in the continuous aggregate definition
have IMMUTABLE volatility. Note that functions or expressions may be
IMMUTABLE for one data type, but STABLE or VOLATILE for another.

The error is caused by the jsonb_build_object function, is there any
reason why this function is not IMMUTABLE? I would have expected it to
be IMMUTABLE.


Kind regards,

Martijn de Munnik





pgsql-general by date:

Previous
From: Ben Clements
Date:
Subject: Idea: Add first() and last() aggregate functions to the main release
Next
From: Tom Lane
Date:
Subject: Re: ERROR: only immutable functions supported in continuous aggregate view