PARTITION BY Phrase - 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ā„¢

PARTITION BY takes a column reference list and groups the rows based on the specified column reference list over which the ordered analytical function executes. Such a grouping is static. To define a group or partition based on a condition, use the RESET WHEN phrase. For more information, see RESET WHEN Phrase.

If there is no PARTITION BY phrase or RESET WHEN phrase, then the entire result set, delivered by the FROM clause, constitutes a single partition, over which the ordered analytical function executes.

Consider the following table named sales_tbl.

StoreID SMonth ProdID Sales
1001 1 C 35000.00
1001 2 C 25000.00
1001 3 C 40000.00
1001 4 C 25000.00
1001 5 C 30000.00
1001 6 C 30000.00
1002 1 C 40000.00
1002 2 C 35000.00
1002 3 C 110000.00
1002 4 C 60000.00
1002 5 C 35000.00
1002 6 C 100000.00

The following SELECT statement, which does not include PARTITION BY, computes the average sales for all the stores in the table:

   SELECT StoreID, SMonth, ProdID, Sales, 
   AVG(Sales) OVER () 
   FROM sales_tbl;

Result:

   StoreID  SMonth  ProdID      Sales  Group Avg(Sales)
   -------  ------  ------  ---------  ----------------
      1001       1  C        35000.00          47083.33
      1001       2  C        25000.00          47083.33
      1001       3  C        40000.00          47083.33
      1001       4  C        25000.00          47083.33
      1001       5  C        30000.00          47083.33
      1001       6  C        30000.00          47083.33
      1002       1  C        40000.00          47083.33
      1002       2  C        35000.00          47083.33
      1002       3  C       110000.00          47083.33
      1002       4  C        60000.00          47083.33
      1002       5  C        35000.00          47083.33
      1002       6  C       100000.00          47083.33

To compute the average sales for each store, partition the data in sales_tbl by StoreID:

   SELECT StoreID, SMonth, ProdID, Sales, 
   AVG(Sales) OVER (PARTITION BY StoreID)
   FROM sales_tbl;

Result:

   StoreID  SMonth  ProdID      Sales  Group Avg(Sales)
   -------  ------  ------  ---------  ----------------
      1001       3  C        40000.00          30833.33
      1001       5  C        30000.00          30833.33
      1001       6  C        30000.00          30833.33
      1001       4  C        25000.00          30833.33
      1001       2  C        25000.00          30833.33
      1001       1  C        35000.00          30833.33
      1002       3  C       110000.00          63333.33
      1002       5  C        35000.00          63333.33
      1002       6  C       100000.00          63333.33
      1002       4  C        60000.00          63333.33
      1002       2  C        35000.00          63333.33
      1002       1  C        40000.00          63333.33