Computation Sort Order and Result Order - Analytics Database - Teradata Vantage

SQL Functions, Expressions, and Predicates

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
2024-01-12
dita:mapPath
obm1628111499646.ditamap
dita:ditavalPath
qkf1628213546010.ditaval
dita:id
kby1472250656485
lifecycle
latest
Product Category
Teradata Vantageā„¢

The sort order that you specify in the window specification defines the sort order of the rows over which the function is applied; it does not define the ordering of the results.

For example, to compute the average sales for the months following the current month, order the rows by month:

   SELECT StoreID, SMonth, ProdID, Sales,
   AVG(Sales) OVER (PARTITION BY StoreID ORDER BY SMonth
                    ROWS BETWEEN 1 FOLLOWING AND UNBOUNDED FOLLOWING)
   FROM sales_tbl;

Result:

   StoreID  SMonth  ProdID      Sales  Remaining Avg(Sales)
   -------  ------  ------  ---------  --------------------
      1001       6  C        30000.00                     ?
      1001       5  C        30000.00              30000.00
      1001       4  C        25000.00              30000.00
      1001       3  C        40000.00              28333.33
      1001       2  C        25000.00              31250.00
      1001       1  C        35000.00              30000.00

The default sort order is ASC for the computation. However, the results are returned in the reverse order.

To order the results, use an ORDER BY phrase in the SELECT statement. For example:

   SELECT StoreID, SMonth, ProdID, Sales,
   AVG(Sales) OVER (PARTITION BY StoreID ORDER BY SMonth
                    ROWS BETWEEN 1 FOLLOWING AND UNBOUNDED FOLLOWING)
   FROM sales_tbl
   ORDER BY SMonth;

Result:

   StoreID  SMonth  ProdID      Sales  Remaining Avg(Sales)
   -------  ------  ------  ---------  --------------------
      1001       1  C        35000.00              30000.00
      1001       2  C        25000.00              31250.00
      1001       3  C        40000.00              28333.33
      1001       4  C        25000.00              30000.00
      1001       5  C        30000.00              30000.00
      1001       6  C        30000.00                     ?