NORMALIZE - 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

Period values in the first period column that meet or overlap are combined to form a period that encompasses the individual period values.

Syntax Elements

NORMALIZE
The result of the select is normalized on the first period column in the select list. Period values that meet or overlap are coalesced, that is, combined to form a period that encompasses the individual period values.
Any period columns that are specified after the first period column are treated as regular column values. Normalize is the last operation performed on the result of a SELECT statement. You can use a SELECT statement with the normalize clause on a normalized or non-normalized table.
A SELECT statement cannot normalize a derived period column.
ON MEETS OR OVERLAPS
Period values that meet or overlap are to be coalesced, that is, combined to form a period that encompasses the individual period values.
ON OVERLAPS
Period values that overlap are to be coalesced, that is, combined to form a period that encompasses the individual period values.
ON OVERLAPS OR MEETS
Period values that overlap or meet are to be coalesced, that is, combined to form a period that encompasses the individual period values.
table_name
Name of a table for which all the attributes of all its structured UDT columns are to be returned.
column_name
Name of a column in the named query definition.
You can specify a row-level table constraint column in the select list of a SELECT statement, as long as it is not part of an arithmetic expression. The value returned for the column is the coded value for the row-level security constraint from the row.
Columns with a UDT type are valid with some exceptions. See Specifying UDTs in an SQL Request for the specific exceptions.
You cannot specify LOB columns with NORMALIZE.

ANSI Compliance

NORMALIZE is aTeradata extension to the ANSI SQL:2011 SQL standard.

Usage Notes: Using SELECT with NORMALIZE

Following are the rules and restrictions for using SELECT with NORMALIZE. For information about temporal tables, see Temporal Table Support.

The NORMALIZE operation is performed on the first period column in the select list.

For NORMALIZE, at least one column in the select list must be of period data type.

You can use NORMALIZE:

  • on normalized or non-normalized tables
  • in subqueries
  • in the SELECT INTO statement

When the first period value specified in the SELECT list is a USING value, a constant value, or DEFAULT function on the period column, NORMALIZE operates like SELECT with DISTINCT.

When the NORMALIZE clause is specified with EXPAND, the rows are expanded and then the result is normalized.

When a query includes NORMALIZE and ORDER BY, the rows are normalized first and the result is ordered on the normalized result.

NORMALIZE is the last operation performed, except when the query includes ORDER BY or INTO. The other operations in a query are performed before NORMALIZE, except ORDER BY and INTO, and then the rows are normalized. If NORMALIZE is specified in a query with aggregation or OLAP, normalize is performed on the final result after the aggregate or OLAP operation.

When SELECT NORMALIZE includes a view list, views are not updatable.

A SELECT statement on a derived period column cannot include NORMALIZE.

You cannot include LOB columns in the select column list for NORMALIZE.

You cannot use NORMALIZE in a SELECT statement that includes the WITH clause or the TOP n operator.

You can use NORMALIZE in a non-recursive seed statement in a recursive query. However, NORMALIZE is not allowed in a recursive statement of a recursive query.

When NORMALIZE is specified in the CURSOR select statement, the CURSOR is not updatable.

Example: Using NORMALIZE

Following is the table definition for the NORMALIZE examples;

     CREATE TABLE project
     (    emp_id        INTEGER,
          project_name  VARCHAR(20),
          dept_id       INTEGER,
          duration      PERIOD(DATE)
     );

The table contains the following rows:

Emp_ID Project_Name Dept_ID Duration
10 First Phase 1000 10 Jan 2010 - 20 Mar 2010
10 First Phase 2000 20 Mar 2010 - 15 July 2010
10 Second Phase 2000 15 June 2010 - 18 Aug 2010
20 First Phase 2000 10 Mar 2010 - 20 July 2010

The following select statement performs a normalize operation on emp_id. Note that the select list contains only one period column.

     SELECT NORMALIZE ON MEETS OR OVERLAPS emp_id, duration
     FROM project;

The query returns the following result:

Emp_ID Duration
10 10 Jan 2010 - 18 Aug 2010
20 10 Mar 2010 - 20 July 2010

The following select statement performs a normalize operation on project_name. Note that the select list contains only one period column.

SELECT NORMALIZE project_name, duration
FROM project;

The query returns the following result:

Project_Name Duration
First Phase 10 Jan 2010 - 20 July 2010
Second Phase 15 June 2010 - 18 Aug 2010

The following select statement performs a normalize operation on project_name and dept_id. Note that the select list contains only one period column.

SELECT NORMALIZE project_name, dept_id, duration
FROM project;

The query returns the following result:

Project_Name Dept_ID Duration
First Phase 1000 10 Jan 2010 - 20 Mar 2010
First Phase 2000 20 Mar 2010 - 20 July 2010
Second Phase 2000 15 June 2010 - 18 Aug 2010