Median Absolute Deviation (MAD) Examples | Teradata Vantage - Examples - 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ā„¢

Example: Finding the Median Absolute Deviation

/*PTI Table*/
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, MAD(1, TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS
WHERE TD_TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
GROUP BY TIME (MINUTES(30) AND BUOYID)
ORDER BY 3,2,1;

/*Non-PTI Table*/
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, MAD(1, TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS_NONPTI
WHERE TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
GROUP BY TIME (MINUTES(30) AND BUOYID)
USING TIMECODE(TIMECODE)
ORDER BY 3,2,1;

The results are the same for both tables:

TIMECODE_ RANGE GROUP BY TIME (MINUTES(10)) BUOYID Mad(1, TEMPERATURE) Count(*)
('2014-01-06 08:00:00.000000+00:00', '2014-01-06 08:30:00.000000+00:00') 1 0 4.45000000000000E 001 5
('2014-01-06 09:00:00.000000+00:00', '2014-01-06 09:30:00.000000+00:00') 3 1 3.50000000000000E 000 6
('2014-01-06 10:00:00.000000+00:00', '2014-01-06 10:30:00.000000+00:00') 5 44 3.00000000000000E 000 11

Example: Reporting Groups of Two or More with An Odd Number of Values

/*PTI Table*/
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, MAD(1, TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS
WHERE TD_TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
GROUP BY TIME (MINUTES(30) AND BUOYID)
HAVING COUNT(*) MOD 2 = 1 AND COUNT(*) > 2
ORDER BY 3,2,1;

/*Non-PTI Table*/
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, MAD(1, TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS_NONPTI
WHERE TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
GROUP BY TIME (MINUTES(30) AND BUOYID)
USING TIMECODE(TIMECODE)
HAVING COUNT(*) MOD 2 = 1 AND COUNT(*) > 2
ORDER BY 3,2,1;

The results are the same for both tables:

TIMECODE_ RANGE GROUP BY TIME (MINUTES(10)) BUOYID Mad(1, TEMPERATURE) Count(*)
('2014-01-06 08:00:00.000000+00:00', '2014-01-06 08:30:00.000000+00:00') 1 0 4.45000000000000E 001 50
('2014-01-06 10:00:00.000000+00:00', '2014-01-06 10:30:00.000000+00:00') 5 44 3.00000000000000E 000 11

Example: Using the Default Constant Multiplier

/*PTI Table*/
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, MAD(TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS
WHERE TD_TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
GROUP BY TIME (MINUTES(30) AND BUOYID)
ORDER BY 3,2,1;

/*Non-PTI Table*/
SELECT $TD_TIMECODE_RANGE, $TD_GROUP_BY_TIME, BUOYID, MAD(TEMPERATURE), COUNT(*)
FROM OCEAN_BUOYS_NONPTI
WHERE TIMECODE BETWEEN TIMESTAMP '2014-01-06 08:00:00' AND TIMESTAMP '2014-01-06 10:30:00'
GROUP BY TIME (MINUTES(30) AND BUOYID)
USING TIMECODE(TIMECODE)
ORDER BY 3,2,1;

The results are the same for both tables:

TIMECODE_RANGE GROUP BY TIME (MINUTES(10)) BUOYID Mad(1.4826, TEMPERATURE) Count(*)
('2014-01-06 08:00:00.000000+00:00', '2014-01-06 08:30:00.000000+00:00') 1 0 6.59757000000000E 001 5
('2014-01-06 09:00:00.000000+00:00', '2014-01-06 09:30:00.000000+00:00') 3 1 5.18910000000000E 000 6
('2014-01-06 10:00:00.000000+00:00', '2014-01-06 10:30:00.000000+00:00') 5 44 4.44780000000000E 000 11