There are two types of analytical functions: rank and inverse distribution. The rank analytical functions rank items in a group, compute distribution, and divide a result set into a number of groupings. The inverse distribution analytical functions return a k-th percentile value, which can be used to help establish a threshold acceptance value for a set of data.
The rank analytical functions are RANK, DENSE_RANK, PERCENT_RANK, and NTILE. The inverse distribution analytical functions are PERCENTILE_CONT and PERCENTILE_DISC.
Table 5-11 lists the analytical functions and their parameters.
Analytical function |
Parameters |
---|---|
DENSE_RANK |
() |
NTILE |
( integer ) |
PERCENT_RANK |
() |
PERCENTILE_CONT |
( numeric-expr ) |
PERCENTILE_DISC |
( numeric-expr ) |
RANK |
() |
The rank analytical functions RANK, DENSE_RANK, PERCENT_RANK, and NTILE all require an OVER (ORDER BY) clause. For example:
RANK() OVER ( ORDER BY <expression> [ ASC | DESC ] )
The ORDER BY clause specifies the parameter on which ranking is performed and the order in which the rows are sorted in each group. Note that this ORDER BY clause is used only within the OVER clause and is not an ORDER BY for the SELECT. No aggregation functions in the rank query are allowed to specify DISTINCT.
The OVER clause indicates that the function operates on a query result set. The result set is the rows that are returned after the FROM, WHERE, GROUP BY, and HAVING clauses have all been evaluated. The OVER clause defines the data set of the rows to include in the computation of the rank analytical function.
The value expression is a sort specification that can be any valid expression involving a column reference, aggregates, or expressions invoking these items.
The ASC or DESC parameter specifies the ordering sequence ascending or descending. Ascending order is the default.
Rank analytical functions are only allowed in the select list of a SELECT or INSERT statement or in the ORDER BY clause of the SELECT statement. Rank functions can be in a view or a union. Rank functions cannot be used in a subquery, a HAVING clause, or in the select list of an UPDATE or DELETE statement. Only one rank analytical function is allowed per query.
The inverse distribution analytical functions PERCENTILE_CONT and PERCENTILE_DISC take a percentile value as the function argument and operate on a group of data specified in the WITHIN GROUP clause or operate on the entire data set. These functions return one value per group. For PERCENTILE_DISC, the data type of the results is the same as the data type of its ORDER BY item specified in the WITHIN GROUP clause. For PERCENTILE_CONT, the data type of the results is either numeric, if the ORDER BY item in the WITHIN GROUP clause is a numeric, or double, if the ORDER BY item is an integer or floating point.
The inverse distribution analytical functions require a WITHIN GROUP (ORDER BY) clause. For example:
PERCENTILE_CONT ( expression1 ) WITHIN GROUP ( ORDER BY expression2 [ASC | DESC ] )
The value of expression1 must be a constant of numeric data type and range from 0 to 1 (inclusive). If the argument is NULL, then a “wrong argument for percentile” error is returned. If the argument value is less than 0 or greater than 1, then a “data value out of range” error is returned.
The ORDER BY clause, which must be present, specifies the expression on which the percentile function is performed and the order in which the rows are sorted in each group. Note that this ORDER BY clause is used only within the WITHIN GROUP clause and is not an ORDER BY for the SELECT.
The WITHIN GROUP clause distributes the query result into an ordered data set from which the function calculates a result.
The value expression2 is a sort specification that must be a single expression involving a column reference. Multiple expressions are not allowed and no rank analytical functions, set functions, or subqueries are allowed in this sort expression.
The ASC or DESC parameter specifies the ordering sequence ascending or descending. Ascending order is the default.
Inverse distribution analytical functions are allowed in a subquery, a HAVING clause, a view or a union. The inverse distribution functions can be used anywhere the simple non-analytical aggregate functions are used. The inverse distribution functions ignore the NULL value in the data set.
The rank and inverse distribution analytical functions are not supported by Adaptive Server Anywhere or Adaptive Server Enterprise.
See the individual analytical function descriptions for specific details on the use of each function.