17.10 - Example - Advanced SQL Engine - Teradata Database

Teradata Vantage™ - SQL Operators and User-Defined Functions

Product
Advanced SQL Engine
Teradata Database
Release Number
17.10
Release Date
July 2021
Content Type
Administration
Programming Reference
Publication ID
B035-1210-171K
Language
English (United States)

Consider the following table definition and inserted data:

CREATE MULTISET TABLE t
   (id INTEGER,
    v  INTEGER);
INSERT INTO t VALUES (1,1);
INSERT INTO t VALUES (1,2);
INSERT INTO t VALUES (1,2);
INSERT INTO t VALUES (1,4);
INSERT INTO t VALUES (1,5);
INSERT INTO t VALUES (1,5);
INSERT INTO t VALUES (1,5);
INSERT INTO t VALUES (1,8);
INSERT INTO t VALUES (1,);

The following is the SQL definition of a window aggregate UDF that performs the dense rank operation:

REPLACE FUNCTION dense_rank (x INTEGER)
RETURNS INTEGER
CLASS AGGREGATE (1000)
LANGUAGE C
NO SQL
PARAMETER STYLE SQL
DETERMINISTIC
CALLED ON NULL INPUT
EXTERNAL;

The dense_rank UDF evaluates dense rank over the set of values passed as arguments to the UDF. With dense ranking, items that compare equal receive the same ranking number, and the next item(s) receive the immediately following ranking number. In the following query and result, note the difference in the rank and dense rank value for v=4. The dense rank value is 4 whereas the rank of 4 is 5.

SELECT v, dense_rank(v) OVER (PARTITION BY id ORDER BY v 
   ROWS UNBOUNDED PRECEDING) as dr,
   rank() OVER (PARTITION BY id ORDER BY v) as r
FROM t ORDER BY dr;

The output from the SELECT statement is:

          v           dr            r
-----------  -----------  -----------
          ?            1            1
          1            2            2
          2            3            3
          2            3            3
          4             4              5 
          5            5            6
          5            5            6
          5            5            6
          8            6            9

For a C code example of the dense_rank UDF, see Teradata Vantage™ - SQL External Routine Programming, B035-1147.