Option 3: Replace Missing Values with an Estimated Value - Advanced SQL Engine - Teradata Database

Time Series Tables and Operations

Product
Advanced SQL Engine
Teradata Database
Release Number
17.10
Published
July 2021
Language
English (United States)
Last Update
2021-07-28
dita:mapPath
zzg1600277315070.ditamap
dita:ditavalPath
zzg1600277315070.ditaval
dita:id
B035-1208
lifecycle
previous
Product Category
Teradata Vantageā„¢

You can estimate a value to update the rows with a missing value.

The value loaded can be the result of any function, including other aggregates.

The example shows this for the TEMPERATURE column in Table and Data Definition for Time Series Aggregates Examples. The example updates all missing values in each timebucket with the average of the present values:

Create table ocean_buoys2 as ocean_buoys with no data;
INSERT INTO OCEAN_BUOYS2 VALUES(TIMESTAMP '2014-01-06 08:00:00.000000', 0, 55, );
INSERT INTO OCEAN_BUOYS2 VALUES(TIMESTAMP '2014-01-06 08:09:59.999999', 0, 55, );
INSERT INTO OCEAN_BUOYS2 VALUES(TIMESTAMP '2014-01-06 09:01:25.122200', 1, 55, );
INSERT INTO OCEAN_BUOYS2 VALUES(TIMESTAMP '2014-01-06 09:02:25.122200', 1, 55, );
 
MERGE INTO OCEAN_BUOYS2
USING (SELECT TD_TIMECODE, BUOYID, Avg(TEMPERATURE) FROM OCEAN_BUOYS GROUP BY (TD_TIMECODE, BUOYID) WHERE TEMPERATURE IS NOT NULL) AS S(a,b,c)
ON TD_TIMECODE=S.a AND BUOYID=S.b AND TEMPERATURE IS NULL
WHEN MATCHED THEN UPDATE SET TEMPERATURE=S.c;
select * from ocean_buoys2 order by 1;

Result:

TIMECODE BUOYID SALINITY TEMPERATURE
2014-01-06 08:00:00.000000 0 55 10
2014-01-06 08:09:59.999999 0 55 99
2014-01-06 09:01:25.122200 1 55 73
2014-01-06 09:02:25.122200 1 55 74
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, AVG(TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS
WHERE TD_TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
AND BUOYID=0
GROUP BY TIME (MINUTES(10) AND BUOYID)
ORDER BY 2,3;

Result: Note the effect on the Average column.

TIMECODE_RANGE GROUP BY TIME(MINUTES(10)) BUOYID Average(TEMPERATURE) COUNT(*)
('2014-01-06 08:00:00.000000+00:00', '2014-01-06 08:10:00.000000+00:00') 1 0 54 3
('2014-01-06 08:10:00.000000+00:00', '2014-01-06 08:20:00.000000+00:00') 2 0 55 2