Usage Notes - Teradata Database

SQL Data Manipulation Language

Product
Teradata Database
Release Number
16.10
Published
June 2017
Language
English (United States)
Last Update
2018-04-25
dita:mapPath
psg1480972718197.ditamap
dita:ditavalPath
changebar_rev_16_10_exclude_audience_ie.ditaval
dita:id
B035-1146
lifecycle
previous
Product Category
Teradata® Database

Rules and Restrictions for the QUALIFY Clause

The rules and restrictions are:

  • You cannot specify LOB columns in a QUALIFY clause search condition.
  • You cannot specify an OR condition connected with a subquery in a QUALIFY clause search condition.

    The following query fails because of the OR condition connected with the subquery.

         SELECT RANK (column_1)
         FROM table_1
         QUALIFY column_1 IN (SELECT table_2.column_1
                              FROM table_2)
         OR table_1.column.1 = 10000;
  • When you specify a QUALIFY clause in a query, you must also specify a statistical function in one of the following locations within the query.
    • The select list of the SELECT clause
    • The grouping key of the GROUP BY clause
    • The search condition of the QUALIFY clause
  • If you specify the value for a row-level security constraint in a search condition, that value must be expressed in its encoded form.
  • The following rules apply to the use of the DEFAULT function as part of the search condition within a QUALIFY clause.
    • You can specify a DEFAULT function with a column name argument within a predicate. Teradata Database evaluates the DEFAULT function to the default value of the column specified as its argument and uses the value like a constant in the predicate.
    • You can specify a DEFAULT function without a column name argument within a predicate only if there is one column specification and one DEFAULT function as the terms on each side of the comparison operator within the expression.
    • Following existing comparison rules, a condition with a DEFAULT function used with comparison operators other than IS NULL or IS NOT NULL is unknown if the DEFAULT function evaluates to null.

      A condition other than IS NULL or IS NOT NULL with a DEFAULT function compared with a null evaluates to unknown.

      IF a DEFAULT function is used with … THEN the comparison is …
      IS NULL
      • TRUE if the default is null
      • Else it is FALSE
      IS NOT NULL
      • FALSE if the default is null
      • Else it is TRUE

    See SQL Functions, Operators, Expressions, and Predicates for more information about the DEFAULT function.

  • A SELECT statement that specifies the TOP n operator cannot also specify the QUALIFY clause.
  • You cannot specify a SAMPLE clause in a subquery used as a QUALIFY clause predicate.

Evaluation Order of WHERE, GROUP BY, and QUALIFY Clauses

When the WHERE, GROUP BY, and QUALIFY clauses are used together in a SELECT statement, the order of evaluation is as follows:
  1. WHERE clause
  2. GROUP BY clause
  3. QUALIFY clause
The detailed steps are as follows:
  1. Teradata Database evaluates the WHERE clause conditions on the FROM clause tables.
  2. The system groups the resulting rows using the GROUP BY columns.
  3. Teradata Database evaluates the ordered analytical functions on the grouped table.
  4. The system applies the QUALIFY clause to the resulting set.

Teradata Database-specific functions such as CSUM and MAVG that are invoked in both the select list and in the search condition of the QUALIFY clause are computed on the grouped rows without eliminating any rows and then the system applies the search condition of the QUALIFY clause.

For window functions, such as SUM and AVG, the GROUP BY collapses all rows with the same value for the group-by columns into a single row.

QUALIFY Error Conditions

Tables referenced in a QUALIFY clause must be specified in one of the following:
  • FROM clause
  • WHERE clause
  • SELECT expression list
  • Non-aggregate condition

Otherwise, the system returns an error to the requestor. QUALIFY is similar to HAVING in that rows are eliminated based on the value of a function computation. With QUALIFY, rows are eliminated based on the computation of the ordered analytical functions.