Examples: FILL with a Constant Value - Analytics Database - Teradata Vantage

Time Series Tables and Operations

Deployment
VantageCloud
VantageCore
Edition
Enterprise
IntelliFlex
VMware
Product
Analytics Database
Teradata Vantage
Release Number
17.20
Published
June 2022
Language
English (United States)
Last Update
2023-10-30
dita:mapPath
tuc1628112453431.ditamap
dita:ditavalPath
qkf1628213546010.ditaval
dita:id
sfz1493079039055
lifecycle
latest
Product Category
Teradata Vantageā„¢

Use the FILL clause to replace missing values with a constant value for timebuckets with missing values. The data type of the constant must be compatible with the data type of the data being aggregated.

Example: Invalid Case: Fill with an Incompatible Constant Value

In the example the data type of the constant is incompatible with the data type of the data being aggregated, in this case TEMPERATURE:

SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, AVG(TEMPERATURE)
FROM OCEAN_BUOYS
WHERE TD_TIMECODE BETWEEN TIMESTAMP '2014-01-06 09:45:00' AND TIMESTAMP '2014-01-06 11:45:00'
AND BUOYID=44
GROUP BY TIME (MINUTES(15) AND BUOYID) FILL('a')
ORDER BY 2,3;

Result:

*** Failure 3706 Data type specified in FILL clause is incompatible with input data types to some aggregate functions.

Example: Fill with a Constant Value

The example shows a query when the FILL clause is used with a constant value with a compatible data type:

SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, AVG(TEMPERATURE)
FROM OCEAN_BUOYS
WHERE TD_TIMECODE BETWEEN TIMESTAMP '2014-01-06 09:45:00' AND TIMESTAMP '2014-01-06 11:45:00'
AND BUOYID=44
GROUP BY TIME (MINUTES(15) AND BUOYID) FILL(45)
ORDER BY 2,3;

Result: The timebuckets with no value are included in the result set with the specified constant value returned in place of the missing values.

TIMECODE_RANGE GROUP BY TIME(MINUTES(15)) BUOYID AVG(TEMPERATURE)
('2014-01-06 09:45:00.000000+00:00', '2014-01-06 10:00:00.000000+00:00') 1 44 45
('2014-01-06 10:00:00.000000+00:00', '2014-01-06 10:15:00.000000+00:00') 2 44 49
('2014-01-06 10:15:00.000000+00:00', '2014-01-06 10:30:00.000000+00:00') 3 44 45
('2014-01-06 10:30:00.000000+00:00', '2014-01-06 10:45:00.000000+00:00') 4 44 43
('2014-01-06 10:45:00.000000+00:00', '2014-01-06 11:00:00.000000+00:00') 5 44 43
('2014-01-06 11:00:00.000000+00:00', '2014-01-06 11:15:00.000000+00:00') 6 44 45
('2014-01-06 11:15:00.000000+00:00', '2014-01-06 11:30:00.000000+00:00') 7 44 45
('2014-01-06 11:30:00.000000+00:00', '2014-01-06 11:45:00.000000+00:00') 8 44 45