License Statement
Licensed to the Apache Software Foundation (ASF) under one or more contributor license agreements. See the NOTICE file distributed with this work for additional information regarding copyright ownership. The ASF licenses this file to you under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at http://www.apache.org/licenses/LICENSE-2.0
Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License.
Acknowledgements
Microsoft®, Windows®, Windows NT®, Windows® XP, and Windows Vista® are U.S. registered trademarks of Microsoft Corporation. Intel® and Intel® Itanium® are trademarks of Intel Corporation in the U.S. and other countries. Java® is a registered trademark of Oracle and/or its affiliates. Motif, OSF/1, UNIX®, X/Open®, and the X device is a trademark of X/Open Company Ltd. in the UK and other countries.
OSF, OSF/1, OSF/Motif, Motif, and Open Software Foundation are trademarks of the Open Software Foundation in the U.S. and other countries. © 1990, 1991, 1992, 1993 Open Software Foundation, Inc.
The OSF documentation and the OSF software to which it relates are derived in part from materials supplied by the following: © 1987, 1988, 1989 Carnegie-Mellon University. © 1989, 1990, 1991 Digital Equipment Corporation. © 1985, 1988, 1989, 1990 Encore Computer Corporation. © 1988 Free Software Foundation, Inc. © 1987, 1988, 1989, 1990, 1991 Hewlett-Packard Company. © 1985, 1987, 1988, 1989, 1990, 1991, 1992 International Business Machines Corporation. © 1988, 1989 Massachusetts Institute of Technology. © 1988, 1989, 1990 Mentat Inc. © 1988 Microsoft Corporation. © 1987, 1988, 1989, 1990, 1991, 1992 SecureWare, Inc. © 1990, 1991 Siemens Nixdorf Informations systeme AG. © 1986, 1989, 1996, 1997 Sun Microsystems, Inc. © 1989, 1990, 1991 Transarc Corporation.
OSF software and documentation are based in part on the Fourth Berkeley Software Distribution under license from The Regents of the University of California. OSF acknowledges the following individuals and institutions for their role in its development: Kenneth C.R.C. Arnold, Gregory S. Couch, Conrad C. Huang, Ed James, Symmetric Computer Systems, Robert Elz. © 1980, 1981, 1982, 1983, 1985, 1986, 1987, 1988, 1989 Regents of the University of California. OSF MAKES NO WARRANTY OF ANY KIND WITH REGARD TO THE OSF MATERIAL PROVIDED HEREIN, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. OSF shall not be liable for errors contained herein or for incidental consequential damages in connection with the furnishing, performance, or use of this material.
Revision History
Version | Date |
---|---|
2.0.0 |
To be announced. |
1.3.0 |
January, 2016 |
1. About This Document
This manual describes reference information about the syntax of SQL statements, functions, and other SQL language elements supported by the Trafodion project’s database software.
Trafodion SQL statements and utilities are entered interactively or from script files using a client-based tool, such as the Trafodion Command Interface (TrafCI). To install and configure a client application that enables you to connect to and use a Trafodion database, see the Trafodion Client Installation Guide.
In this manual, SQL language elements, statements, and clauses within statements are based on the ANSI SQL:1999 standard. |
1.1. Intended Audience
This manual is intended for database administrators and application programmers who are using SQL to read, update, and create Trafodion SQL tables, which map to HBase tables, and to access native HBase and Hive tables.
You should be familiar with structured query language (SQL) and with the American National Standard Database Language SQL:1999.
1.2. New and Changed Information
This edition includes updates for these new features:
New Feature | Location in the Manual |
---|---|
On Line Analytical Process (OLAP) window functions |
|
Ability to cancel DDL, update statistics, and additional child query operations in addition to DML statements |
|
Authorization required to run the CONTROL QUERY CANCEL Statement |
|
Ability to grant privileges on behalf of a role using the GRANTED BY clause. |
|
Authorization required for all SHOWDDL commands |
|
Ability to display the DDL syntax of a library object using the SHOWDDL LIBRARY command |
|
Listing of HBase objects using the GET HBASE OBJECTS command through an SQL interface |
1.3. Document Organization
Chapter or Appendix | Description |
---|---|
Introduces Trafodion SQL and covers topics such as data consistency, transaction management, and ANSI compliance. |
|
Describes the SQL statements supported by Trafodion SQL. |
|
Describes the SQL utilities supported by Trafodion SQL. |
|
Describes parts of the language, such as database objects, data types, expressions, identifiers, literals, and predicates, which occur within the syntax of Trafodion SQL statements. |
|
Describes clauses used by Trafodion SQL statements. |
|
Describes specific functions and expressions that you can use in Trafodion SQL statements. |
|
Describes how to gather statistics for active queries or for the Runtime Management System (RMS) and describes the RMS counters that are returned. |
|
Describes specific on line analytical processing functions. |
|
Lists the words that are reserved in Trafodion SQL. |
|
Describes limits in Trafodion SQL. |
1.4. Notation Conventions
This list summarizes the notation conventions for syntax presentation in this manual.
-
UPPERCASE LETTERS
Uppercase letters indicate keywords and reserved words. Type these items exactly as shown. Items not enclosed in brackets are required.
SELECT
-
lowercase letters
Lowercase letters, regardless of font, indicate variable items that you supply. Items not enclosed in brackets are required.
file-name
-
[ ] Brackets
Brackets enclose optional syntax items.
DATETIME [start-field TO] end-field
A group of items enclosed in brackets is a list from which you can choose one item or none.
The items in the list can be arranged either vertically, with aligned brackets on each side of the list, or horizontally, enclosed in a pair of brackets and separated by vertical lines.
For example:
DROP SCHEMA schema [CASCADE] DROP SCHEMA schema [ CASCADE | RESTRICT ]
-
{ } Braces
Braces enclose required syntax items.
FROM { grantee [, grantee ] ... }
A group of items enclosed in braces is a list from which you are required to choose one item.
The items in the list can be arranged either vertically, with aligned braces on each side of the list, or horizontally, enclosed in a pair of braces and separated by vertical lines.
For example:
INTERVAL { start-field TO end-field } { single-field } INTERVAL { start-field TO end-field | single-field }
-
| Vertical Line
A vertical line separates alternatives in a horizontal list that is enclosed in brackets or braces.
{expression | NULL}
-
… Ellipsis
An ellipsis immediately following a pair of brackets or braces indicates that you can repeat the enclosed sequence of syntax items any number of times.
ATTRIBUTE[S] attribute [, attribute] ... {, sql-expression } ...
An ellipsis immediately following a single syntax item indicates that you can repeat that syntax item any number of times.
For example:
expression-n ...
-
Punctuation
Parentheses, commas, semicolons, and other symbols not previously described must be typed as shown.
DAY (datetime-expression) @script-file
Quotation marks around a symbol such as a bracket or brace indicate the symbol is a required character that you must type as shown.
For example:
"{" module-name [, module-name] ... "}"
-
Item Spacing
Spaces shown between items are required unless one of the items is a punctuation symbol such as a parenthesis or a comma.
DAY (datetime-expression) DAY(datetime-expression)
If there is no space between two items, spaces are not permitted. In this example, no spaces are permitted between the period and any other items:
myfile.sh
-
Line Spacing
If the syntax of a command is too long to fit on a single line, each continuation line is indented three spaces and is separated from the preceding line by a blank line.
This spacing distinguishes items in a continuation line from items in a vertical list of selections.
match-value [NOT] LIKE _pattern [ESCAPE esc-char-expression]
1.5. Comments Encouraged
We encourage your comments concerning this document. We are committed to providing documentation that meets your needs. Send any errors found, suggestions for improvement, or compliments to user@trafodion.incubator.apache.org.
Include the document title and any comment, error found, or suggestion for improvement you have concerning this document.
2. Introduction
The Trafodion SQL database software allows you to use SQL statements, which comply closely to ANSI SQL:1999, to access data in Trafodion SQL tables, which map to HBase tables, and to access native HBase tables and Hive tables.
This introduction describes:
Other sections of this manual describe the syntax and semantics of individual statements, commands, and language elements.
2.1. SQL Language
The SQL language consists of statements and other language elements that you can use to access SQL databases. For descriptions of individual SQL statements, see SQL Statements.
SQL language elements are part of statements and commands and include data types, expressions, functions, identifiers, literals, and predicates. For more information, see:
For information on specific functions and expressions, see:
2.2. Using Trafodion SQL to Access HBase Tables
You can use Trafodion SQL statements to read, update, and create HBase tables.
For a list of Control Query Default (CQD) settings for the HBase environment, see the Trafodion Control Query Default (CQD) Reference Guide.
2.2.1. Ways to Access HBase Tables
Trafodion SQL supports these ways to access HBase tables:
Accessing Trafodion SQL Tables
A Trafodion SQL table is a relational SQL table generated by a CREATE TABLE
statement and mapped
to an HBase table. Trafodion SQL tables have regular ANSI names in the catalog TRAFODION
.
A Trafodion SQL table name can be a fully qualified ANSI name of the form
TRAFODION.schema-name.object-name
.
To access a Trafodion SQL table, specify its ANSI table name in a Trafodion SQL statement, similar to how you would specify an ANSI table name when running SQL statements in a relational database.
Example
CREATE TABLE trafodion.sales.odetail
( ordernum NUMERIC (6) UNSIGNED NO DEFAULT NOT NULL
, partnum NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL
, unit_price NUMERIC (8,2) NO DEFAULT NOT NULL
, qty_ordered NUMERIC (5) UNSIGNED NO DEFAULT NOT NULL
, PRIMARY KEY (ordernum, partnum)
);
INSERT INTO trafodion.sales.odetail VALUES ( 900000, 7301, 425.00, 100 );
SET SCHEMA trafodion.sales;
SELECT * FROM odetail;
For more information about Trafodion SQL tables, see Trafodion SQL Tables Versus Native HBase Tables.
Cell-Per-Row Access to HBase Tables (Technology Preview)
This is a Technology Preview (Complete But Not Tested) feature, meaning that it is functionally complete but has not been tested or debugged. |
To access HBase data using cell-per-row mode, specify the schema HBASE."CELL"
and the full ANSI
name of the table as a delimited table name. You can specify the name of any HBase table, regardless of whether
it was created through Trafodion SQL.
Example
select * from hbase."_CELL_"."TRAFODION.MYSCH.MYTAB";
select * from hbase."_CELL_"."table_created_in_HBase";
All tables accessed through this schema have the same column layout:
>>invoke hbase."_CELL_"."table_created_in_HBase";
(
ROW_ID VARCHAR(100) ...
, COL_FAMILY VARCHAR(100) ...
, COL_NAME VARCHAR(100) ...
, COL_TIMESTAMP LARGEINT ...
, COL_VALUE VARCHAR(1000) ...
)
PRIMARY KEY (ROW_ID)
>>select * from hbase."_CELL_"."mytab";
Rowwise Access to HBase Tables (Technology Preview)
This is a Technology Preview (Complete But Not Tested) feature, meaning that it is functionally complete but has not been tested or debugged. |
To access HBase data using rowwise mode, specify the schema HBASE."ROW"
and the full ANSI name of the
table as a delimited table name. You can specify the name of any HBase table, regardless of whether
it was created through Trafodion SQL.
Example
select * from hbase."_ROW_"."TRAFODION.MYSCH.MYTAB";
select * from hbase."_ROW_"."table_created_in_HBase";
All column values of the row are returned as a single, big varchar:
>>invoke hbase."_ROW_"."mytab";
(
ROW_ID VARCHAR(100) ...
, COLUMN_DETAILS VARCHAR(10000) ...
)
PRIMARY KEY (ROW_ID)
>>select * from hbase."_ROW_"."mytab";
2.2.2. Trafodion SQL Tables Versus Native HBase Tables
Trafodion SQL tables have many advantages over regular HBase tables:
-
They can be made to look like regular, structured SQL tables with fixed columns.
-
They support the usual SQL data types supported in relational databases.
-
They support compound keys, unlike HBase tables that have a single row key (a string).
-
They support indexes.
-
They support salting, which is a technique of adding a hash value of the row key as a key prefix to avoid hot spots for sequential keys. For the syntax, see the CREATE TABLE Statement.
The problem with Trafodion SQL tables is that they use a fixed format to represent column values, making it harder for native HBase applications to access them. Also, they have a fixed structure, so users lose the flexibility of dynamic columns that comes with HBase.
2.2.3. Supported SQL Statements With HBase Tables
You can use these SQL statements with HBase tables:
2.3. Using Trafodion SQL to Access Hive Tables
You can use Trafodion SQL statements to access Hive tables.
For a list of Control Query Default (CQD) settings for the Hive environment, see the Trafodion Control Query Default (CQD) Reference Guide.
2.3.1. ANSI Names for Hive Tables
Hive tables appear in the Trafodion Hive ANSI name space in a special catalog and schema named HIVE.HIVE
.
To select from a Hive table named T
, specify an implicit or explicit name, such as HIVE.HIVE.T
,
in a Trafodion SQL statement.
Example
This example should work if a Hive table named T
has already been defined:
set schema hive.hive;
CQD HIVE_MAX_STRING_LENGTH '20'; -- creates a more readable display
select * from t; -- implicit table name
set schema trafodion.seabase;
select * from hive.hive.t; -- explicit table name
2.3.2. Type Mapping From Hive to Trafodion SQL
Trafodion performs the following data-type mappings:
Hive Type | Trafodion SQL Type |
---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-
The value
n
is determined byCQD HIVE_MAX_STRING_LENGTH
. See the Trafodion Control Query Default (CQD) Reference Guide. -
Hive supports timestamps with nanosecond resolution (precision of 9). Trafodion SQL supports only microsecond resolution (precision 6).
2.3.3. Supported SQL Statements With Hive Tables
You can use these SQL statements with Hive tables:
-
GET TABLES (See the GET Statement.)
2.4. Data Consistency and Access Options
Access options for DML statements affect the consistency of the data that your query accesses.
For any DML statement, you specify access options by using the FOR option ACCESS
clause and,
for a SELECT
statement, by using this same clause, you can also specify access options for individual
tables and views referenced in the FROM clause.
The possible settings for option
in a DML statement are:
Specifies that the data accessed by the DML statement must be from committed rows.
The SQL default access option for DML statements is READ COMMITTED
.
For related information about transactions, see Transaction Isolation Levels.
2.4.1. READ COMMITTED
This option allows you to access only committed data.
The implementation requires that a lock can be acquired on the data requested by the DML statement—but does not actually lock the data, thereby reducing lock request conflicts. If a lock cannot be granted (implying that the row contains uncommitted data), the DML statement request waits until the lock in place is released.
READ COMMITTED provides the next higher level of data consistency (compared to READ UNCOMMITTED). A statement executing with this access option does not allow dirty reads, but both non-repeatable reads and phantoms are possible.
READ COMMITTED provides sufficient consistency for any process that does not require a repeatable read capability.
READ COMMITTED is the default isolation level.
2.5. Transaction Management
A transaction (a set of database changes that must be completed as a group) is the basic recoverable unit in case of a failure or transaction interruption. Transactions are controlled through client tools that interact with the database using ODBC or JDBC.
The typical order of events is:
-
Transaction is started.
-
Database changes are made.
-
Transaction is committed.
If, however, the changes cannot be made or if you do not want to complete the transaction, then you can abort the transaction so that the database is rolled back to its original state.
This subsection discusses these considerations for transaction management:
2.5.1. User-Defined and System-Defined Transactions
Transactions you define are called user-defined transactions. To be sure that a sequence of statements executes successfully or not at all, you can define one transaction consisting of these statements by using the BEGIN WORK statement and COMMIT WORK statement. You can abort a transaction by using the ROLLBACK WORK statement.
If AUTOCOMMIT is on, then you do not have to end the transaction explicitly as Trafodion SQL will end the transaction automatically. Sometimes an error occurs that requires the user-defined transaction to be aborted. Trafodion SQL will automatically abort the transaction and return an error indicating that the transaction was rolled back.
System-Defined Transactions
In some cases, Trafodion SQL defines transactions for you. These transactions are called system-defined transactions. Most DML statements initiate transactions implicitly at the start of execution. See Implicit Transactions.
However, even if a transaction is initiated implicitly, you must end a transaction explicitly with the COMMIT WORK statement or the ROLLBACK WORK statement. If AUTOCOMMIT is on, you do not need to end a transaction explicitly.
2.5.2. Rules for DML Statements
If deadlock occurs, the DML statement times out and receives an error.
2.5.3. Effect of AUTOCOMMIT Option
AUTOCOMMIT is an option that can be set in a SET TRANSACTION statement. It specifies whether Trafodion SQL will commit automatically, or roll back if an error occurs, at the end of statement execution. This option applies to any statement for which the system initiates a transaction. See SET TRANSACTION Statement.
If this option is set to ON, Trafodion SQL automatically commits any changes, or rolls back any changes, made to the database at the end of statement execution.
2.5.4. Concurrency
Concurrency is defined by two or more processes accessing the same data at the same time. The degree of concurrency available — whether a process that requests access to data that is already being accessed is given access or placed in a wait queue — depends on the purpose of the access mode (read or update) and the isolation level. Currently, the only isolation level is READ COMMITTED.
Trafodion SQL provides concurrent database access for most operations and controls database access through concurrency control and the mechanism for opening and closing tables. For DML operations, the access option affects the degree of concurrency. See Data Consistency and Access Options.
2.5.5. Transaction Isolation Levels
A transaction has an isolation level that is READ COMMITTED.
READ COMMITTED
This option, which is ANSI compliant, allows your transaction to access only committed data. No row locks are acquired when READ COMMITTED is the specified isolation level.
READ COMMITTED provides the next level of data consistency. A transaction executing with this isolation level does not allow dirty reads, but both non-repeatable reads and phantoms are possible.
READ COMMITTED provides sufficient consistency for any transaction that does not require a repeatable-read capability.
The default isolation level is READ COMMITTED.
2.6. ANSI Compliance and Trafodion SQL Extensions
Trafodion SQL complies most closely with Core SQL 99. Trafodion SQL also includes some features from SQL 99 and part of the SQL 2003 standard, and special Trafodion SQL extensions to the SQL language.
Statements and SQL elements in this manual are ANSI compliant unless specified as Trafodion SQL extensions.
2.6.1. ANSI-Compliant Statements
These statements are ANSI compliant, but some might contain Trafodion SQL extensions:
2.6.2. Statements That Are Trafodion SQL Extensions
These statements are Trafodion SQL extensions to the ANSI standard.
2.6.3. ANSI-Compliant Functions
These functions are ANSI compliant, but some might contain Trafodion SQL extensions:
All other functions are Trafodion SQL extensions.
2.7. Trafodion SQL Error Messages
Trafodion SQL reports error messages and exception conditions. When an error condition occurs, Trafodion SQL returns a message number and a brief description of the condition.
Example
Trafodion SQL might display this error message:
*** ERROR[1000] A syntax error occurred.
The message number is the SQLCODE value (without the sign). In this example, the SQLCODE value is 1000
.
3. SQL Statements
This section describes the syntax and semantics of Trafodion SQL statements.
Trafodion SQL statements are entered interactively or from script files using a client-based tool, such as the Trafodion Command Interface (TrafCI). To install and configure a client application that enables you to connect to and use a Trafodion database, see the Trafodion Client Installation Guide.
3.1. Categories
The statements are categorized according to their functionality:
3.1.1. Data Definition Language (DDL) Statements
Use these DDL statements to create, drop, or alter the definition of a Trafodion SQL schema or object.
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements, AUTOCOMMIT must be turned ON (the default) for the session. |
Statement |
What It Does |
Changes attributes for a table. |
|
Changes attributes for a user. |
|
Registers a user-defined function (UDF) written in C as a function within a Trafodion database. |
|
Creates an index on a table. |
|
Registers a library object in a Trafodion database. |
|
Registers a Java method as a stored procedure in Java (SPJ) within a Trafodion database. |
|
Creates a role. |
|
Creates a schema in the database. |
|
Creates a table. |
|
Creates a view. |
|
Removes a user-defined function (UDF) from the Trafodion database. |
|
Drops an index. |
|
Removes a library object from the Trafodion database and also removes the library file referenced by the library object. |
|
Removes a stored procedure in Java (SPJ) from the Trafodion database. |
|
Drops a role. |
|
Drops a schema from the database. |
|
Drops a table. |
|
Drops a view. |
|
Registers a user in the SQL database, associating the user’s login name with a database user name. |
|
Removes a database user name from the SQL database. |
3.1.2. Data Manipulation Language (DML) Statements
Use these DML statements to delete, insert, select, or update rows in one or more tables:
Statement | What It Does |
---|---|
Deletes rows from a table or view. |
|
Inserts data into tables and views. |
|
Either performs an upsert operation (that is, updates a table if the row exists or inserts into a table if the row does not exist) or updates (merges) matching rows from one table to another. |
|
Retrieves data from tables and views. |
|
Equivalent to the query specification SELECT * FROM table |
|
Updates values in columns of a table or view. |
|
Updates a table if the row exists or inserts into a table if the row does not exist. |
|
Displays the results of the evaluation of the expressions and the results of row subqueries within the row value constructors. |
3.1.3. Transaction Control Statements
Use these statements to specify user-defined transactions and to set attributes for the next transaction:
Statement | What It Does |
---|---|
Starts a transaction. |
|
Commits changes made during a transaction and ends the transaction. |
|
Undoes changes made during a transaction and ends the transaction. |
|
Sets attributes for the next SQL transaction — whether to automatically commit database changes. |
3.1.4. Data Control and Security Statements
Use these statements to register users, create roles, and grant and revoke privileges:
Statement | What It Does |
---|---|
Changes attributes associated with a user who is registered in the database. |
|
Creates an SQL role. |
|
Deletes an SQL role. |
|
Grants access privileges on an SQL object to specified users or roles. |
|
Grants one or more component privileges to a user or role. |
|
Grants one or more roles to a user. |
|
Registers a user in the SQL database, associating the user’s login name with a database user name. |
|
Revokes access privileges on an SQL object from specified users or roles. |
|
Removes one or more component privileges from a user or role. |
|
Removes one or more roles from a user. |
|
Removes a database user name from the SQL database. |
3.1.5. Stored Procedure and User-Defined Function Statements
Use these statements to create and execute stored procedures in Java (SPJs) or create user-defined functions (UDFs) and to modify authorization to access libraries or to execute SPJs or UDFs:
Statement | What It Does |
---|---|
Initiates the execution of a stored procedure in Java (SPJ) in a Trafodion database. |
|
Registers a user-defined function (UDF) written in C as a function within a Trafodion database. |
|
Registers a library object in a Trafodion database. |
|
Registers a Java method as a stored procedure in Java (SPJ) within a Trafodion database. |
|
Removes a user-defined function (UDF) from the Trafodion database. |
|
Removes a library object from the Trafodion database and also removes the library file referenced by the library object. |
|
Removes a stored procedure in Java (SPJ) from the Trafodion database. |
|
Grants privileges for accessing a library object or executing an SPJ or UDF to specified users. |
|
Revokes privileges for accessing a library object or executing an SPJ or UDF from specified users. UDF from specified users. |
3.1.6. Prepared Statements
Use these statements to prepare and execute an SQL statement:
Statement | What It Does |
---|---|
Executes an SQL statement previously compiled by a PREPARE statement. |
|
Compiles an SQL statement for later use with the EXECUTE statement in the same session. |
3.1.7. Control Statements
Use these statements to control the execution, default options, plans, and performance of DML statements:
Statement | What It Does |
---|---|
Cancels an executing query that you identify with a query ID. |
|
Changes a default attribute to influence a query plan. |
3.1.8. Object Naming Statements
Use this statements to specify default ANSI names for the schema:
Statement | What It Does |
---|---|
Sets the default ANSI schema for unqualified object names for the current session. |
3.1.9. SHOW, GET, and EXPLAIN Statements
Use these statements to display information about database objects or query execution plans:
Statement | What It Does |
---|---|
Displays information contained in the query execution plan. |
|
Displays the names of database objects, components, component privileges, roles, or users that exist in the Trafodion instance. |
|
Displays a list of HBase objects through an SQL interface |
|
Displays the version of the metadata in the Trafodion instance and indicates if the metadata is current. |
|
Displays the version of the Trafodion software that is installed on the system and indicates if it is current. |
|
Generates a record description that corresponds to a row in the specified table or view. |
|
Displays the CONTROL QUERY DEFAULT attributes in effect. |
|
Describes the DDL syntax used to create an object as it exists in the metadata, or it returns a description of a user, role, or component in the form of a GRANT statement. |
|
Displays the DDL syntax used to create a schema as it exists in the metadata and shows the authorization ID that owns the schema. |
|
Displays the histogram statistics for one or more groups of columns within a table. These statistics are used to devise optimized access plans. |
3.2. ALTER TABLE Statement
The ALTER TABLE statement changes a Trafodion SQL table. See Tables.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
ALTER TABLE name alter-action
alter-action is:
ADD [COLUMN] column-definition
| ADD IF NOT EXISTS column-definition
| ADD [CONSTRAINT constraint-name] table-constraint
| DROP CONSTRAINT constraint-name [RESTRICT]
| RENAME TO new-name [CASCADE]
| DROP COLUMN [IF EXISTS] column-name
column-definition is:
column-name data-type
([DEFAULT default]
[[constraint constraint-name] column-constraint])
data-type is:
char[acter] [(length)[characters]]
[CHARACTER SET char-set-name]
[UPSHIFT] [[not] casespecific]
| char[acter] varying (length)
[character set char-set-name]
[upshift] [[not] casespecific]
| varchar (length) [character set char-set-name]
[upshift] [[not] casespecific]
| numeric [(precision [,scale])] [signed|unsigned]
| nchar [(length) [character set char-set-name]
[upshift] [[not] casespecific]
| nchar varying(length) [character set char-set-name]
[upshift] [[not] casespecific]
| smallint [signed|unsigned]
| int[eger] [signed|unsigned]
| largeint
| dec[imal] [(precision [,scale])] [signed|unsigned]
| float [(precision)]
| real
| double precision
| date
| time [(time-precision)]
| timestamp [(timestamp-precision)]
| interval { start-field to end-field | single-field }
default is:
literal
| null
| currentdate
| currenttime
| currenttimestamp }
column-constraint is:
not null
| unique
| check (condition)
| references ref-spec
table-constraint is:
unique (column-list)
| check (condition)
| foreign key (column-list) references ref-spec
ref-spec is:
referenced-table [(column-list)]
column-list is:
column-name[, column-name]...
3.2.1. Syntax Description of ALTER TABLE
-
name
specifies the current name of the object. See Database Object Names.
-
ADD [COLUMN] column-definition
adds a column to table.
The clauses for the column-definition are:
-
column-name
specifies the name for the new column in the table. column-name is an SQL identifier. column-name must be unique among column names in the table. If the column name is a Trafodion SQL reserved word, you must delimit it by enclosing it in double quotes. For example:
"sql".myview
. See Identifiers. -
data-type
specifies the data type of the values that can be stored in column-name. See Data Types If a default is not specified, NULL is used.
-
DEFAULT default
specifies a default value for the column or specifies that the column does not have a default value. You can declare the default value explicitly by using the DEFAULT clause, or you can enable null to be used as the default by omitting both the DEFAULT and NOT NULL clauses. If you omit the DEFAULT clause and specify NOT NULL, Trafodion SQL returns an error. For existing rows of the table, the added column takes on its default value.
If you set the default to the datetime value CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP, Trafodion SQL uses January 1, 1 A.D. 12:00:00.000000 as the default date and time for the existing rows.
For any row that you add after the column is added, if no value is specified for the column as part of the add row operation, the column receives a default value based on the current timestamp at the time the row is added.
-
-
[[constraint constraint-name] column-constraint]
specifies a name for the column or table constraint. constraint-name must have the same schema as table and must be unique among constraint names in its schema. if you omit the schema portions of the name you specify in constraint-name, trafodion sql expands the constraint name by using the schema for table. see database object names.
if you do not specify a constraint name, trafodion sql constructs an sql identifier as the name for the constraint in the schema for table. the identifier consists of the fully qualified table name concatenated with a system-generated unique identifier. for example, a constraint on table a.b.c might be assigned a name such as a.b.c_123…_01….
-
column-constraint
options:-
not null
is a column constraint that specifies that the column cannot contain nulls. if you omit not null, nulls are allowed in the column. if you specify both not null and no default, then each row inserted in the table must include a value for the column. see null.
-
unique
is a column constraint that specifies that the column cannot contain more than one occurrence of the same value. if you omit unique, duplicate values are allowed unless the column is part of the primary key. columns that you define as unique must be specified as not null.
-
check (condition)
is a constraint that specifies a condition that must be satisfied for each row in the table. see search condition. you cannot refer to the current_date, current_time, or current_timestamp function in a check constraint, and you cannot use subqueries in a check constraint.
-
-
-
references ref-spec
specifies a references column constraint. the maximum combined length of the columns for a references constraint is 2048 bytes.
-
ref-spec
is:referenced-table [(column-list)]
referenced-table
is the table referenced by the foreign key in a referential constraint. referenced-table cannot be a view. referenced-table cannot be the same as table. referenced-table corresponds to the foreign key in the table.
column-list
specifies the column or set of columns in the referenced-table that corresponds to the foreign key in table. the columns in the column list associated with references must be in the same order as the columns in the column list associated with foreign key. if column-list is omitted, the referenced table’s primary key columns are the referenced columns.a table can have an unlimited number of referential constraints, and you can specify the same foreign key in more than one referential constraint, but you must define each referential constraint separately. you cannot create self-referencing foreign key constraints.
-
add [constraint constraint-name] table-constraint
adds a constraint to the table and optionally specifies constraint-name as the name for the constraint. the new constraint must be consistent with any data already present in the table.
-
-
-
constraint constraint-name
specifies a name for the column or table constraint. constraint-name must have the same schema as table and must be unique among constraint names in its schema. if you omit the schema portions of the name you specify in constraint-name, trafodion sql expands the constraint name by using the schema for table. see database object names.
if you do not specify a constraint name, trafodion sql constructs an sql identifier as the name for the constraint in the schema for table. the identifier consists of the fully qualified table name concatenated with a system-generated unique identifier. for example, a constraint on table a.b.c might be assigned a name such as a.b.c_123…_01….
-
table-constraint
options:-
unique (column-list)
is a table constraint that specifies that the column or set of columns cannot contain more than one occurrence of the same value or set of values.
column-list
cannot include more than one occurrence of the same column. in addition, the set of columns that you specify on a unique constraint cannot match the set of columns on any other unique constraint for the table or on the primary key constraint for the table. all columns defined as unique must be specified as not null.a unique constraint is enforced with a unique index. if there is already a unique index on column-list, trafodion sql uses that index. if a unique index does not exist, the system creates a unique index.
-
check (condition)
is a constraint that specifies a condition that must be satisfied for each row in the table. see search condition. you cannot refer to the current_date, current_time, or current_timestamp function in a check constraint, and you cannot use subqueries in a check constraint.
-
-
foreign key (column-list) references ref-spec not enforced
is a table constraint that specifies a referential constraint for the table, declaring that a column or set of columns (called a foreign key) in table can contain only values that match those in a column or set of columns in the table specified in the references clause. however, because not enforced is specified, this relationship is not checked.
the two columns or sets of columns must have the same characteristics (data type, length, scale, precision). without the foreign key clause, the foreign key in table is the column being defined; with the foreign key clause, the foreign key is the column or set of columns specified in the foreign key clause. for information about ref-spec, see references ref-spec not enforced.
-
drop constraint constraint-name [restrict]
drops a constraint from the table.
if you drop a constraint, trafodion sql drops its dependent index if trafodion sql originally created the same index. if the constraint uses an existing index, the index is not dropped.
-
constraint constraint-name
specifies a name for the column or table constraint. constraint-name must have the same schema as table and must be unique among constraint names in its schema. if you omit the schema portions of the name you specify in constraint-name, trafodion sql expands the constraint name by using the schema for table. see database object names.
if you do not specify a constraint name, trafodion sql constructs an sql identifier as the name for the constraint in the schema for table. the identifier consists of the fully qualified table name concatenated with a system-generated unique identifier. for example, a constraint on table a.b.c might be assigned a name such as a.b.c_123…_01….
-
-
rename to new-name [cascade]
changes the logical name of the object within the same schema.
-
new-name
specifies the new name of the object after the rename to operation occurs.
-
-
-
cascade
specifies that indexes and constraints on the renamed object will be renamed.
-
add if not exists column-definition
adds a column to table if it does not already exist in the table.
the clauses for the column-definition are the same as described in add [column] column-definition.
-
drop column [if exists] column-name
drops the specified column from table, including the column’s data. you cannot drop a primary key column.
-
3.2.2. Considerations for ALTER TABLE
Effect of Adding a Column on View Definitions
The addition of a column to a table has no effect on existing view definitions. Implicit column references specified by SELECT * in view definitions are replaced by explicit column references when the definition clauses are originally evaluated.
Authorization and Availability Requirements
ALTER TABLE works only on user-created tables.
Required Privileges
To issue an ALTER TABLE statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the table.
-
You have the ALTER or ALTER_TABLE component privilege for the SQL_OPERATIONS component.
Privileges Needed to Create a Referential Integrity Constraint
To create a referential integrity constraint (that is, a constraint on the table that refers to a column in another table), one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the referencing and referenced tables.
-
You have these privileges on the referencing and referenced table:
-
For the referencing table, you have the ALTER or ALTER_TABLE component privilege for the SQL_OPERATIONS component.
-
For the referenced table, you have the REFERENCES (or ALL) privilege on the referenced table through your user name or through a granted role.
-
If the constraint refers to the other table in a query expression, you must also have SELECT privileges on the other table.
3.2.3. Example of ALTER TABLE
This example adds a column:
ALTER TABLE persnl.project
ADD COLUMN projlead
NUMERIC (4) UNSIGNED
3.3. ALTER USER Statement
The ALTER USER statement changes attributes associated with a user who is registered in the database.
ALTER USER is a Trafodion SQL extension.
ALTER USER database-username alter-action[, alter-action]
alter-action is:
SET EXTERNAL NAME directory-service-username
| SET { ONLINE | OFFLINE }
3.3.1. Syntax Description of ALTER USER
-
database-username
is the name of a currently registered database user.
-
SET EXTERNAL NAME
changes the name that identifies the user in the directory service. This is also the name the user specifies when connecting to the database.
-
directory-service-username
specifies the new name of the user in the directory service.
-
-
directory-service-username is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers.
-
SET { ONLINE | OFFLINE }
changes the attribute that controls whether the user is allowed to connect to the database.
-
ONLINE
specifies that the user is allowed to connect to the database.
-
OFFLINE
specifies that the user is not allowed to connect to the database.
-
3.3.2. Considerations for ALTER USER
Only a user with user administrative privileges (that is, a user who has been granted the MANAGE_USERS component privilege) can do the following:
-
Set the EXTERNAL NAME for any user
-
Set the ONLINE | OFFLINE attribute for any user
Initially, DB_ROOT is the only database user who has been granted the MANAGE_USERS component privilege.
3.3.3. Examples of ALTER USER
-
To change a user’s external name:
ALTER USER ajones SET EXTERNAL NAME "Americas\ArturoJones";
-
To change a user’s attribute to allow the user to connect to the database:
ALTER USER ajones SET ONLINE;
3.4. BEGIN WORK Statement
The BEGIN WORK statement enables you to start a transaction explicitly—where the transaction consists of the set of operations defined by the sequence of SQL statements that begins immediately after BEGIN WORK and ends with the next COMMIT or ROLLBACK statement. See Transaction Management. BEGIN WORK will raise an error if a transaction is currently active.
BEGIN WORK is a Trafodion SQL extension.
BEGIN WORK
3.4.1. Considerations for BEGIN WORK
BEGIN WORK starts a transaction. COMMIT WORK or ROLLBACK WORK ends a transaction.
3.4.2. Example of BEGIN WORK
Group three separate statements—two INSERT statements and an UPDATE statement—that update the database within a single transaction:
--- This statement initiates a transaction.
BEGIN WORK;
--- SQL operation complete.
INSERT INTO sales.orders VALUES (125, DATE '2008-03-23', DAT '2008-03-30', 75, 7654);
--- 1 row(s) inserted.
INSERT INTO sales.odetail VALUES (125, 4102, 25000, 2);
--- 1 row(s) inserted.
UPDATE invent.partloc SET qty_on_hand = qty_on_hand - 2 WHERE partnum = 4102 AND loc_code = 'G45';
--- 1 row(s) updated.
--- This statement ends a transaction.
COMMIT WORK;
--- SQL operation complete.
3.5. CALL Statement
The CALL statement invokes a stored procedure in Java (SPJ) in a Trafodion SQL database.
CALL procedure-ref ([argument-list])
procedure-ref is:
[[catalog-name.]schema-name.]procedure-name
argument-list is:
sql-expression[, sql-expression]...
3.5.1. Syntax Description of CALL
-
procedure-ref
specifies an ANSI logical name of the form:
[[_catalog-name_.]schema-name.]procedure-name
where each part of the name is a valid sql identifier with a maximum of 128 characters. for more information, see identifiers and database object names.
if you do not fully qualify the procedure name, trafodion sql qualifies it according to the schema of the current session.
-
argument-list
accepts arguments for in, in-out, or out parameters. the arguments consist of sql expressions, including dynamic parameters, separated by commas:
sql-expression[{, sql-expression}…]
each expression must evaluate to a value of one of these data types:
-
character value
-
date-time value
-
numeric value
interval value expressions are disallowed in SPJs. for more information, see input parameter arguments and output parameter arguments.
do not specify result sets in the argument list.
-
3.5.2. Considerations for CALL
Usage Restrictions
You can use a CALL statement as a stand-alone SQL statement in applications or command-line interfaces, such as TrafCI. You cannot use a CALL statement inside a compound statement or with row sets.
Required Privileges
To issue a CALL statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the stored procedure.
-
You have the EXECUTE (or ALL) privileges, either directly through your username or through a granted role. For more information, see the GRANT Statement.
When the stored procedure executes, it executes as the Trafodion ID.
Input Parameter Arguments
You pass data to an SPJ by using IN or INOUT parameters. For an IN parameter argument, use one of these SQL expressions:
-
Literal
-
SQL function (including CASE and CAST expressions)
-
Arithmetic or concatenation operation
-
Scalar subquery
-
Dynamic parameter (for example, ?) in an application
-
Named (for example, ?param) or unnamed (for example, ?) parameter in TrafCI
For an INOUT parameter argument, you can use only a dynamic, named, or unnamed parameter. For more information, see Expressions.
Output Parameter Arguments
An SPJ returns values in OUT and INOUT parameters. Output parameter arguments must be dynamic parameters in an application (for example, ?) or named or unnamed parameters in DCI (for example, ?param or ?). Each calling application defines the semantics of the OUT and INOUT parameters in its environment.
Data Conversion of Parameter Arguments
Trafodion SQL performs an implicit data conversion when the data type of a parameter argument is compatible with but does not match the formal data type of the stored procedure. For stored procedure input values, the conversion is from the actual argument value to the formal parameter type. For stored procedure output values, the conversion is from the actual output value, which has the data type of the formal parameter, to the declared type of the dynamic parameter.
Null Input and Output
You can pass a null value as input to or output from an SPJ, provided that the corresponding Java data type of the parameter supports nulls. If a null is input or output for a parameter that does not support nulls, Trafodion SQL returns an error.
Transaction Semantics
The CALL statement automatically initiates a transaction if no active transaction exists. However, the failure of a CALL statement does not always automatically abort the transaction.
3.5.3. Examples of CALL
-
In TrafCI, execute an SPJ named MONTHLYORDERS, which has one IN parameter represented by a literal and one OUT parameter represented by an unnamed parameter, ?:
CALL sales.monthlyorders(3,?);
-
This CALL statement executes a stored procedure, which accepts one IN parameter (a date literal), returns one OUT parameter (a row from the column, NUM_ORDERS), and returns two result sets:
CALL sales.ordersummary('01/01/2001', ?); NUM_ORDERS -------------------- 13 ORDERNUM NUM_PARTS AMOUNT ORDER_DATE LAST_NAME ---------- -------------- --------------- ---------- ------------------ 100210 4 19020.00 2006-04-10 HUGHES 100250 4 22625.00 2006-01-23 HUGHES 101220 4 45525.00 2006-07-21 SCHNABL 200300 3 52000.00 2006-02-06 SCHAEFFER 200320 4 9195.00 2006-02-17 KARAJAN 200490 2 1065.00 2006-03-19 WEIGL . . . --- 13 row(s) selected. ORDERNUM PARTNUM UNIT_PRICE QTY_ORDERED PARTDESC ---------- -------- ------------ ----------- ------------------ 100210 2001 1100.00 3 GRAPHIC PRINTER,M1 100210 2403 620.00 6 DAISY PRINTER,T2 100210 244 3500.00 3 PC GOLD, 30 MB 100210 5100 150.00 10 MONITOR BW, TYPE 1 100250 6500 95.00 10 DISK CONTROLLER 100250 6301 245.00 15 GRAPHIC CARD, HR . . . --- 70 row(s) selected. --- SQL operation complete.
3.6. COMMIT WORK Statement
The COMMIT WORK statement commits any changes to objects made during the current transaction and ends the transaction. See Transaction Management.
WORK is an optional keyword that has no effect.
COMMIT WORK issued outside of an active transaction generates error 8605.
COMMIT [WORK]
3.6.1. Considerations for COMMIT WORK
BEGIN WORK starts a transaction. COMMIT WORK or ROLLBACK WORK ends a transaction.
3.6.2. Example of COMMIT WORK
Suppose that your application adds information to the inventory. You have received 24 terminals from a new supplier and want to add the supplier and update the quantity on hand. The part number for the terminals is 5100, and the supplier is assigned supplier number 17. The cost of each terminal is $800.
The transaction must add the order for terminals to PARTSUPP, add the supplier to the SUPPLIER table, and update QTY_ON_HAND in PARTLOC. After the INSERT and UPDATE statements execute successfully, you commit the transaction, as shown:
-- This statement initiates a transaction.
BEGIN WORK;
--- SQL operation complete.
-- This statement inserts a new entry into PARTSUPP.
INSERT INTO invent.partsupp
VALUES (5100, 17, 800.00, 24);
--- 1 row(s) inserted.
-- This statement inserts a new entry into SUPPLIER.
INSERT INTO invent.supplier
VALUES (17, 'Super Peripherals','751 Sanborn Way',
'Santa Rosa', 'California', '95405');
--- 1 row(s) inserted.
-- This statement updates the quantity in PARTLOC.
UPDATE invent.partloc
SET qty_on_hand = qty_on_hand + 24
WHERE partnum = 5100 AND loc_code = 'G43';
--- 1 row(s) updated.
-- This statement ends a transaction.
COMMIT WORK;
--- SQL operation complete.
3.7. CONTROL QUERY CANCEL Statement
The CONTROL QUERY CANCEL statement cancels an executing query that you identify with a query ID. You can execute the CONTROL QUERY CANCEL statement in a client-based tool like TrafCI or through any ODBC or JDBC application.
CONTROL QUERY CANCEL is a Trafodion SQL extension.
CONTROL QUERY CANCEL QID query-id [COMMENT 'comment-text']
3.7.1. Syntax Description of CONTROL QUERY CANCEL
-
query-id
specifies the query ID of an executing query, which is a unique identifier generated by the SQL compiler.
-
'comment-text'
specifies an optional comment to be displayed in the canceled query’s error message.
3.7.2. Considerations for CONTROL QUERY CANCEL
Benefits of CONTROL QUERY CANCEL
For many queries, the CONTROL QUERY CANCEL statement allows the termination of the query without stopping the master executor process (MXOSRVR). This type of cancellation has these benefits over standard ODBC/JDBC cancel methods:
-
An ANSI-defined error message is returned to the client session, and SQLSTATE is set to HY008.
-
Important cached objects persist after the query is canceled, including the master executor process and its compiler, the compiled statements cached in the master, and the compiler’s query cache and its cached metadata and histograms.
-
The client does not need to reestablish its connection, and its prepared statements are preserved.
-
When clients share connections using a middle-tier application server, the effects of canceling one client’s executing query no longer affect other clients sharing the same connection.
Restrictions on CONTROL QUERY CANCEL
Some executing queries may not respond to a CONTROL QUERY CANCEL statement within a 60-second interval. For those queries, Trafodion SQL stops their ESP processes if there are any. If this action allows the query to be canceled, you will see all the benefits listed above.
If the executing query does not terminate within 120 seconds after the CONTROL QUERY CANCEL statement is issued, Trafodion SQL stops the master executor process, terminating the query and generating a lost connection error. In this case, you will not see any of the benefits listed above. Instead, you will lose your connection and will need to reconnect and re-prepare the query. This situation often occurs with the CALL, DDL, and utility statements and rarely with other statements.
The CONTROL QUERY CANCEL statement does not work with these statements:
-
Unique queries, which operate on a single row and a single partition
-
Queries that are not executing, such as a query that is being compiled
-
CONTROL QUERY DEFAULT, BEGIN WORK, COMMIT WORK, ROLLBACK WORK, and EXPLAIN statements
-
Statically compiled metadata queries
-
Queries executed in anomalous conditions, such as queries without runtime statistics or without a query ID
Required Privileges
To issue a CONTROL QUERY CANCEL statement, one of the following must be true:
-
You are DB ROOT.
-
You own (that is, issued) the query.
-
You have the QUERY_CANCEL component privilege for the SQL_OPERATIONS component.
3.7.3. Example of CONTROL QUERY CANCEL
This CONTROL QUERY CANCEL statement cancels a specified query and provides a comment concerning the cancel operation:
control query cancel qid
MXID11000010941212288634364991407000000003806U3333300_156016_S1 comment
'Query is consuming too many resources.';
In a separate session, the client that issued the query will see this error message indicating that the query has been canceled:
>>execute s1;
*** ERROR[8007] The operation has been canceled. Query is consuming too many resources.
3.8. CONTROL QUERY DEFAULT Statement
The CONTROL QUERY DEFAULT statement changes the default settings for the current process. You can execute the CONTROL QUERY DEFAULT statement in a client-based tool like TrafCI or through any ODBC or JDBC application.
CONTROL QUERY DEFAULT is a Trafodion SQL extension.
{ CONTROL QUERY DEFAULT | CQD } control-default-option
control-default-option is:
attribute {'attr-value' | RESET}
3.8.1. Syntax Description of CONTROL QUERY DEFAULT
-
attribute
is a character string that represents an attribute name. For descriptions of these attributes, see the Trafodion Control Query Default (CQD) Reference Guide.
-
attr-value
is a character string that specifies an attribute value. You must specify attr-value as a quoted string—even if the value is a number.
-
RESET
specifies that the attribute that you set by using a CONTROL QUERY DEFAULT statement in the current session is to be reset to the value or values in effect at the start of the current session.
3.8.2. Considerations for CONTROL QUERY DEFAULT
Scope of CONTROL QUERY DEFAULT
The result of the execution of a CONTROL QUERY DEFAULT statement stays in effect until the current process terminates or until the execution of another statement for the same attribute overrides it.
CQDs are applied at compile time, so CQDs do not affect any statements that are already prepared. For example:
PREPARE x FROM SELECT * FROM t;
CONTROL QUERY DEFAULT SCHEMA 'myschema';
EXECUTE x; -- uses the default schema SEABASE
SELECT * FROM t2; -- uses MYSCHEMA;
PREPARE y FROM SELECT * FROM t3;
CONTROL QUERY DEFAULT SCHEMA 'seabase';
EXECUTE y; -- uses MYSCHEMA;
3.8.3. Examples of CONTROL QUERY DEFAULT
-
Increase the cache refresh time for the histogram cache to two hours (7,200 minutes).
CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL '7200';
-
Reset the CACHE_HISTOGRAMS_REFRESH_INTERVAL attribute to its initial value in the current process:
CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL RESET;
3.9. CREATE FUNCTION Statement
The CREATE FUNCTION statement registers a user-defined function (UDF) written in C as a function within a Trafodion database. Currently, Trafodion supports the creation of scalar UDFs, which return a single value or row when invoked. Scalar UDFs are invoked as SQL expressions in the SELECT list or WHERE clause of a SELECT statement.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE FUNCTION function-ref ([parameter-declaration[, parameter-declaration]...])
{RETURN | RETURNS}
(return-parameter-declaration[, return-parameter-declaration]...)
EXTERNAL NAME 'character-string-literal'
LIBRARY [[catalog-name.]schema-name.]library-name
[language c]
[parameter style sql]
[no sql]
[not deterministic | deterministic]
[final call | no final call]
[no state area | state area size]
[no parallelism | allow any parallelism]
function-ref is:
[[catalog-name.]schema-name.]function-name
parameter-declaration is:
[in] [sql-parameter-name] sql-datatype
return-parameter-declaration is:
[out] [sql-parameter-name] sql-datatype
3.9.1. Syntax Description of CREATE FUNCTION
-
function-ref ( [parameter-declaration[,parameter-declaration]…] )
specifies the name of the function and any SQL parameters that correspond to the signature of the external function.
-
function-ref
specifies an ANSI logical name of the form:
[[_catalog-name_.]schema-name.]function-name
where each part of the name is a valid sql identifier with a maximum of 128 characters. for more information, see identifiers and database object names.
specify a name that is unique and does not exist for any procedure or function in the same schema.
if you do not fully qualify the function name, trafodion sql qualifies it according to the schema of the current session.
-
parameter-declaration
specifies an sql parameter that corresponds to the signature of the external function:
[in] [sql-parameter-name] sql-datatype
-
in
specifies that the parameter passes data to the function.
-
sql-parameter-name
specifies an sql identifier for the parameter. for more information, see identifiers.
-
-
-
sql-datatype
specifies an sql data type that corresponds to the data type of the parameter in the signature of the external function. sql-datatype is one of the supported sql data types in trafodion. see data types.
-
{return | returns} (return-parameter-declaration[,return-parameter-declaration]…)
specifies the type of output of the function.
-
return-parameter-declaration
specifies an sql parameter for an output value:
[out] [sql-parameter-name] sql-datatype
-
-
-
out
specifies that the parameter accepts data from the function.
-
sql-parameter-name
specifies an sql identifier for the return parameter. for more information, see identifiers.
-
sql-datatype
specifies an sql data type for the return parameter. sql-datatype is one of the supported sql data types in trafodion. see data types.
-
external name 'method-name'
specifies the case-sensitive name of the external function’s method.
-
library [[_catalog-name_.]schema-name.]library-name
specifies the ANSI logical name of a library containing the external function. if you do not fully qualify the library name, trafodion sql qualifies it according to the schema of the current session.
-
language c
specifies that the external function is written in the c language. this clause is optional.
-
parameter style sql
specifies that the run-time conventions for arguments passed to the external function are those of the sql language. this clause is optional.
-
no sql
specifies that the function does not perform sql operations. this clause is optional.
-
deterministic | not deterministic
specifies whether the function always returns the same values for out parameters for a given set of argument values (deterministic, the default behavior) or does not return the same values (not deterministic). if the function is deterministic, trafodion sql is not required to execute the function each time to produce results; instead, trafodion sql caches the results and reuses them during subsequent executions, thus optimizing the execution.
-
final call | no final call
specifies whether or not a final call is made to the function. a final call enables the function to free up system resources. the default is final call.
-
no state area | state area size
specifies whether or not a state area is allocated to the function. size is an integer denoting memory in bytes. acceptable values range from 0 to 16000. the default is no state area.
-
no parallelism | allow any parallelism
specifies whether or not parallelism is applied when the function is invoked. the default is allow any parallelism.
-
3.9.2. Considerations for CREATE FUNCTION
Required Privileges
To issue a CREATE FUNCTION statement, one of the following must be true:
-
You are DB ROOT.
-
You are creating the function in a shared schema, and you have the USAGE (or ALL) privilege on the library that will be used in the creation of the function. The USAGE privilege provides you with read access to the library’s underlying library file.
-
You are the private schema owner and have the USAGE (or ALL) privilege on the library that will be used in the creation of the function. The USAGE privilege provides you with read access to the library’s underlying library file.
-
You have the CREATE or CREATE_ROUTINE component level privilege for the SQL_OPERATIONS component and have the USAGE (or ALL) privilege on the library that will be used in the creation of the function. The USAGE privilege provides you with read access to the library’s underlying library file.
In this case, if you create a function in a private schema, it will be owned by the schema owner.
3.9.3. Examples of CREATE FUNCTION
-
This CREATE FUNCTION statement creates a function that adds two integers:
create function add2 (int, int) returns (total_value int) external name 'add2' library myudflib;
-
This CREATE FUNCTION statement creates a function that returns the minimum, maximum, and average values of five input integers:
create function mma5 (int, int, int, int, int) returns (min_value int, max_value int, avg_value int) external name 'mma5' library myudflib;
-
This CREATE FUNCTION statement creates a function that reverses an input string of at most 32 characters:
create function reverse (varchar(32)) returns (reversed_string varchar(32)) external name 'reverse' library myudflib;
3.10. CREATE INDEX Statement
The CREATE INDEX statement creates an SQL index based on one or more columns of a table or table-like object. The CREATE VOLATILE INDEX statement creates an SQL index with a lifespan that is limited to the SQL session that the index is created. Volatile indexes are dropped automatically when the session ends. See Indexes.
CREATE INDEX is a Trafodion SQL extension.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE [VOLATILE] INDEX index ON table
(column-name [ASC[ENDING] | DESC[ENDING]]
[,column-name [ASC[ENDING] | DESC[ENDING]]]...)
[HBASE_OPTIONS (hbase-options-list)]
[SALT LIKE TABLE]
hbase-options-list is:
hbase-option = 'value'[, hbase-option = 'value']...
3.10.1. Syntax Description of CREATE INDEX
-
index
is an SQL identifier that specifies the simple name for the new index. You cannot qualify index with its schema name. Indexes have their own name space within a schema, so an index name might be the same as a table or constraint name. However, no two indexes in a schema can have the same name.
-
table
is the name of the table for which to create the index. See Database Object Names.
-
column-name [ASC[ENDING] | DESC[ENDING]] [,column-name [ASC[ENDING] | DESC[ENDING]]]…
specifies the columns in table to include in the index. The order of the columns in the index need not correspond to the order of the columns in the table.
ASCENDING or DESCENDING specifies the storage and retrieval order for rows in the index. The default is ASCENDING.
Rows are ordered by values in the first column specified for the index. If multiple index rows share the same value for the first column, the values in the second column are used to order the rows, and so forth. If duplicate index rows occur in a non-unique index, their order is based on the sequence specified for the columns of the key of the underlying table. For ordering (but not for other purposes), nulls are greater than other values.
-
HBASE_OPTIONS (hbase-option = 'value'[, hbase-option = 'value']…)
a list of HBase options to set for the index. These options are applied independently of any HBase options set for the index’s table.
-
hbase-option = 'value'
is one of the these HBase options and its assigned value:
HBase Option Accepted Values1 BLOCKCACHE
'true' | 'false'
BLOCKSIZE
*'65536'( | 'positive-integer'
BLOOMFILTER
'NONE' | 'ROW' | 'ROWCOL'
CACHE_BLOOMS_ON_WRITE
'true' | 'false'
CACHE_DATA_ON_WRITE
'true' | 'false'
CACHE_INDEXES_ON_WRITE
'true' | 'false'
COMPACT
'true' | 'false'
COMPACT_COMPRESSION
'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'
COMPRESSION
'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'
DATA_BLOCK_ENCODING
'DIFF' | 'FAST_DIFF' | 'NONE' | 'PREFIX'
DURABILITY
'USE_DEFAULT' | 'SKIP_WAL' | 'ASYNC_WAL' | 'SYNC_WAL' | 'FSYNC_WAL'
EVICT_BLOCKS_ON_CLOSE
'true' | 'false'
IN_MEMORY
'true' | 'false'
KEEP_DELETED_CELLS
'true' | 'false'
MAX_FILESIZE
'positive-integer'
MAX_VERSIONS
'1' | 'positive-integer'
MEMSTORE_FLUSH_SIZE
'positive-integer'
MIN_VERSIONS
'0' | 'positive-integer'
PREFIX_LENGTH_KEY
'positive-integer', which should be less than maximum length of the key for the table. It applies only if the SPLIT_POLICY is
KeyPrefixRegionSplitPolicy
.REPLICATION_SCOPE
'0' | '1'
SPLIT_POLICY
'org.apache.hadoop.hbase.regionserver.
ConstantSizeRegionSplitPolicy' |
'org.apache.hadoop.hbase.regionserver.
IncreasingToUpperBoundRegionSplitPolicy' |
'org.apache.hadoop.hbase.regionserver.
KeyPrefixRegionSplitPolicy'TTL
'-1' (forever) | 'positive-integer'
1 Values in boldface are default values.
-
SALT LIKE TABLE
causes the index to use the same salting scheme (that is,
SALT USING num PARTITIONS [ON (column[, column]…)])
as its base table.
-
3.10.2. Considerations for CREATE INDEX
Indexes are created under a single transaction. When an index is created, the following steps occur:
-
Transaction begins (either a user-started transaction or a system-started transaction).
-
Rows are written to the metadata.
-
Physical labels are created to hold the index (as non audited).
-
The base table is locked for read shared access which prevents inserts, updates, and deletes on the base table from occurring.
-
The index is loaded by reading the base table for read uncommitted access using side tree inserts.
A side tree insert is a fast way of loading data that can perform specialized optimizations because the partitions are not audited and empty. -
After load is complete, the index audit attribute is turned on and it is attached to the base table (to bring the index on-line).
-
The transaction is committed, either by the system or later by the requester.
If the operation fails after basic semantic checks are performed, the index no longer exists and the entire transaction is rolled back even if it is a user-started transaction.
Authorization and Availability Requirements
An index always has the same security as the table it indexes.
CREATE INDEX locks out INSERT, DELETE, and UPDATE operations on the table being indexed. If other processes have rows in the table locked when the operation begins, CREATE INDEX waits until its lock request is granted or timeout occurs.
You cannot access an index directly.
Required Privileges
To issue a CREATE INDEX statement, one of the following must be true:
-
You are DB ROOT.
-
You are creating the table in a shared schema.
-
You are the private schema owner.
-
You are the owner of the table.
-
You have the ALTER, ALTER_TABLE, CREATE, or CREATE_INDEX component privilege for the SQL_OPERATIONS component.
In this case, if you create an index in a private schema, it will be owned by the schema owner.
Limits on Indexes
For non-unique indexes, the sum of the lengths of the columns in the index plus the sum of the length of the clustering key of the underlying table cannot exceed 2048 bytes.
No restriction exists on the number of indexes per table.
3.10.3. Examples of CREATE INDEX
-
This example creates an index on two columns of a table:
CREATE INDEX xempname ON persnl.employee (last_name, first_name);
3.11. CREATE LIBRARY Statement
The CREATE LIBRARY statement registers a library object in a Trafodion database. A library object can be an SPJ’s JAR file or a UDF’s library file.
CREATE LIBRARY is a Trafodion SQL extension.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE LIBRARY [[catalog-name.]schema-name.]library-name
file 'library-filename'
[host name 'host-name']
[local file 'host-filename']
3.11.1. Syntax Description of CREATE LIBRARY
-
[[_catalog-name_.]schema-name.]library-name
specifies the ANSI logical name of the library object, where each part of the name is a valid sql identifier with a maximum of 128 characters. specify a name that is unique and does not exist for libraries in the same schema. if you do not fully qualify the library name, trafodion sq qualifies it according to the schema of the current session. for more information, see identifiers and database object names.
-
file 'library-filename'
specifies the full path of a deployed library file, which either an SPJ’s jar file or a UDF’s library file.
note: make sure to upload the library file to the trafodion cluster and then copy the library file to the same directory on all the nodes in the cluster before running the create library statement. otherwise, you will see an error message indicating that the jar or dll file was not found.
-
host name 'host-name'
specifies the name of the client host machine where the deployed file resides.
-
local file 'host-filename'
specifies the path on the client host machine where the deployed file is stored.
3.11.2. Considerations for CREATE LIBRARY
-
A library object cannot refer to a library file referenced by another library object. If the library-filename is in use by another library object, the CREATE LIBRARY command will fail.
-
The library-filename must specify an existing file. Otherwise, the CREATE LIBRARY command will fail.
-
The CREATE LIBRARY command does not verify that the specified library-filename is a valid executable file.
-
HOST NAME and LOCAL FILE are position dependent.
Required Privileges
To issue a CREATE LIBRARY statement, one of the following must be true:
-
You are DB ROOT.
-
You are creating the library in a shared schema and have the MANAGE_LIBRARY privilege.
-
You are the private schema owner and have the MANAGE_LIBRARY privilege.
-
You have the CREATE or CREATE_LIBRARY component privilege for the SQL_OPERATIONS component and have the MANAGE_LIBRARY privilege.
In this case, if you create a library in a private schema, it will be owned by the schema owner.
3.11.3. Examples of CREATE LIBRARY
-
This CREATE LIBRARY statement registers a library named SALESLIB in the SALES schema for a JAR file (SPJs):
CREATE LIBRARY sales.saleslib FILE '/opt/home/trafodion/spjjars/Sales.jar';
-
This CREATE LIBRARY statement registers a library named MYUDFS in the default schema for a library file (UDFs):
CREATE LIBRARY myudfs FILE $UDFLIB;
3.12. CREATE PROCEDURE Statement
The CREATE PROCEDURE statement registers a Java method as a stored procedure in Java (SPJ) within a Trafodion database.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE PROCEDURE procedure-ref([sql-parameter-list])
EXTERNAL NAME 'java-method-name [java-signature]'
LIBRARY [[catalog-name.]schema-name.]library-name
[external security external-security-type]
language java
parameter style java
[no sql | contains sql | modifies sql data | reads sql data]
[dynamic result sets integer]
[transaction required | no transaction required]
[deterministic | not deterministic]
[no isolate | isolate]
procedure-ref is:
[[catalog-name.]schema-name.]procedure-name
sql-parameter-list is:
sql-parameter[, sql-parameter]...
sql-parameter is:
[parameter-mode] [sql-identifier] sql-datatype
parameter-mode is:
in
| out
| inout
java-method-name is:
[package-name.]class-name.method-name
java-signature is:
([java-parameter-list])
java-parameter-list is:
java-datatype[, java-datatype]...
external-security-type is:
definer
| invoker
delimited variables in this syntax diagram are case-sensitive. case-sensitive variables include java-method-name, java-signature, and class-file-path, and any delimited part of the procedure-ref. the remaining syntax is not case-sensitive. |
3.12.1. Syntax Description of CREATE PROCEDURE
-
procedure-ref([sql-parameter[, sql-parameter]…])
specifies the name of the stored procedure in Java (SPJ) and any SQL parameters that correspond to the signature of the SPJ method.
-
procedure-ref
specifies an ANSI logical name of the form:
[[_catalog-name_.]schema-name.]procedure-name
where each part of the name is a valid SQL identifier with a maximum of 128 characters. For more information, see identifiers and database object names.
specify a name that is unique and does not exist for any procedure or function in the same schema. Trafodion does not support the overloading of procedure names. That is, you cannot register the same procedure name more than once with different underlying SPJ methods.
If you do not fully qualify the procedure name, then Trafodion qualifies it according to the schema of the current session.
-
sql-parameter
specifies an SQL parameter that corresponds to the signature of the SPJ method:
[parameter-mode] [sql-identifier] sql-datatype
-
parameter-mode
specifies the mode
in
,out
, orinout
of a parameter. The default isin
.-
in
specifies a parameter that passes data to an SPJ.
-
out
specifies a parameter that accepts data from an SPJ. The parameter must be an array.
-
inout
specifies a parameter that passes data to and accepts data from an SPJ. The parameter must be an array.
-
-
sql-identifier
specifies an SQL identifier for the parameter. For more information, see identifiers.
-
sql-datatype
specifies an SQL data type that corresponds to the Java parameter of the SPJ method.
sql-datatype can be:
sql data type maps to java data type… char[acter]
char[acter] varying
varchar
pic[ture] x1
nchar
nchar varying
national char[acter]
national char[acter] varyingjava.lang.string
date
java.sql.date
time
java.sql.time
timestamp
java.sql.timestamp
dec2
pic[ture] s93
numeric (including numeric with a precision greater than eighteen)2java.math.bigdecimal
smallint2
short
int2
int or java.lang.integer4
largeint2
long or java.lang.long4
float
double or java.lang.double4
real
float or java.lang.float4
double precision
double or java.lang.double4
-
the trafodion database stores pic x as a char data type.
-
numeric data types of sql parameters must be signed, which is the default in the trafodion database.
-
the trafodion database stores pic s9 as a decimal or numeric data type.
-
by default, the sql data type maps to a java primitive type. the sql data type maps to a java wrapper class only if you specify the wrapper class in the java signature of the external name clause.
for more information, see data types.
-
-
-
-
external name 'java-method-name [java-signature]'
-
java-method-name
specifies the case-sensitive name of the SPJ method of the form:
class-name.method-name
The Java method must exist in a Java class file, class-name.class, within a library registered in the database. The Java method must be defined as
public
andstatic
and have a return type ofvoid
.If the class file that contains the SPJ method is part of a package, then you must also specify the package name. If you do not specify the package name, the create procedure statement fails to register the SPJ.
-
java-signature
specifies the signature of the SPJ method and consists of:
([java-datatype[, java-datatype]…])
The Java signature is necessary only if you want to specify a Java wrapper class (for example,
java.lang.integer
) instead of a java primitive data type (for example,int
). An SQL data type maps to a Java primitive data type by default.The Java signature is case-sensitive and must be placed within parentheses, such as
(java.lang.integer, java.lang.integer
). The signature must specify each of the parameter data types in the order they appear in the Java method definition within the class file. Each Java data type that corresponds to an out or inout parameter must be followed by empty square brackets ([ ]
), such asjava.lang.integer[]
.-
java-datatype
Specifies a mappable Java data type. For the mapping of the Java data types to SQL data types, see sql-datatype.
-
-
-
library [[_catalog-name_.]schema-name.]library-name
specifies the ANSI logical name of a library containing the SPJ method. If you do not fully qualify the library name, then Trafodion qualifies it according to the schema of the current session.
-
external security external-security-type
determines the privileges, or rights, that users have when executing (or calling) the SPJ. An SPJ can have one of these types of external security:
-
invoker
determines that users can execute, or invoke, the stored procedure using the privileges of the user who invokes the stored procedure. This behavior is referred to as invoker rights and is the default behavior if external security is not specified. Invoker rights allow a user who has the execute privilege on the SPJ to call the SPJ using his or her existing privileges. In this case, the user must be granted privileges to access the underlying database objects on which the SPJ operates.Granting a user privileges to the underlying database objects gives the user direct access to those database objects, which could pose a risk to more sensitive or critical data to which users should not have access. For example, an SPJ might operate on a subset of the data in an underlying database object but that database object might contain other more sensitive or critical data to which users should not have access. -
definer
determines that users can execute, or invoke, the stored procedure using the privileges of the user who created the stored procedure. This behavior is referred to as definer rights. The advantage of definer rights is that users are allowed to manipulate data by invoking the stored procedure without having to be granted privileges to the underlying database objects. That way, users are restricted from directly accessing or manipulating more sensitive or critical data in the database. However, be careful about the users to whom you grant execute privilege on an SPJ with definer external security because those users will be able to execute the SPJ without requiring privileges to the underlying database objects.
-
-
language java
specifies that the external user-defined routine is written in the java language.
-
parameter style java
specifies that the run-time conventions for arguments passed to the external user-defined routine are those of the Java language.
-
no sql
specifies that the SPJ cannot perform SQL operations.
-
contains sql | modifies sql data | reads sql data
specifies that the SPJ can perform SQL operations. All these options behave the same as
contains sql
, meaning that the SPJ can read and modify SQL data. Use one of these options to register a method that contains SQL statements. Ff you do not specify an SQL access mode, then the default iscontains sql
. -
dynamic result sets integer
specifies the maximum number of result sets that the SPJ can return. This option is applicable only if the method signature contains a
java.sql.resultset[]
object. If the method contains a result set object, then the valid range is 1 to 255 inclusive. The actual number of result sets returned by the SPJ method can be fewer than or equal to this number. If you do not specify this option, then the default value is 0 (zero), meaning that the SPJ does not return result sets. -
transaction required | no transaction required
determines whether the SPJ must run in a transaction inherited from the calling application (
transaction required
, the default option) or whether the SPJ runs without inheriting the calling application’s transaction (no transaction required
). Typically, you want the stored procedure to inherit the transaction from the calling application. However, if the SPJ method does not access the database or if you want the stored procedure to manage its own transactions, then you should set the stored procedure’s transaction attribute to no transaction required. For more information, see effects of the transaction attribute on SPJs.
-
deterministic | not deterministic
specifies whether the SPJ always returns the same values for out and inout parameters for a given set of argument values (
deterministic
) or does not return the same values (not deterministic
, the default option). If you specifydeterministic
, Trafodion is not required to call the SPJ each time to produce results; instead, Trafodion caches the results and reuses them during subsequent calls, thus optimizing the CALL statement. -
no isolate | isolate
specifies that the SPJ executes either in the environment of the database server (
no isolate
) or in an isolated environment (isolate
, the default option). Trafodion allows both options but always executes the SPJ in the UDR server process (isolate
).
3.12.2. Considerations for CREATE PROCEDURE
Required Privileges
To issue a CREATE PROCEDURE statement, one of the following must be true:
-
You are DB ROOT.
-
You are creating the procedure in a shared schema, and you have the USAGE (or ALL) privilege on the library that will be used in the creation of the stored procedure. The USAGE privilege provides you with read access to the library’s underlying JAR file, which contains the SPJ Java method.
-
You are the private schema owner and have the USAGE (or ALL) privilege on the library that will be used in the creation of the stored procedure. The USAGE privilege provides you with read access to the library’s underlying JAR file, which contains the SPJ Java method.
-
You have the CREATE or CREATE_ROUTINE component level privilege for the SQL_OPERATIONS component and have the USAGE (or ALL) privilege on the library that will be used in the creation of the stored procedure. The USAGE privilege provides you with read access to the library’s underlying JAR file, which contains the SPJ Java method.
In this case, if you create a stored procedure in a private schema, it will be owned by the schema owner.
Effects of the Transaction Attribute on SPJs
Transaction Required
Using Transaction Control Statements or Methods
If you specify TRANSACTION REQUIRED (the default option), a CALL statement automatically initiates a transaction if there is
no active transaction. In this case, you should not use transaction control statements (or equivalent JDBC transaction methods)
in the SPJ method. Transaction control statements include COMMIT WORK and ROLLBACK WORK, and the equivalent JDBC transaction
methods are Connection.commit()
and Connection.rollback()
. If you try to use transaction control statements or methods in an
SPJ method when the stored procedure’s transaction attribute is set to TRANSACTION REQUIRED, then the transaction control statements
or methods in the SPJ method are ignored, and the Java virtual machine (JVM) does not report any errors or warnings. When the
stored procedure’s transaction attribute is set to TRANSACTION REQUIRED, then you should rely on the transaction control statements
or methods in the application that calls the stored procedure and allow the calling application to manage the transactions.
Committing or Rolling Back a Transaction
If you do not use transaction control statements in the calling application, then the transaction initiated by the CALL statement might not automatically commit or roll back changes to the database. When AUTOCOMMIT is ON (the default setting), the database engine automatically commits or rolls back any changes made to the database at the end of the CALL statement execution. However, when AUTOCOMMIT is OFF, the current transaction remains active until the end of the client session or until you explicitly commit or roll back the transaction. To ensure an atomic unit of work when calling an SPJ, use the COMMIT WORK statement in the calling application to commit the transaction when the CALL statement succeeds, and use the ROLLBACK WORK statement to roll back the transaction when the CALL statement fails.
No Transaction Required
In some cases, you might not want the SPJ method to inherit the transaction from the calling application. Instead, you might want the stored procedure to manage its own transactions or to run without a transaction. Not inheriting the calling application’s transaction is useful in these cases:
-
The stored procedure performs several long-running operations, such as multiple DDL or table maintenance operations, on the database. In this case, you might want to commit those operations periodically from within the SPJ method to avoid locking tables for a long time.
-
The stored procedure performs certain SQL operations that must run without an active transaction. For example, INSERT, UPDATE, and DELETE statements with the WITH NO ROLLBACK option are rejected when a transaction is already active, as is the case when a stored procedure inherits a transaction from the calling application. The PURGEDATA utility is also rejected when a transaction is already active.
-
The stored procedure does not access the database. In this case, the stored procedure does not need to inherit the transaction from the calling application. By setting the stored procedure’s transaction attribute to NO TRANSACTION REQUIRED, you can avoid the overhead of the calling application’s transaction being propagated to the stored procedure.
In these cases, you should set the stored procedure’s transaction attribute to NO TRANSACTION REQUIRED when creating the stored procedure.
If you specify NO TRANSACTION REQUIRED and if the SPJ method creates a JDBC default connection, that connection will have autocommit
enabled by default. You can either use the autocommit transactions or disable autocommit (conn.setAutoCommit(false);) and use the
JDBC transaction methods, Connection.commit()
and Connection.rollback()
, to commit or roll back work where needed.
3.12.3. Examples of CREATE PROCEDURE
-
This CREATE PROCEDURE statement registers an SPJ named LOWERPRICE, which does not accept any arguments:
SET SCHEMA SALES; CREATE PROCEDURE lowerprice() EXTERNAL NAME 'Sales.lowerPrice' LIBRARY saleslib LANGUAGE JAVA PARAMETER STYLE JAVA MODIFIES SQL DATA;
Because the procedure name is not qualified by a catalog and schema, Trafodion qualifies it according to the current session settings, where the catalog is TRAFODION (by default) and the schema is set to SALES. Since the procedure needs to be able to read and modify SQL data, MODIFIES SQL DATA is specified in the CREATE PROCEDURE statement.
To call this SPJ, use this CALL statement:
CALL lowerprice();
The LOWERPRICE procedure lowers the price of items with 50 or fewer orders by 10 percent in the database.
-
This CREATE PROCEDURE statement registers an SPJ named TOTALPRICE, which accepts three input parameters and returns a numeric value, the total price to an INOUT parameter:
CREATE PROCEDURE trafodion.sales.totalprice(IN qty NUMERIC (18), IN rate VARCHAR (10), INOUT price NUMERIC (18,2)) EXTERNAL NAME 'Sales.totalPrice' LIBRARY sales.saleslib LANGUAGE JAVA PARAMETER STYLE JAVA NO SQL;
To call this SPJ in TrafCI, use these statements:
SET PARAM ?p 10.00; CALL sales.totalprice(23, 'standard', ?p); p -------------------- 253.97 --- SQL operation complete.
Since the procedure does not read and modify any SQL data, NO SQL is specified in the CREATE PROCEDURE statement.
-
This CREATE PROCEDURE statement registers an SPJ named MONTHLYORDERS, which accepts an integer value for the month and returns the number of orders:
CREATE PROCEDURE sales.monthlyorders(IN INT, OUT number INT) EXTERNAL NAME 'Sales.numMonthlyOrders (int, java.lang.Integer[])' LIBRARY sales.saleslib LANGUAGE JAVA PARAMETER STYLE JAVA READS SQL DATA;
Because the OUT parameter is supposed to map to the Java wrapper class, java.lang.Integer, you must specify the Java signature in the EXTERNAL NAME clause. To invoke this SPJ, use this CALL statement:
CALL sales.monthlyorders(3, ?); ORDERNUM ----------- 4 --- SQL operation complete.
-
This CREATE PROCEDURE statement registers an SPJ named ORDERSUMMARY, which accepts a date (formatted as a string) and returns information about the orders on or after that date.
CREATE PROCEDURE sales.ordersummary(IN on_or_after_date VARCHAR (20), OUT num_orders LARGEINT) EXTERNAL NAME 'Sales.orderSummary (int, long[])' LIBRARY sales.saleslib EXTERNAL SECURITY invoker LANGUAGE JAVA PARAMETER STYLE JAVA READS SQL DATA DYNAMIC RESULT SETS 2;
To invoke this SPJ, use this CALL statement:
CALL trafodion.sales.ordersummary('01-01-2014', ?);
The ORDERSUMMARY procedure returns this information about the orders on or after the specified date, 01-01-2014:
NUM_ORDERS -------------------- 13 ORDERNUM NUM_PARTS AMOUNT ORDER_DATE LAST_NAME -------- -------------------- -------------------- ---------- -------------------- 100210 4 19020.00 2014-04-10 HUGHES 100250 4 22625.00 2014-01-23 HUGHES 101220 4 45525.00 2014-07-21 SCHNABL ... ... ... ... ... --- 13 row(s) selected. ORDERNUM PARTNUM UNIT_PRICE QTY_ORDERED PARTDESC -------- ------- ---------- ----------- ------------------ 100210 244 3500.00 3 PC GOLD, 30 MB 100210 2001 1100.00 3 GRAPHIC PRINTER,M1 100210 2403 620.00 6 DAISY PRINTER,T2 ... ... ... ... ... --- 70 row(s) selected. --- SQL operation complete.
3.13. CREATE ROLE Statement
The CREATE ROLE statement creates an SQL role. See Roles.
CREATE ROLE role-name [ WITH ADMIN grantor ]
grantor is:
database-username
3.13.1. Syntax Description of CREATE ROLE
-
role-name
is an SQL identifier that specifies the new role. role-name is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers. role-name cannot be an existing role name, and it cannot be a registered database username. However, role-name can be a configured directory-service username.
-
WITH ADMIN grantor
specifies a role owner other than the current user. This is an optional clause.
-
grantor
specifies a registered database username to whom you assign the role owner.
3.13.2. Considerations for CREATE ROLE
-
To create a role, you must either be DB ROOT or have been granted the MANAGE_ROLES component privilege for SQL_OPERATIONS.
-
PUBLIC, SYSTEM, NONE, and database user names beginning with DB are reserved. You cannot specify a _role-name with any such name.
Role Ownership
You can give role ownership to a user by specifying the user in the WITH ADMIN grantor clause with the grantor as the user.
The role owner can perform these operations:
-
Grant and revoke the role to users.
-
Drop the role.
Role ownership is permanent. After you create the role, the ownership of the role cannot be changed or assigned to another user.
3.13.3. Examples of CREATE ROLE
-
To create a role and assign the current user as the role owner:
CREATE ROLE clerks;
-
To create a role and assign another user as the role owner:
CREATE ROLE sales WITH ADMIN cmiller;
3.14. CREATE SCHEMA Statement
The CREATE SCHEMA statement creates a schema in the database. See Schemas.
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE [schema-class] SCHEMA schema-clause
schema-class is:
[ PRIVATE | SHARED ]
schema-clause is:
{ schema-name [AUTHORIZATION authid] | AUTHORIZATION authid }
3.14.1. Syntax Description of CREATE SCHEMA
-
schema-class
indicates whether access to the schema is restricted to the authorization ID by default (PRIVATE) or whether any database user may add objects to the schema (SHARED). The default class is PRIVATE.
Schemas created in Trafodion Release 0.9 or earlier are SHARED schemas. -
schema-name
is a name for the new schema and is an SQL identifier that specifies a unique name that is not currently a schema name. This parameter is optional. However, if you do not specify a schema name, you must specify the authorization clause. If a schema name is not provided, the authorization ID is used for the schema name. If the authorization ID name matches an existing schema, the CREATE SCHEMA command fails.
-
authid
is the name of the database user or role will own and administer the schema. If this clause is not present, the current user becomes the schema owner.
3.14.2. Considerations for CREATE SCHEMA
Reserved Schema Names
Schema names that begin with a leading underscore (_) are reserved for future use.
AUTHORIZATION Clause
The AUTHORIZATION clause is optional. If you omit this clause, the current user becomes the schema owner.
An authorization ID is assigned to a schema name even if authorization is not enabled for the Trafodion database. However, no enforcement occurs unless authorization is enabled. |
The schema owner can perform operations on the schema and on objects within the schema. For example:
-
Alter DDL of objects
-
Drop the schema
-
Drop objects
-
Manage objects with utility commands such as UPDATE STATISTICS and PURGEDATA
Who Can Create a Schema
The privilege to create a schema is controlled by the component privilege CREATE_SCHEMA for the SQL_OPERATIONS component. By default, this privilege is granted to PUBLIC, but it can be revoked by DB ROOT.
When authorization is initialized, these authorization IDs are granted the CREATE_SCHEMA privilege:
-
PUBLIC
-
DB ROOT
-
DB ROOTROLE
DB ROOT or anyone granted the DB_ROOTROLE role can grant the CREATE_SCHEMA privilege.
3.14.3. Examples of CREATE SCHEMA
-
This example creates a private schema schema named MYSCHEMA, which will be owned by the current user:
CREATE SCHEMA myschema;
-
This example creates a shared schema and designates CliffG as the schema owner:
CREATE SHARED SCHEMA hockey_league AUTHORIZATION "CliffG";
-
This example creates a private schema and designates the role DBA as the schema owner:
CREATE PRIVATE SCHEMA contracts AUTHORIZATION DBA;
Users with the role DBA granted to them can grant access to objects in the CONTRACTS schema to other users and roles.
-
This example creates a schema named JSMITH:
CREATE PRIVATE SCHEMA AUTHORIZATION JSmith;
3.15. CREATE TABLE Statement
The CREATE TABLE statement creates a Trafodion SQL table, which is a mapping of a relational SQL table to an HBase table. The CREATE VOLATILE TABLE statement creates a temporary Trafodion SQL table that exists only during an SQL session. The CREATE TABLE AS statement creates a table based on the data attributes of a SELECT query and populates the table using the data returned by the SELECT query. See Tables.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE [VOLATILE] TABLE IF NOT EXISTS table
{ table-spec | like-spec }
[SALT USING num PARTITIONS [ON (column[, column]...)]]
[STORE BY {PRIMARY KEY | (key-column-list)}]
[HBASEOPTIONS (hbase-options-list)]
[LOAD IF EXISTS | NO LOAD]
[AS select-query]
table-spec is:
(table-element [,table-element]...)
table-element is:
column-definition
| [CONSTRAINT constraint-name] table-constraint
column-definition is:
column data-type
[DEFAULT default | NO DEFAULT]
[[constraint constraint-name] column-constraint]...
data-type is:
char[acter] [(length [characters])]
[character set char-set-name]
[upshift] [[not]casespecific]
| char[acter] varying (length [characters])
[character set char-set-name]
[upshift] [[not]casespecific]
| varchar (length) [character set char-set-name]
[upshift] [[not]casespecific]
| nchar (length) [characters] [upshift] [[not]casespecific]
| nchar varying(length [characters]) [upshift] [[not] casespecific]
| numeric [(precision [,scale])] [signed|unsigned]
| smallint [signed|unsigned]
| int[eger] [signed|unsigned]
| largeint
| dec[imal] [(precision [,scale])] [signed|unsigned]
| float [(precision)]
| real
| double precision
| date
| time [(time-precision)]
| timestamp [(timestamp-precision)]
| interval { start-field to end-field | single-field }
default is:
literal
| null
| currentdate
| currenttime
| currenttimestamp
column-constraint is:
not null
| unique
| primary key [asc[ending] | desc[ending]]
| CHECK (condition)
| REFERENCES ref-spec
table-constraint is:
UNIQUE (column-list)
| PRIMARY KEY (key-column-list)
| CHECK (condition)
| FOREIGN KEY (column-list) REFERENCES ref-spec
ref-spec is:
referenced-table [(column-list)]
column-list is:
column-name [,column-name]...
key-column-list is:
column-name [ASC[ENDING] | DESC[ENDING]]
[,column-name [ASC[ENDING] | DESC[ENDING]]]...
like-spec is:
LIKE source-table [include-option]
hbase-options-list is:
hbase-option = 'value'[, hbase-option = 'value']...
3.15.1. Syntax Description of CREATE TABLE
-
VOLATILE
specifies a volatile table, which is a table limited to the session that creates the table. After the session ends, the
-
IF NOT EXISTS
creates an HBase table if it does not already exist when the table is created. This option does not apply to volatile tables.
-
table
specifies the ANSI logical name of the table. See Database Object Names. This name must be unique among names of tables and views within its schema.
-
SALT USING num PARTITIONS [ON (column[, column]…)]
pre-splits the table into multiple regions when the table is created. Salting adds a hash value of the row key as a key prefix, thus avoiding hot spots for sequential keys. The number of partitions that you specify can be a function of the number of region servers present in the HBase cluster. You can specify a number from 2 to 1024. If you do not specify columns, the default is to use all primary key columns.
-
STORE BY { PRIMARY KEY | (key-column-list)}
specifies a set of columns on which to base the clustering key. The clustering key determines the order of rows within the physical file that holds the table. The storage order has an effect on how you can partition the object.
-
PRIMARY KEY
bases the clustering key on the primary key columns.
-
key-column-list
bases the clustering key on the columns in the key-column-list. The key columns in key-column-list must be specified as NOT NULL and must be the same as the primary key columns that are defined on the table. If STORE BY is not specified, then the clustering key is the PRIMARY KEY.
-
-
HBASE_OPTIONS (hbase-option = 'value'[, hbase-option = 'value']…)
a list of HBase options to set for the table.
-
hbase-option = 'value'
is one of the these HBase options and its assigned value:
HBase Option Accepted Values1 BLOCKCACHE
'true' | 'false'
BLOCKSIZE
'65536' | 'positive-integer'
BLOOMFILTER
'NONE' | 'ROW' | 'ROWCOL'
CACHE_BLOOMS_ON_WRITE
'true' | 'false'
CACHE_DATA_ON_WRITE
'true' | 'false'
CACHE_INDEXES_ON_WRITE
'true' | 'false'
COMPACT
'true' | 'false'
COMPACT_COMPRESSION
'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'
COMPRESSION
'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'
DATA_BLOCK_ENCODING
'DIFF' | 'FAST_DIFF' | 'NONE' | 'PREFIX'
DURABILITY
'USE_DEFAULT' | 'SKIP_WAL' | 'ASYNC_WAL' | 'SYNC_WAL' | 'FSYNC_WAL'
EVICT_BLOCKS_ON_CLOSE
'true' | 'false'
IN_MEMORY
'true' | 'false'
KEEP_DELETED_CELLS
'true' | 'false'
MAX_FILESIZE
'positive-integer'
MAX_VERSIONS
'1' | 'positive-integer'
MEMSTORE_FLUSH_SIZE
'positive-integer'
MIN_VERSIONS
'0' | 'positive-integer'
PREFIX_LENGTH_KEY
'positive-integer', which should be less than maximum length of the key for the table. It applies only if the SPLIT_POLICY is
KeyPrefixRegionSplitPolicy
.REPLICATION_SCOPE
'0' | '1'
SPLIT_POLICY
'org.apache.hadoop.hbase.regionserver.ConstantSizeRegionSplitPolicy' | 'org.apache.hadoop.hbase.regionserver.IncreasingToUpperBoundRegionSplitPolicy' | 'org.apache.hadoop.hbase.regionserver.KeyPrefixRegionSplitPolicy'
TTL
'-1' (forever) | 'positive-integer'
-
Values in boldface are default values.
-
-
-
LOAD IF EXISTS
loads data into an existing table. Must be used with AS select-query. See Considerations For LOAD IF EXISTS and NO LOAD options of CREATE TABLE AS.
-
NO LOAD
creates a table with the CREATE TABLE AS statement, but does not load data into the table. See Considerations for LOAD IF EXISTS and NO LOAD options of CREATE TABLE AS.
-
AS select-query
specifies a select query which is used to populate the created table. A select query can be any SQL select statement.
-
column data-type
specifies the name and data type for a column in the table. At least one column definition is required in a CREATE TABLE statement.
-
column is an SQL identifier. column must be unique among column names in the table. If the name is a Trafodion SQL reserved word, you must delimit it by enclosing it in double quotes. Such delimited parts are case-sensitive. For example: "join".
-
data-type is the data type of the values that can be stored in column. A default value must be of the same type as the column, including the character set for a character column. See "Data Types" Data type also includes case specific information, such as UPSHIFT.
-
-
[NOT] CASESPECIFIC
specifies that the column contains strings that are not case specific. The default is CASESPECIFIC. Comparison between two values is done in a case insensitive way only if both are case insensitive. This applies to comparison in a binary predicate, LIKE predicate, and POSITION/REPLACE string function searches.
-
DEFAULT default | NO DEFAULT
specifies a default value for the column or specifies that the column does not have a default value. See DEFAULT Clause.
-
CONSTRAINT constraint-name
specifies a name for the column or table constraint. constraint-name must have the same schema as table and must be unique among constraint names in its schema. If you omit the schema portions of the name you specify in constraint-name, Trafodion SQL expands the constraint name by using the schema for table. See Constraint Names and Database Object Names.
-
NOT NULL
is a column constraint that specifies that the column cannot contain nulls. If you omit NOT NULL, nulls are allowed in the column. If you specify both NOT NULL and NO DEFAULT, each row inserted in the table must include a value for the column. See Null.
-
UNIQUE, or, UNIQUE (column-list)
is a column or table constraint, respectively, that specifies that the column or set of columns cannot contain more than one occurrence of the same value or set of values. If you omit UNIQUE, duplicate values are allowed unless the column is part of the PRIMARY KEY.
-
column-list cannot include more than one occurrence of the same column. In addition, the set of columns that you specify on a UNIQUE constraint cannot match the set of columns on any other UNIQUE constraint for the table or on the PRIMARY KEY constraint for the table. All columns defined as unique must be specified as NOT NULL.
A UNIQUE constraint is enforced with a unique index. If there is already a unique index on column-list, Trafodion SQL uses that index. If a unique index does not exist, the system creates a unique index.
-
-
PRIMARY KEY [ASC[ENDING] | DESC[ENDING]], or, PRIMARY KEY (key-column-list)
is a column or table constraint, respectively, that specifies a column or set of columns as the primary key for the table. key-column-list cannot include more than one occurrence of the same column.
ASCENDING and DESCENDING specify the direction for entries in one column within the key. The default is ASCENDING.
The PRIMARY KEY value in each row of the table must be unique within the table. A PRIMARY KEY defined for a set of columns implies that the column values are unique and not null. You can specify PRIMARY KEY only once on any CREATE TABLE statement.
Trafodion SQL uses the primary key as the clustering key of the table to avoid creating a separate, unique index to implement the primary key constraint.
A PRIMARY KEY constraint is required in Trafodion SQL.
-
CHECK (condition)
is a constraint that specifies a condition that must be satisfied for each row in the table. See Search Condition.
You cannot refer to the CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP function in a CHECK constraint, and you cannot use subqueries in a CHECK constraint.
-
REFERENCES ref-spec
specifies a REFERENCES column constraint. The maximum combined length of the columns for a REFERENCES constraint is 2048 bytes.
ref-spec is:
referenced-table [(column-list)]
-
referenced-table is the table referenced by the foreign key in a referential constraint. referenced-table cannot be a view. referenced-table cannot be the same as table. referenced-table corresponds to the foreign key in the table.
-
column-list specifies the column or set of columns in the referenced-table that corresponds to the foreign key in table. The columns in the column list associated with REFERENCES must be in the same order as the columns in the column list associated with FOREIGN KEY. If column-list is omitted, the referenced table’s PRIMARY KEY columns are the referenced columns.
A table can have an unlimited number of referential constraints, and you can specify the same foreign key in more than one referential constraint, but you must define each referential constraint separately. You cannot create self-referencing foreign key constraints.
-
-
FOREIGN KEY (column-list) REFERENCES ref-spec
is a table constraint that specifies a referential constraint for the table, declaring that a column or set of columns (called a foreign key) in table can contain only values that match those in a column or set of columns in the table specified in the REFERENCES clause.
The two columns or sets of columns must have the same characteristics (data type, length, scale, precision). Without the FOREIGN KEY clause, the foreign key in table is the column being defined; with the FOREIGN KEY clause, the foreign key is the column or set of columns specified in the FOREIGN KEY clause. For information about ref-spec, see REFERENCES ref-spec.
-
LIKE source-table [include-option]…
directs Trafodion SQL to create a table like the existing table, source-table, omitting constraints (with the exception of the NOT NULL and PRIMARY KEY constraints) and partitions unless the include-option clauses are specified.
-
source-table
is the ANSI logical name for the existing table and must be unique among names of tables and views within its schema.
-
include-option
-
WITH CONSTRAINTS
directs Trafodion SQL to use constraints from source-table. Constraint names for table are randomly generated unique names.
When you perform a CREATE TABLE LIKE, whether or not you include the WITH CONSTRAINTS clause, the target table will have all the NOT NULL column constraints that exist for the source table with different constraint names.
-
WITH PARTITIONS
directs Trafodion SQL to use partition definitions from source-table. Each new table partition resides on the same volume as its original source-table counterpart. The new table partitions do not inherit partition names from the original table. Instead, Trafodion SQL generates new names based on the physical file location.
If you specify the LIKE clause and the SALT USING num PARTITIONS clause, you cannot specify WITH PARTITIONS.
-
-
3.15.2. Considerations for CREATE TABLE
The following subsections provide considerations for various CREATE TABLE options:
Authorization and Availability Requirements
Required Privileges
To issue a CREATE TABLE statement, one of the following must be true:
-
You are DB ROOT.
-
You are creating the table in a shared schema.
-
You are the private schema owner.
-
You have the CREATE or CREATE_TABLE component privilege for the SQL_OPERATIONS component.
In this case, if you create a table in a private schema, it will be owned by the schema owner. |
Privileges Needed to Create a Referential Integrity Constraint
To create a referential integrity constraint (that is, a constraint on he table that refers to a column in another table), one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the referencing and referenced tables.
-
You have these privileges on the referencing and referenced table:
-
For the referencing table, you have the CREATE or CREATE_TABLE component privilege for the SQL_OPERATIONS component.
-
For the referenced table, you have the REFERENCES (or ALL) privilege on the referenced table through your username or through a granted role.
-
If the constraint refers to the other table in a query expression, you must also have SELECT privileges on the other table.
Considerations for CREATE VOLATILE TABLE
-
Volatile temporary tables are closely linked to the session. Their name space is unique across multiple concurrent sessions, and therefore allow multiple sessions to use the same volatile temporary table names simultaneously without any conflicts.
-
Volatile tables support creation of indexes.
-
Volatile tables are partitioned by the system. The number of partitions is limited to four partitions by default. The partitions will be distributed across the cluster. The default value is four partitions regardless of the system configuration.
-
Statistics are not automatically updated for volatile tables. If you need statistics, you must explicitly run UPDATE STATISTICS.
-
Volatile tables can be created and accessed using one-part, two-part, or three-part names. However, you must use the same name (one part, two part, or three part) for any further DDL or DML statements on the created volatile table. See Examples of CREATE TABLE.
-
Trafodion SQL allows users to explicitly specify primary key and STORE BY clauses on columns that contain null values.
-
Trafodion SQL does not require that the first column in a volatile table contain not null values and be the primary key. Instead, Trafodion SQL attempts to partition the table, if possible, using an appropriate suitable key column as the primary and partitioning key. For more information, see How Trafodion SQL Selects Suitable Keys for Volatile Tables.
Restrictions for CREATE VOLATILE TABLE
These items are not supported for volatile tables:
-
ALTER statement
-
User constraints
-
Creating views
-
Creating non-volatile indexes on a volatile table or a volatile index on a non-volatile table
-
CREATE TABLE LIKE operations
How Trafodion SQL Supports Nullable Keys for Volatile Tables
-
Allows nullable keys in primary key, STORE BY, and unique constraints.
-
A null value is treated as the highest value for that column.
-
A null value as equal to other null values and only one value is allowed for that column.
How Trafodion SQL Selects Suitable Keys for Volatile Tables
Trafodion SQL searches for the first suitable column in the list of columns of the table being created. Once the column is located, the table is partitioned on it. The searched columns in the table might be explicitly specified (as in a CREATE TABLE statement) or implicitly created (as in a CREATE TABLE AS SELECT statement).
The suitable key column is selected only if no primary key or STORE BY clause has been specified in the statement. If any of these clauses have been specified, they are used to select the key columns.
Trafodion SQL follows these guidelines to search for and select suitable keys:
-
A suitable column can be a nullable column.
-
Certain data types in Trafodion SQL cannot be used as a partitioning key. Currently, this includes any floating point columns (REAL, DOUBLE PRECISION, and FLOAT).
-
Trafodion SQL searches for a suitable column according to this predefined order:
-
Numeric columns are chosen first, followed by fixed CHAR, DATETIME, INTERVAL, and VARCHAR data types.
-
Within numeric data types, the order is binary NUMERIC (LARGEINT, INTEGER, SMALLINT), and DECIMAL.
-
An unsigned column is given preference over a signed column.
-
A non-nullable column is given preference over a nullable column.
-
If all data types are the same, the first column is selected.
-
-
If a suitable column is not located, the volatile table becomes a non-partitioned table with a system-defined SYSKEY as its primary key.
-
If a suitable column is located, it becomes the partitioning key where the primary key is suitable_column, SYSKEY. This causes the table to be partitioned while preventing the duplicate key and null-to-non-null errors.
The list below shows the order of precedence, from low to high, of data types when Trafodion SQL searches for a suitable key. A data type appearing later has precedence over previously-appearing data types. Data types that do not appear in the list below cannot be chosen as a key column.
Precedence of Data Types (From Low to High):
-
VARCHAR
-
INTERVAL
-
DATETIME
-
CHAR(ACTER)
-
DECIMAL (signed, unsigned)
-
SMALLINT (signed, unsigned)
-
INTEGER (signed,unsigned)
-
LARGEINT (signed only)
Creating Nullable Constraints in a Volatile Table
These examples show the creation of nullable constraints (primary key, STORE BY, and unique) in a volatile table:
create volatile table t (a int, primary key(a));
create volatile table t (a int, store by primary key);
create volatile table t (a int unique);
Creating a Volatile Table With a Nullable Primary Key
This example creates a volatile table with a nullable primary key:
>>create volatile table t (a int, primary key(a));
--- SQL operation complete.
Only one unique null value is allowed:
>>insert into t values (null);
--- 1 row(s) inserted.
>>insert into t values (null);
*** ERROR[8102] The operation is prevented by a unique constraint.
--- 0 row(s) inserted.
Examples for Selecting Suitable Keys for Volatile Tables
These examples show the order by which Trafodion SQL selects a suitable key based on the precedence rules described in How Trafodion SQL Selects Suitable Keys for Volatile Tables:
-
Selects column a as the primary and partitioning key:
create volatile table t (a int);
-
Selects column b because int has a higher precedence than char:
create volatile table t (a char(10), b int);
-
Selects column b because not null has precedence over nullable columns:
create volatile table t (a int, b int not null);
-
Selects column b because int has precedence over decimal:
create volatile table t (a decimal(10), b int);
-
Selects the first column, a, because both columns have the same data type:
create volatile table t (a int not null, b int not null);
-
Selects column b because char has precedence over date:
create volatile table t (a date, b char(10));
-
Selects column b because the real data type is not part of the columns to be examined:
create volatile table t (a real, b date);
-
Does not select any column as the primary/partitioning key. SYSKEY is used automatically.
create volatile table t (a real, b double precision not null);
Similar examples would be used for CREATE TABLE AS SELECT queries.
Considerations for CREATE TABLE … LIKE
The CREATE TABLE LIKE statement does not create views, owner information, or privileges for the new table based on the source table. Privileges associated with a new table created by using the LIKE specification are defined as if the new table is created explicitly by the current user.
CREATE TABLE … LIKE and File Attributes
CREATE TABLE … LIKE creates a table like another table, with the exception of file attributes. File attributes include COMPRESSION, and so on. If you do not include the attribute value as part of the CREATE TABLE … LIKE command, SQL creates the table with the default value for the attributes and not the value from the source object. For example, to create a table like another table that specifies compression, you must specify the compression attribute value as part of the CREATE TABLE… LIKE statement. In the following example, the original CREATE TABLE statement creates a table without compression. However, in the CREATE TABLE … LIKE statement, compression is specified.
-- Original Table create table NPTEST
(FIRST_NAME CHAR(12) CHARACTER SET ISO88591 COLLATE DEFAULT NO DEFAULT NOT NULL
, LAST_NAME CHAR(24) CHARACTER SET ISO88591 COLLATE DEFAULT NO DEFAULT NOT NULL
, ADDRESS CHAR(128) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, ZIP INT DEFAULT 0
, PHONE CHAR(10) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, SSN LARGEINT NO DEFAULT NOT NULL
, INFO1 CHAR(128) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, INFO2 CHAR(128) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, primary key (SSN,first_name,last_name)
)
max table size 512
-- CREATE TABLE LIKE
create table LSCE002 like NPTEST ATTRIBUTE compression type hardware;
Considerations for CREATE TABLE AS
These considerations apply to CREATE TABLE AS:
-
Access to the table built by CREATE TABLE AS will be a full table scan because a primary and clustering key cannot be easily defined.
-
Compile time estimates and runtime information is not generated for CREATE TABLE AS tables.
-
You cannot manage CREATE TABLE AS tables using WMS compile time or runtime rules.
-
You cannot specify a primary key for a CREATE TABLE AS table without explicitly defining all the columns in the CREATE TABLE statement.
-
You cannot generate an explain plan for a CREATE TABLE AS …INSERT/SELECT statement. You can, however, use the EXPLAIN plan for a CREATE TABLE AS … INSERT/SELECT statement if you use the NO LOAD option.
-
You cannot use the ORDER BY clause in a CREATE TABLE AS statement. The compiler transparently orders the selected rows to improve the efficiency of the insert.
Considerations for LOAD IF EXISTS and NO LOAD options of CREATE TABLE AS
The LOAD IF EXISTS option in a CREATE TABLE AS statement causes data to be loaded into an existing table. If you do not specify the LOAD IF EXISTS option and try to load data into an existing table, the CREATE TABLE AS statement fails to execute. Use the LOAD IF EXISTS option with the AS clause in these scenarios:
-
Running CREATE TABLE AS without re-creating the table. The table must be empty. Otherwise, the CREATE TABLE AS statement returns an error. Delete the data in the table by using a DELETE statement before issuing the CREATE TABLE AS statement.
-
Using CREATE TABLE AS to incrementally add data to an existing table. You must start a user-defined transaction before issuing the CREATE TABLE AS statement. If you try to execute the CREATE TABLE AS statement without starting a user-defined transaction, an error is returned, stating that data already exists in the table. With a user-defined transaction, newly added rows are rolled back if an error occurs.
The NO LOAD option in a CREATE TABLE AS statement creates a table with the CREATE TABLE AS statement, but does not load data into the table. The option is useful if you must create a table to review its structure and to analyze the SELECT part of the CREATE TABLE AS statement with the EXPLAIN statement. You can also use EXPLAIN to analyze the implicated INSERT/SELECT part of the CREATE TABLE AS … NO LOAD statement. For example:
CREATE TABLE ttgt NO LOAD AS (SELECT ...);
3.15.3. Trafodion SQL Extensions to CREATE TABLE
This statement is supported for compliance with ANSI SQL:1999 Entry Level. Trafodion SQL extensions to the CREATE TABLE statement are ASCENDING, DESCENDING, and PARTITION clauses. CREATE TABLE LIKE is also an extension.
3.15.4. Examples of CREATE TABLE
-
This example creates a table. The clustering key is the primary key.
CREATE TABLE SALES.ODETAIL ( ordernum NUMERIC (6) UNSIGNED NO DEFAULT NOT NULL, partnum NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL, unit_price NUMERIC (8,2) NO DEFAULT NOT NULL, qty_ordered NUMERIC (5) UNSIGNED NO DEFAULT NOT NULL, PRIMARY KEY (ordernum, partnum) );
-
This example creates a table like the JOB table with the same constraints:
CREATE TABLE PERSNL.JOB_CORPORATE LIKE PERSNL.JOB WITH CONSTRAINTS;
-
This is an example of NOT CASESPECIFIC usage:
CREATE TABLE T (a char(10) NOT CASESPECIFIC, b char(10)); INSERT INTO T values ('a', 'A');
-
A row is not returned in this example. Constant ‘A’ is case sensitive, whereas column ‘a’ is insensitive.
SELECT * FROM T WHERE a = 'A';
-
The row is returned in this example. Both sides are case sensitive.
SELECT * FROM T WHERE a = 'A' (not casespecific);
-
The row is returned in this example. A case sensitive comparison is done because column ‘b’ is case sensitive.
SELECT * FROM T WHERE b = 'A';
-
The row is returned in this example. A case sensitive comparison is done because column ‘b’ is case sensitive.
SELECT * FROM T WHERE b = 'A' (not casespecific);
Examples of CREATE TABLE AS
This section shows the column attribute rules used to generate and specify the column names and data types of the table being created.
-
If column-attributes are not specified, the select list items of the select-query are used to generate the column names and data attributes of the created table. If the select list item is a column, then it is used as the name of the created column. For example:
create table t as select a,b from t1
Table t has 2 columns named (a,b) and the same data attributes as columns from table t1.
-
If the select list item is an expression, it must be renamed with an AS clause. An error is returned if expressions are not named. For example:
create table t as select a+1 as c from t1
Table t has 1 column named (c) and data attribute of (a+1)
create table t as select a+1 from t1
An error is returned, expression must be renamed.
-
If column-attributes are specified and contains datatype-info, then they override the attributes of the select items in the select query. These data attributes must be compatible with the corresponding data attributes of the select list items in the select-query.
create table t(a int) as select b from t1
Table t has one column named "a" with data type "int".
create table t(a char(10)) as select a+1 b from t1;
An error is returned because the data attribute of column "a", a char, does not match the data attribute of the select list item "b" a numeric.
-
If column-attributes are specified and they only contain column-name, then the specified column-name override any name that was derived from the select query.
create table t(c,d) as select a,b from t1
Table t has 2 columns, c and d, which has the data attributes of columns a and b from table t1.
-
If column-attributes are specified, then they must contain attributes corresponding to all select list items in the select-query. An error is returned, if a mismatch exists.
create table t(a int) as select b,c from t1
An error is returned. Two items need to be specified as part of the table-attributes.
-
The column-attributes must specify either the column-name datatype-info pair or just the column-name for all columns. You cannot specify some columns with just the name and others with name and data type.
create table t(a int, b) as select c,d from t1
An error is returned.
In the following example, table t1 is created. Table t2 is created using the CREATE TABLE AS syntax without table attributes:
CREATE TABLE t1 (c1 int not null primary key, c2 char(50));
CREATE TABLE t2 (c1 int, c2 char (50) UPSHIFT NOT NULL) AS SELECT * FROM t1;
3.16. CREATE VIEW Statement
The CREATE VIEW statement creates a Trafodion SQL view. See Views.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
CREATE [OR REPLACE] VIEW view
[(column-name ] [,column-name ...)]
AS query-expr [order-by-clause]
[WITH CHECK OPTION]
3.16.1. Syntax Description of CREATE VIEW
-
OR REPLACE
creates a view if one does not exist or replaces a view if a view of the same name exists. The view being replaced might have the same view definition or a different view definition.
-
view
specifies the ANSI logical name of the view. See Database Object Names. This name must be unique among names of tables and views within its schema.
-
(column-name [,column-name ]…)
specifies names for the columns of the view. Column names in the list must match one-for-one with columns in the table specified by query-expr.
If you omit this clause, columns in the view have the same names as the corresponding columns in query-expr. You must specify this clause if any two columns in the table specified by query-expr have the same name or if any column of that table does not have a name. For example, this query expression SELECT MAX(salary), AVG(salary) AS average_salary FROM employee the first column does not have a name.
No two columns of the view can have the same name; if a view refers to more than one table and the select list refers to columns from different tables with the same name, you must specify new names for columns that would otherwise have duplicate names.
-
AS query-expr
specifies the columns for the view and sets the selection criteria that determines the rows that make up the view. For information about character string literals, see Character String Literals. For the syntax and syntax description of query-expr, see SELECT Statement. The CREATE VIEW statement provides this restriction with regard to the query-expr syntax: [ANY_N_], [FIRST N] select list items are not allowed in a view.
-
order-by-clause
specifies the order in which to sort the rows of the final result table. For the syntax and syntax description of the order-by-clause, see SELECT Statement. The CREATE VIEW statement restricts the order-by-clause with regard to the access-clause and mode-clause. The access-mode and mode-clause cannot follow the order-by-clause.
-
WITH CHECK OPTION
specifies that no row can be inserted or updated in the database through the view unless the row satisfies the view definition—that is, the search condition in the WHERE clause of the query expression must evaluate to true for any row that is inserted or updated. This option is only allowed for updatable views.
If you omit this option, a newly inserted row or an updated row need not satisfy the view definition, which means that such a row can be inserted or updated in the table but does not appear in the view. This check is performed each time a row is inserted or updated.
WITH CHECK OPTION does not affect the query expression; rows must always satisfy the view definition.
3.16.2. Considerations for CREATE VIEW
-
If you specify CREATE OR REPLACE VIEW:
-
A new view is created if a view of the same name does not exist.
-
If a view of same name exists, the old view definition is dropped, and a view with a new definition is created. No check will be done to see if the new view is identical to the view it is replacing. The CREATE OR REPLACE VIEW command will unilaterally drop the old view definition and replace it with the new view definition.
-
The privileges granted on the old view will be re-granted on the new view. If the re-grant of privileges fails, the CREATE OR REPLACE VIEW operation fails.
-
When CREATE OR REPLACE VIEW replaces an existing view, any dependent views will be dropped.
-
-
You can specify GROUP BY using ordinals to refer to the relative position within the SELECT list. For example, GROUP BY 3, 2, 1.
-
Dynamic parameters are not allowed.
Effect of Adding a Column on View Definitions
The addition of a column to a table has no effect on any existing view definitions or conditions included in constraint definitions. Any implicit column references specified by SELECT * in view or constraint definitions are replaced by explicit column references when the definition clauses are originally evaluated.
Authorization and Availability Requirements
To issue a CREATE VIEW statement, you must have SELECT privileges on the objects underlying the view or be the owner of the objects underlying the view, and one of the following must be true:
-
You are DB ROOT.
-
You are creating the view in a shared schema.
-
You are the private schema owner.
-
You have the CREATE or CREATE_VIEW component privilege for the SQL_OPERATIONS component.
In this case, if you create a view in a private schema, it will be owned by the schema owner.
When you create a view on a single table, the owner of the view is automatically given all privileges WITH GRANT OPTION on the view. However, when you create a view that spans multiple tables, the owner of the view is given only SELECT privileges WITH GRANT OPTION. If you try to grant privileges to another user on the view other than SELECT, you will receive a warning that you lack the grant option for that privilege.
Updatable and Non-Updatable Views
Single table views can be updatable. Multi-table views cannot be updatable.
To define an updatable view, a query expression must also meet these requirements:
-
It cannot contain a JOIN, UNION, or EXCEPT clause.
-
It cannot contain a GROUP BY or HAVING clause.
-
It cannot directly contain the keyword DISTINCT.
-
The FROM clause must refer to exactly one table or one updatable view.
-
It cannot contain a WHERE clause that contains a subquery.
-
The select list cannot include expressions or functions or duplicate column names.
ORDER BY Clause Guidelines
The ORDER BY clause can be specified in the SELECT portion of a CREATE VIEW definition. Any SELECT syntax that is valid when the SELECT portion is specified on its own is also valid during the view definition. An ORDER BY clause can contain either the column name from the SELECT list or from select-list-index.
When a DML statement is issued against the view, the rules documented in the following sections are used to apply the ORDER BY clause.
When to Use ORDER BY
An ORDER BY clause is used in a view definition only when the clause is under the root of the Select query that uses that view. If the ORDER BY clause appears in other intermediate locations or in a subquery, it is ignored.
Consider this CREATE VIEW statement:
create view v as select a from t order by a; select * from v x, v y;
Or this INSERT statement:
insert into t1 select * from v;
In these two examples, the ORDER BY clause is ignored during DML processing because the first appears as part of a derived table and the second as a subquery selects, both created after the view expansion.
If the same query is issued using explicit derived tables instead of a view, a syntax error is returned:
select * from (select a from t order by a) x, (select a from t order by a) y;
This example returns a syntax error because an ORDER BY clause is not supported in a subquery.
The ORDER BY clause is ignored if it is part of a view and used in places where it is not supported. This is different than returning an error when the same query was written with explicit ORDER BY clause, as is shown in the preceding examples.
ORDER BY in a View Definition With No Override
If the SELECT query reads from the view with no explicit ORDER BY override, the ORDER BY semantics of the view definition are used.
In this example, the ordering column is the one specified in the CREATE VIEW statement:
create view v as select * from t order by a Select * from v
The SELECT query becomes equivalent to:
select * from t order by a;
ORDER BY in a View Definition With User Override
If a SELECT query contains an explicit ORDER BY clause, it overrides the ORDER BY clause specified in the view definition.
For example:
create view v as select a,b from t order by a; select * from v order by b;
In this example, order by b overrides the order by a specified in the view definition. The SELECT query becomes equivalent to:
select a,b from t order by b;
Nested View Definitions
In case of nested view definitions, the ORDER BY clause in the topmost view definition overrides the ORDER BY clause of any nested view definitions.
For example:
create view v1 as select a,b from t1 order by a;
create view v2 as select a,b from v1 order by b;
select * from v2;
In this example, the ORDER BY specified in the definition of view v2 overrides the ORDER BY specified in the definition of view v1.
The SELECT query becomes equivalent to:
select a,b from (select a, b from t) x order by b;
3.16.3. Examples of CREATE VIEW
-
This example creates a view on a single table without a view column list:
CREATE VIEW SALES.MYVIEW1 AS SELECT ordernum, qty_ordered FROM SALES.ODETAIL;
-
This example replaces the view, MYVIEW1, with a different view definition:
CREATE OR REPLACE VIEW SALES.MYVIEW1 AS SELECT ordernum, qty_ordered FROM SALES.ODETAIL WHERE unit_price > 100;
-
This example creates a view with a column list:
CREATE VIEW SALES.MYVIEW2 (v_ordernum, t_partnum) AS SELECT v.ordernum, t.partnum FROM SALES.MYVIEW1 v, SALES.ODETAIL t;
-
This example creates a view from two tables by using an INNER JOIN:
CREATE VIEW MYVIEW4 (v_ordernum, v_partnum) AS SELECT od.ordernum, p.partnum FROM SALES.ODETAIL OD INNER JOIN SALES.PARTS P ON od.partnum = p.partnum;
Vertical Partition Example
This example creates three logical vertical partitions for a table, vp0, vp1, and vp2 and then creates a view vp to access them.
A view can be used to obtain a composite representation of a set of closely related tables. In the following example tables vp0, vp1 and vp2 all have a key column a. This key column is known to contain identical rows for all three tables. The three tables vp0, vp1 and vp2 also contain columns b, c and d respectively. We can create a view vp that combines these three tables and provides the interface of columns a, b, c and d belonging to a single object.
Trafodion SQL has the ability to eliminate redundant joins in a query. Redundant joins occur when:
-
Output of join contains expressions from only one of its two children
-
Every row from this child will match one and only one row from the other child
Suppose tables A and B denote generic tables. To check if the rule "every row from this child will match one and only one row from the other child" is true, Trafodion SQL uses the fact that the join of Table A with table or subquery B preserves all the rows of A if the join predicate contains an equi-join predicate that references a key of B, and one of the following is true: The join is a left outer join where B is the inner table. In this example, for the join between vp0 and vp1,vp0 fills the role of table A and vp1 fills the role of table B. For the join between vp1 and vp2, vp1 fills the role of table A and vp2 fills the role of table B.
The view vp shown in this example uses left outer joins to combine the three underlying tables. Therefore, if the select list in a query that accesses vp does not contain column d from vp2 then the join to table vp2 in the view vp will not be performed.
create table vp0(a integer not null, b integer, primary key(a));
create table vp1(a integer not null, c integer, primary key(a));
create table vp2(a integer not null, d integer, primary key(a));
create view vp(a,b,c,d) as
select vp0.a, b, c, d
from vp0
left outer join vp1 on vp0.a=vp1.a
left outer join vp2 on vp0.a=vp2.a;
select a, b from vp; -- reads only vp0
select a, c from vp; -- reads vp0 and vp1
select d from vp; -- reads vp0 and vp2
3.17. DELETE Statement
The DELETE statement is a DML statement that deletes a row or rows from a table or an updatable view. Deleting rows from a view deletes the rows from the table on which the view is based. DELETE does not remove a table or view, even if you delete the last row in the table or view.
Trafodion SQL provides searched DELETE—deletes rows whose selection depends on a search condition.
For the searched DELETE form, if no WHERE clause exists, all rows are deleted from the table or view.
Searched DELETE is:
DELETE FROM table
[WHERE search-condition ]
[[for] access-option access]
access-option is:
read committed
3.17.1. Syntax Description of DELETE
-
table
names the user table or view from which to delete rows. table must be a base table or an updatable view. To refer to a table or view, use the ANSI logical name. See Database Object Names.
-
WHERE search-condition
specifies a search condition that selects rows to delete. Within the search condition, any columns being compared are columns in the table or view being deleted from. See Search Condition
If you do not specify a search condition, all rows in the table or view are deleted.
-
[FOR] access-option ACCESS
specifies the access option required for data used to evaluate the search condition. See Data Consistency and Access Options.
-
`READ `COMMITTED
specifies that any data used to evaluate the search condition must come from committed rows.
The default access option is the isolation level of the containing transaction.
-
3.17.2. Considerations for DELETE
Authorization Requirements
DELETE requires authority to read and write to the table or view being deleted from and authority to read tables or views specified in subqueries used in the search condition.
Transaction Initiation and Termination
The DELETE statement automatically initiates a transaction if no transaction is active. Otherwise, you can explicitly initiate a transaction with the BEGIN WORK statement. When a transaction is started, the SQL statements execute within that transaction until a COMMIT or ROLLBACK is encountered or an error occurs.
Isolation Levels of Transactions and Access Options of Statements
The isolation level of an SQL transaction defines the degree to which the operations on data within that transaction are affected by operations of concurrent transactions. When you specify access options for the DML statements within a transaction, you override the isolation level of the containing transaction. Each statement then executes with its individual access option.
3.17.3. Examples of DELETE
-
Remove all rows from the JOB table:
DELETE FROM persnl.job; --- 10 row(s) deleted.
-
Remove from the table ORDERS any orders placed with sales representative 220 by any customer except customer number 1234:
DELETE FROM sales.orders WHERE salesrep = 220 AND custnum <> 1234; --- 2 row(s) deleted.
-
Remove all suppliers not in Texas from the table PARTSUPP:
DELETE FROM invent.partsupp WHERE suppnum IN (SELECT suppnum FROM samdbcat.invent.supplier WHERE state <> 'TEXAS'); --- 41 row(s) deleted.
This statement achieves the same result:
DELETE FROM invent.partsupp WHERE suppnum NOT IN SELECT suppnum FROM samdbcat.invent.supplier WHERE state = 'TEXAS'); --- 41 row(s) deleted.
-
This is an example of a self-referencing DELETE statement, where the table from which rows are deleted is scanned in a subquery:
delete from table1 where a in (select a from table1 where b > 200)
3.18. DROP FUNCTION Statement
The DROP FUNCTION statement removes a user-defined function (UDF) from the Trafodion database.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP FUNCTION [[catalog-name.]schema-name.]function-name
3.18.1. Syntax Description of DROP FUNCTION
-
[[_catalog-name_.]schema-name.]function-name
specifies the ANSI logical name of the function, where each part of the name is a valid sql identifier with a maximum of 128 characters. specify the name of a function that has already been registered in the schema. if you do not fully qualify the function name, trafodion sql qualifies it according to the schema of the current session. for more information, see identifiers and database object names.
3.18.2. Considerations for DROP FUNCTION
Required Privileges
To issue a DROP FUNCTION statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the function.
-
You have the DROP or DROP_ROUTINE component privilege for SQL_OPERATIONS component.
3.18.3. Examples of DROP FUNCTION
-
This DROP FUNCTION statement removes the function named ADD2 from the default schema:
DROP FUNCTION add2;
-
This DROP FUNCTION statement removes the function named MMA5 from the default schema:
DROP PROCEDURE mma5;
-
This DROP FUNCTION statement removes the function named REVERSE from the default schema:
DROP PROCEDURE reverse;
3.19. DROP INDEX Statement
The DROP INDEX statement drops a Trafodion SQL index. See Indexes. DROP INDEX is a Trafodion SQL extension.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP [VOLATILE] INDEX index
3.19.1. Syntax Description of DROP INDEX
-
index
is the index to drop.
For information, see Database Object Names.
3.19.2. Considerations for DROP INDEX
Required Privileges
To issue a DROP INDEX statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the index or the table associated with the index.
-
You have the DROP or DROP_INDEX component privilege for the SQL_OPERATIONS component.
3.19.3. Examples of DROP INDEX
-
This example drops an index:
DROP INDEX myindex;
-
This example drops a volatile index:
DROP VOLATILE INDEX vindex;
3.20. DROP LIBRARY Statement
The DROP LIBRARY statement removes a library object from the Trafodion database and also removes the library file referenced by the library object.
DROP LIBRARY is a Trafodion SQL extension.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP LIBRARY [[catalog-name.]schema-name.]library-name [restrict | cascade]
3.20.1. Syntax Description of DROP LIBRARY
-
[[_catalog-name_.]schema-name.]library-name
specifies the ANSI logical name of the library object, where each part of the name is a valid sql identifier with a maximum of 128 characters. specify the name of a library object that has already been registered in the schema. if you do not fully qualify the library name, trafodion sql qualifies it according to the schema of the current session. for more information, see identifiers and database object names.
-
[restrict | cascade]
if you specify restrict, the drop library operation fails if any stored procedures in java (spjs) or user-defined functions (UDFs) were created based on the specified library.
if you specify cascade, any such dependent procedures or functions are removed as part of the drop library operation.
the default value is restrict.
3.20.2. Considerations for DROP LIBRARY
-
RESTRICT requires that all procedures and functions that refer to the library object be dropped before you drop the library object. CASCADE automatically drops any procedures or functions that are using the library.
-
If the library filename referenced by the library object does not exist, Trafodion SQL issues a warning.
Required Privileges
To issue a DROP LIBRARY statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the library.
-
You have the DROP or DROP_LIBRARY component privilege for the SQL_OPERATIONS component.
3.20.3. Examples of DROP LIBRARY
-
This DROP LIBRARY statement removes the library named SALESLIB from the SALES schema, removes the Sales2.jar file referenced by the library, and drops any stored procedures in Java (SPJs) that were created based on this library:
DROP LIBRARY sales.saleslib CASCADE;
-
This DROP LIBRARY statement removes the library named MYUDFS from the default schema and removes the $TMUDFS library file referenced by the library:
DROP LIBRARY myudfs RESTRICT;
RESTRICT prevents the DROP LIBRARY operation from dropping any user-defined functions (UDFs) that were created based on this library. If any UDFs were created based on this library, the DROP LIBRARY operation fails.
3.21. DROP PROCEDURE Statement
The DROP PROCEDURE statement removes a stored procedure in Java (SPJ) from the Trafodion database.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP PROCEDURE [[catalog-name.]schema-name.]procedure-name
3.21.1. Syntax Description of DROP PROCEDURE
-
[[_catalog-name_.]schema-name.]procedure-name
specifies the ANSI logical name of the stored procedure in java (SPJ), where each part of the name is a valid sql identifier with a maximum of 128 characters. specify the name of a procedure that has already been registered in the schema. if you do not fully qualify the procedure name, trafodion sql qualifies it according to the schema of the current session.
for more information, see identifiers and database object names.
3.21.2. Considerations for DROP PROCEDURE
Required Privileges
To issue a DROP PROCEDURE statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the procedure.
-
You have the DROP or DROP_ROUTINE component privilege for SQL_OPERATIONS component.
3.21.3. Examples of DROP PROCEDURE
-
This DROP PROCEDURE statement removes the procedure named LOWERPRICE from the SALES schema:
DROP PROCEDURE sales.lowerprice;
-
This DROP PROCEDURE statement removes the procedure TOTALPRICE from the default schema for the session, which is the SALES schema:
SET SCHEMA sales; DROP PROCEDURE totalprice;
3.22. DROP ROLE Statement
The DROP ROLE statement deletes an SQL role. See Roles.
DROP ROLE role-name
3.22.1. Syntax Description of DROP ROLE
-
role-name
is an existing role name. The role cannot be dropped if any of the following are true:
-
Any privileges are granted to the role.
-
The role is granted to any users.
-
The role owns any schemas.
3.22.2. Considerations for DROP ROLE
-
To drop a role, you must own the role or have user administrative privileges for the role. You have user administrative privileges for the role if you have been granted the MANAGE_ROLES component privilege. Initially, DB ROOT is the only database user who has been granted the MANAGE_ROLES component privilege.
-
Role names beginning with DB are reserved and can only be dropped by DB ROOT.
-
You can determine all users to whom a role has been granted by using the SHOWDDL ROLE statement. See the SHOWDDL Statement.
Before You Drop a Role
Before dropping a role, follow these guidelines:
-
You must revoke all privileges granted to the role.
-
You must revoke the role from all users to whom it was granted.
-
You must drop all schemas the role is a manager (or owner) of.
You can determine all users to whom a role has been granted with the SHOWDDL statement. See the SHOWDDL Statement.
Active Sessions for the User
When you revoke a role from a user, then the change in privileges is automatically propagated to and detected by active sessions. There is no need for users to disconnect from and reconnect to a session to see the updated set of privileges.
3.22.3. Examples of DROP ROLE
-
To drop a role:
DROP ROLE clerks;
-
To drop a role with dependent privileges:
-- User administrator creates a role: CREATE ROLE clerks; -- User administrator grants privileges on a table to the role: GRANT ALL PRIVILEGES ON TABLE invent.partloc TO clerks; -- User administrator grants the role to a user: GRANT ROLE clerks TO JSmith; -- JSmith creates a view based upon the granted privilege: CREATE VIEW invent.partlocView (partnum, loc_code) AS SELECT partnum, loc_code FROM invent.partloc; -- If the user administrator attempts to drop the role, this -- would fail because of the view created based on -- the granted privilege. -- To successfully drop the role, the dependent view -- and grant must be removed first. For this example: -- 1. JSmith drops the view: DROP VIEW invent.partlocView; -- 2. User administrator revokes the role from the user: REVOKE ROLE clerks FROM JSmith; -- 3. User administrator revokes all privileges the role has been granted REVOKE ALL ON invent.partloc FROM clerks; -- 4. User administrator drops the role: DROP ROLE clerks; -- The DROP ROLE operation succeeds.
3.23. DROP SCHEMA Statement
The DROP SCHEMA statement drops a schema from the database. SeeSchemas.
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP SCHEMA schema-name [RESTRICT|CASCADE]
3.23.1. Syntax Description of DROP SCHEMA
-
schema-name
is the name of the schema to delete.
-
RESTRICT
If you specify RESTRICT, an error is reported if the specified schema is not empty. The default is RESTRICT.
-
CASCADE
If you specify CASCADE, objects in the specified schema and the schema itself are dropped. Any objects in other schemas that were dependent on objects in this schema are dropped as well.
3.23.2. Considerations for DROP SCHEMA
Authorization Requirements
To drop a schema, one of the following must be true:
-
You are the owner of the schema.
-
You have been granted the role that owns the schema.
-
You have been granted the DROP_SCHEMA privilege.
3.23.3. Example of DROP SCHEMA
-
This example drops an empty schema:
DROP SCHEMA sales;
3.24. DROP TABLE Statement
The DROP TABLE statement deletes a Trafodion SQL table and its dependent objects such as indexes and constraints. See Tables.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP [VOLATILE] TABLE [IF EXISTS] table [RESTRICT|CASCADE]
3.24.1. Syntax Description of DROP TABLE
-
VOLATILE
specifies that the table to be dropped is a volatile table.
-
IF EXISTS
drops the HBase table if it exists. This option does not apply to volatile tables.
-
table
is the name of the table to delete.
-
RESTRICT
If you specify RESTRICT and the table is referenced by another object, the specified table cannot be dropped. The default is RESTRICT.
-
CASCADE
If you specify CASCADE, the table and all objects referencing the table (such as a view) are dropped.
3.24.2. Considerations for DROP TABLE
Authorization Requirements
To issue a DROP TABLE statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the table.
-
You have the DROP or DROP_TABLE component privilege for the SQL_OPERATIONS component.
3.24.3. Examples of DROP TABLE
-
This example drops a table:
DROP TABLE mysch.mytable;
-
This example drops a volatile table:
DROP VOLATILE TABLE vtable;
3.25. DROP VIEW Statement
The DROP VIEW statement deletes a Trafodion SQL view. See Views.
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session. |
DROP VIEW view [RESTRICT|CASCADE]
3.25.1. Syntax Description of DROP VIEW
-
view
is the name of the view to delete.
-
RESTRICT
If you specify RESTRICT, you cannot drop the specified view if it is referenced in the query expression of any other view or in the search condition of another object’s constraint. The default is RESTRICT.
-
CASCADE
If you specify CASCADE, any dependent objects are dropped.
3.25.2. Considerations for DROP VIEW
Authorization Requirements
To issue a DROP VIEW statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the view.
-
You have the DROP or DROP_VIEW component privilege for the SQL_OPERATIONS component.
3.25.3. Example of DROP VIEW
-
This example drops a view:
DROP VIEW mysch.myview;
3.26. Execute Statement
The EXECUTE statement executes an SQL statement previously compiled by a PREPARE statement in a Trafodion Command Interface (TrafCI) session.
EXECUTE statement-name
[ USING param [,param]...] ]
param is:
?param-name | literal-value
3.26.1. Syntax Description of EXECUTE
-
statement-name
is the name of a prepared SQL statement—that is, the statement name used in the PREPARE statement. statement-name is an SQL identifier. See Identifiers.
-
USING param [,param]…
param is: ?param-name | literal-value
specifies values for unnamed parameters (represented by ?) in the prepared statement in the form of either a parameter name (?param-name) or a literal value (literal-value). The data type of a parameter value must be compatible with the data type of the associated parameter in the prepared statement.
Parameter values (param) are substituted for unnamed parameters in the prepared statement by position—the i-th value in the USING clause is the value for the i-th parameter in the statement. If fewer parameter values exist in the USING clause than unnamed parameters in the PREPARE statement, Trafodion SQL returns an error. If more parameter values exist in the USING clause than the unnamed parameters in the PREPARE statement, Trafodion SQL issues warning 15019.
The USING clause does not set parameter values for named parameters (represented by ?param-name) in a prepared statement. To set parameter values for named parameters, use the SET PARAM command. For more information, see the Trafodion Command Interface Guide.
-
?param-name
The value for a ?param-name must be previously specified with the SET PARAM command. The param-name is case-sensitive. For information about the SET PARAM command, see the Trafodion Command Interface Guide.
-
literal-value
is a numeric or character literal that specifies the value for the unnamed parameter.
If literal-value is a character literal and the target column type is character, you do not have to enclose it in single quotation marks. Its data type is determined from the data type of the column to which the literal is assigned. If the literal-value contains leading or trailing spaces, commas, or if it matches any parameter names that are already set, enclose the literal-value in single quotes.
-
See the PREPARE Statement. For information about the SET PARAM command, see the Trafodion Command Interface Guide.
3.26.2. Considerations for EXECUTE
Scope of EXECUTE
A statement must be compiled by PREPARE before you EXECUTE it, but after it is compiled, you can execute the statement multiple times without recompiling it. The statement must have been compiled during the same TrafCI session as its execution.
3.26.3. Examples of EXECUTE
-
Use PREPARE to compile a statement once, and then execute the statement multiple times with different parameter values. This example uses the SET PARAM command to set parameter values for named parameters (represented by ?param-name) in the prepared statement.
SQL>prepare findemp from +>select * from persnl.employee +>where salary > ?sal and jobcode = ?job; --- SQL command prepared. SQL>set param ?sal 40000.00; SQL>set param ?job 450; SQL>execute findemp; EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY ------ --------------- -------------- ------- ------- -------- 232 THOMAS SPINNER 4000 450 45000.00 --- 1 row(s) selected. SQL>set param ?sal 20000.00; SQL>set param ?job 300; SQL>execute findemp; EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY ------ --------------- -------------- ------- ------- -------- 75 TIM WALKER 3000 300 32000.00 89 PETER SMITH 3300 300 37000.40 ... --- 13 row(s) selected.
-
Specify literal values in the USING clause of the EXECUTE statement for unnamed parameters in the prepared statement:
SQL>prepare findemp from +>select * from persnl.employee +>where salary > ? and jobcode = ?; --- SQL command prepared. SQL>execute findemp using 40000.00,450; EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY ------ --------------- -------------- ------- ------- -------- 232 THOMAS SPINNER 4000 450 45000.00 --- 1 row(s) selected. SQL>execute findemp using 20000.00, 300; EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY ------ --------------- -------------- ------- ------- -------- 75 TIM WALKER 3000 300 32000.00 89 PETER SMITH 3300 300 37000.40 ... --- 13 row(s) selected.
-
Use SET PARAM to assign a value to a parameter name and specify both the parameter name and a literal value in the EXECUTE USING clause:
SQL>prepare findemp from +>select * from persnl.employee +>where salary > ? and jobcode = ?; --- SQL command prepared. SQL>set param ?Salary 40000.00; SQL>execute findemp using ?Salary, 450; EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY ------ --------------- -------------- ------- ------- -------- 232 THOMAS SPINNER 4000 450 45000.00
3.27. EXPLAIN Statement
The EXPLAIN statement helps you to review query execution plans. You can use the EXPLAIN statement anywhere you can execute other SQL statements (for example, SELECT). For more information on the EXPLAIN function, see EXPLAIN Function.
EXPLAIN is a Trafodion SQL extension.
EXPLAIN [OPTIONS {'f'}] {FOR QID query-text | prepared-stmt-name}
Plans displayed by the EXPLAIN statement are ordered from top (root operator) to bottom (leaf operators).
3.27.1. Syntax Description of EXPLAIN
-
f
Provides the simple, basic information contained in the query execution plan. This information is formatted for readability and limited to 79 characters (one line) per operator. See Formatted [OPTIONS 'f'] Considerations.
-
query-text
a DML statement such as
SELECT * FROM T3
. -
prepared-stmt-name
an SQL identifier containing the name of a statement already prepared in this session. An SQL identifier is case-insensitive (will be in uppercase) unless it is double-quoted. It must be double-quoted if it contains blanks, lowercase letters, or special characters. It must start with a letter. When you refer to the prepared query in a SELECT statement, you must use uppercase.
3.27.2. Considerations for EXPLAIN
Required Privileges
To issue an EXPLAIN statement, one of the following must be true:
-
You are DB ROOT.
-
You own (that is, issued) the query specified in the EXPLAIN statement.
-
You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.
Obtaining EXPLAIN Plans While Queries Are Running
Trafodion SQL provides the ability to capture an EXPLAIN plan for a query at any time while the query is running with the FOR QID option. By default, this behavior is disabled for a Trafodion database session.
Enable this feature before you start preparing and executing queries. |
After the feature is enabled, use the FOR QID option in an EXPLAIN statement to get the query execution plan of a running query.
The EXPLAIN function or statement returns the plan that was generated when the query was prepared. EXPLAIN with the FOR QID option retrieves all the information from the original plan of the executing query. The plan is available until the query finishes executing and is removed or deallocated.
Case Considerations
In most cases, words in the commands can be in uppercase or lowercase. The options letter must be single quoted and in lowercase.
Number Considerations
Costs are given in a generic unit of effort. They show relative costs of an operation.
When trailing decimal digits are zero, they are dropped. For example, 6.4200 would display as 6.42 and 5.0 would display as 5, without a decimal point.
Formatted [OPTIONS 'f'] Considerations
The formatted option is the simplest option. It provides essential, brief information about the plan and shows the operators and their order within the query execution plan.
OPTIONS 'f' formats the EXPLAIN output into these fields:
LC |
Left child sequence number |
RC |
Right child sequence number |
OP |
The sequence number of the operator in the query plan |
OPERATOR |
The operator type |
OPT |
Query optimizations that were applied |
DESCRIPTION |
Additional information about the operator |
CARD |
Estimated number of rows returned by the plan. CARDINALITY and ROWS_OUT are the same. |
This example uses OPTIONS 'f ':
>>explain options 'f' select * from region;
LC RC OP OPERATOR OPT DESCRIPTION CARD
---- ---- ---- -------------------- -------- -------------------- ---------
1 . 2 root 1.00E+002
. . 1 trafodion_scan REGION 1.00E+002
--- SQL operation complete.
To use the EXPLAIN statement with a prepared statement, first prepare the query. Then use the EXPLAIN statement:
PREPARE q FROM SELECT * FROM REGION;
EXPLAIN options 'f' q;
3.28. GET Statement
The GET statement displays the names of database objects, components, component privileges, roles, or users that exist in the Trafodion instance.
GET is a Trafodion SQL extension.
GET option
option is:
COMPONENT PRIVILEGES ON component-name [FOR auth-name]
| COMPONENTS
| FUNCTIONS FOR LIBRARY [[catalog-name.]schema-name.]library-name
| functions [in schema [catalog-name.]schema-name]
| libraries [in schema [catalog-name.]schema-name]
| procedures for library [[catalog-name.]schema-name.]library-name
| procedures [in schema [catalog-name.]schema-name]
| roles [for user database-username]
| schemas [in catalog catalog-name]
| schemas for [user | role] authorization-id
| tables [in schema [catalog-name.]schema-name]
| users [for role role-name]
| views [in schema [catalog-name.]schema-name]
| views on table [[catalog-name.]schema-name.]table-name
3.28.1. Syntax Description of GET
-
COMPONENT PRIVILEGES ON component-name
displays the names of the component privileges available for the specified component.
-
COMPONENT PRIVILEGES ON component-name FOR auth-name
displays the component privileges that have been granted to the specified authorization name for the specified component. The auth-name is either a registered database username or an existing role name and can be a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers.
-
COMPONENTS
displays a list of all the existing components.
-
FUNCTIONS
displays the names of all the user-defined functions (UDFs) in the catalog and schema of the current session. By default, the catalog is TRAFODION, and the schema is SEABASE.
-
FUNCTIONS FOR LIBRARY [[_catalog-name_.]schema-name.]library-name
displays the UDFs that reference the specified library.
-
functions in schema schema-name
displays the names of all the UDFs in the specified schema.
-
libraries
displays the names of all the libraries in the catalog and schema of the current session. by default, the catalog is trafodion, and the schema is seabase.
-
libraries in schema schema-name
displays the libraries in the specified schema.
-
procedures
displays the names of all the procedures in the catalog and schema of the current session. by default, the catalog is trafodion, and the schema is seabase.
-
procedures for library [[_catalog-name_.]schema-name.]library-name
displays the procedures that reference the specified library.
-
procedures in schema schema-name
displays the names of all the procedures in the specified schema.
-
roles
displays a list of all the existing roles.
-
roles for user database-username
displays all the roles that have been granted to the specified database user. the database-username can be a regular or delimited case-insensitive identifier. see case-insensitive delimited identifiers.
-
schemas
displays the names of all the schemas in the catalog of the current session. by default, the catalog is trafodion.
-
schemas in catalog catalog-name
displays the names of all the schemas in the specified catalog. for the catalog-name, you can specify only trafodion.
-
schemas for [user | role] authorization-id
displays all the schemas managed (or owned) by a specified user or role.
-
`authorization-id
is the name of a user or role. you may specify either user or role for users or roles.
-
tables
displays the names of all the tables in the catalog and schema of the current session. by default, the catalog is trafodion, and the schema is seabase.
-
tables in schema schema-name
displays the names of all the tables in the specified schema.
-
users
displays a list of all the registered database users.
-
users for role role-name
displays all the database users who have been granted the specified role. the role-name can be a regular or delimited case-insensitive identifier. see case-insensitive delimited identifiers.
-
views
displays the names of all the views in the catalog and schema of the current session. by default, the catalog is trafodion, and the schema is seabase.
-
views in schema schema-name
displays the names of all the views in the specified schema. for the catalog-name, you can specify only trafodion.
-
views on table [[_catalog-name_.]schema-name.]table-name
displays the names of all the views that were created for the specified table. if you do not qualify the table name with catalog and schema names, get uses the catalog and schema of the current session. for the catalog-name, you can specify only trafodion.
3.28.2. Considerations for GET
The GET COMPONENT PRIVILEGES, GET COMPONENTS, GET ROLES FOR USER, and GET USERS FOR ROLE statements work only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
The GET statement displays delimited object names in their internal format. For example, the GET statement returns the delimited name "my ""table""" as my "table".
Required Privileges
To issue a GET statement, one of the following must be true:
-
You are DB ROOT.
-
You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.
3.28.3. Examples of GET
-
This GET statement displays the names of all the schemas in the catalog of the current session, which happens to be the TRAFODION catalog:
GET SCHEMAS;
-
This GET statement displays the names of all the schemas in the specified catalog, TRAFODION:
GET SCHEMAS IN CATALOG TRAFODION;
-
This GET statement displays the names of schemas owned by DB ROOT:
GET SCHEMAS FOR USER DB ROOT;
-
This GET statement displays the names of all the tables in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:
GET TABLES;
-
This GET statement displays the names of all the tables in the specified schema, SEABASE2, in the TRAFODION catalog:
GET TABLES IN SCHEMA SEABASE2;
-
This GET statement displays the names of all the views in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:
GET VIEWS;
-
This GET statement displays the names of all the views in the specified schema, SEABASE2, the TRAFODION catalog:
GET VIEWS IN SCHEMA SEABASE2;
-
This GET statement displays the names of all the views that were created for the specified table, T, in the TRAFODION.SEABASE schema:
GET VIEWS ON TABLE T;
-
This GET statement displays the names of the libraries in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:
GET LIBRARIES;
-
This GET statement displays the names of the libraries in the TRAFODION.MD schema:
GET LIBRARIES IN SCHEMA "_MD_";
-
This GET statement displays the names of procedures registered in the library, TRAFODION.MD.UDR_LIBRARY:
GET PROCEDURES FOR LIBRARY "_MD_".UDR_LIBRARY;
-
This GET statement displays the names of procedures in the TRAFODION.MD schema:
GET PROCEDURES IN SCHEMA "_MD_";
-
This GET statement displays the names of procedures in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:
GET PROCEDURES;
-
This GET statement displays the names of user-defined functions (UDFs) in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:
GET FUNCTIONS;
-
This GET statement displays the names of UDFs in MYSCHEMA:
GET FUNCTIONS IN SCHEMA MYSCHEMA;
-
This GET statement displays the names of UDFs created in the library, TRAFODION.MYSCHEMA.MYUDFS:
GET FUNCTIONS FOR LIBRARY MYSCHEMA.MYUDFS;
-
This GET statement displays a list of all the existing components:
get components;
-
This GET statement displays the names of the component privileges available for the SQL_OPERATIONS component:
get component privileges on sql_operations;
-
This GET statement displays the component privileges that have been granted to the DB ROOT user for the SQL_OPERATIONS component:
get component privileges on sql_operations for db root;
-
This GET statement displays a list of all the existing roles:
get roles;
-
This GET statement displays all the roles that have been granted to the DB ROOT user:
get roles for user db root;
-
This GET statement displays a list of all the registered database users:
get users;
-
This GET statement displays all the database users who have been granted the DB ROOTROLE role:
get users for role db rootrole;
3.29. GET HBASE OBJECTS Statement
The GET HBASE OBJECTS statement displays a list of HBase objects directly from HBase, not from the Trafodion metadata, and it can be run in any SQL interface, such as the Trafodion Command Interface (TrafCI). This command is equivalent to running a list command from an HBase shell, but without having to start and connect to an HBase shell.
GET HBASE OBJECTS is a Trafodion SQL extension.
GET [ USER | SYSTEM | EXTERNAL | ALL } HBASE OBJECTS
3.29.1. Syntax Description of GET HBASE OBJECTS
-
USER
displays a list of the Trafodion user objects.
-
SYSTEM
displays a list of the Trafodion system objects, such as metadata, repository, privileges, and Distributed Transaction Manager (DTM) tables.
-
EXTERNAL
displays a list of non-Trafodion objects.
-
ALL
displays a list of all objects, including user, system, and external objects.
3.29.2. Examples of GET HBASE OBJECTS
-
This GET HBASE OBJECTS statement displays the Trafodion user objects in HBase:
Trafodion Conversational Interface 1.1.0 (c) Copyright 2015 Apache Software Foundation >>get user hbase objects; TRAFODION.SCH.SB_HISTOGRAMS TRAFODION.SCH.SB_HISTOGRAM_INTERVALS TRAFODION.SCH.T006T1 TRAFODION.SCH.T006T2 TRAFODION.SCH.T006T3 TRAFODION.SCH.T006T4 TRAFODION.SCH.T006T5 TRAFODION.SCH.T006T6 TRAFODION.SCH.T006T7 TRAFODION.SCH.T006T8 TRAFODION.SCH.X1 TRAFODION.SCH.X2 TRAFODION.SCH.X3 --- SQL operation complete.
-
This GET HBASE OBJECTS statement displays the Trafodion system objects in HBase:
>>get system hbase objects; TRAFODION._DTM_.TLOG0_CONTROL_POINT ... TRAFODION._DTM_.TLOG1_LOG_f TRAFODION._MD_.AUTHS TRAFODION._MD_.COLUMNS TRAFODION._MD_.DEFAULTS TRAFODION._MD_.INDEXES TRAFODION._MD_.KEYS TRAFODION._MD_.LIBRARIES TRAFODION._MD_.LIBRARIES_USAGE TRAFODION._MD_.OBJECTS TRAFODION._MD_.OBJECTS_UNIQ_IDX TRAFODION._MD_.REF_CONSTRAINTS TRAFODION._MD_.ROUTINES TRAFODION._MD_.SEQ_GEN TRAFODION._MD_.TABLES TRAFODION._MD_.TABLE_CONSTRAINTS TRAFODION._MD_.TEXT TRAFODION._MD_.UNIQUE_REF_CONSTR_USAGE TRAFODION._MD_.VERSIONS TRAFODION._MD_.VIEWS TRAFODION._MD_.VIEWS_USAGE TRAFODION._REPOS_.METRIC_QUERY_AGGR_TABLE TRAFODION._REPOS_.METRIC_QUERY_TABLE TRAFODION._REPOS_.METRIC_SESSION_TABLE TRAFODION._REPOS_.METRIC_TEXT_TABLE --- SQL operation complete.
-
This GET HBASE OBJECTS statement displays the external, non-Trafodion objects in HBase:
>>get external hbase objects; obj1 obj2 --- SQL operation complete.
3.30. GET VERSION OF METADATA Statement
The GET VERSION OF METADATA statement displays the version of the metadata in the Trafodion instance and indicates if the metadata is current.
GET VERSION OF METADATA is a Trafodion SQL extension.
GET VERSION OF METADATA
3.30.1. Considerations for GET VERSION OF METADATA
-
If the metadata is compatible with the installed Trafodion software version, the GET VERSION OF METADATA statement indicates that the metadata is current:
Current Version 3.0. Expected Version 3.0. Metadata is current.
-
If the metadata is incompatible with the installed Trafodion software version, the GET VERSION OF METADATA statement indicates that you need to upgrade or reinitialize the metadata:
Current Version 2.3. Expected Version 3.0. Metadata need to be upgraded or reinitialized.
3.30.2. Examples of GET VERSION OF METADATA
-
This GET VERSION OF METADATA statement displays the metadata version in a Trafodion Release 1.0.0 instance:
>> get version of metadata; Current Version 3.0. Expected Version 3.0. Metadata is current. --- SQL operation complete.
-
This GET VERSION OF METADATA statement displays the metadata version in a Trafodion Release 0.9.0 instance:
>> get version of metadata; Current Version 2.3. Expected Version 2.3. Metadata is current. --- SQL operation complete.
-
If the metadata is incompatible with the installed Trafodion software version, you will see this output indicating that you need to upgrade or reinitialize the metadata:
get version of metadata; Current Version 2.3. Expected Version 3.0. Metadata need to be upgraded or reinitialized. --- SQL operation complete.
3.31. GET VERSION OF SOFTWARE Statement
The GET VERSION OF SOFTWARE statement displays the version of the Trafodion software that is installed on the system and indicates if it is current.
GET VERSION OF SOFTWARE is a Trafodion SQL extension.
GET VERSION OF SOFTWARE
3.31.1. Considerations for GET VERSION OF SOFTWARE
-
If the software on the system is current, the GET VERSION OF SOFTWARE statement displays this output:
System Version 1.0.0. Expected Version 1.0.0. Software is current.
-
In rare circumstances where something went wrong with the Trafodion software installation and mismatched objects were installed, the GET VERSION OF SOFTWARE statement displays this output:
System Version 0.9.1. Expected Version 1.0.0. Version of software being used is not compatible with version of software on the system.
3.31.2. Examples of GET VERSION OF SOFTWARE
-
This GET VERSION OF SOFTWARE statement displays the software version for Trafodion Release 1.0.0:
>> get version of software; System Version 1.0.0. Expected Version 1.0.0. Software is current. --- SQL operation complete.
-
This GET VERSION OF SOFTWARE statement displays the software version for Trafodion Release 0.9.0:
get version of software; System Version 0.9.0. Expected Version 0.9.0. Software is current. --- SQL operation complete.
-
If something went wrong with the Trafodion software installation and if mismatched objects were installed, you will see this output indicating that the software being used is incompatible with the software on the system:
get version of software; System Version 0.9.1. Expected Version 1.0.0. Version of software being used is not compatible with version of software on the system. --- SQL operation complete.
3.32. GRANT Statement
The GRANT statement grants access privileges on an SQL object to specified users or roles.
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
GRANT {privilege [,privilege]... |ALL [PRIVILEGES]}
ON [object-type] [schema.]object
TO {grantee [,grantee ]...}
[WITH GRANT OPTION]
[[granted] by grantor]
privilege is:
select
| delete
| insert
| references
| update
| execute
| usage
object-type is:
table
| procedure
| library
| function
grantee is:
auth-name
grantor is:
role-name
3.32.1. syntax description of grant
-
privilege [,privilege ] … | all [privileges]
specifies the privileges to grant. you can specify these privileges for an object.
select
can use the select statement.
delete
can use the delete statement.
insert
can use the insert statement.
references
can create constraints that reference the object.
update
can use the update statement on table objects.
execute
can execute a stored procedure using a call statement or can execute a user-defined function (UDF).
usage
can access a library using the create procedure or create function statement. this privilege provides you with read access to the library’s underlying library file.
all
all the applicable privileges. when you specify all for a table or view, this includes the select, delete, insert, references, and update privileges. when the object is a stored procedure or user-defined function (UDF), only the execute privilege is applied. when the object is a library, only the update and usage privileges are applied.
-
on [object-type] object
specifies an object on which to grant privileges. object-type can be:
-
[table] object
, where object is a table or view. see database object names. -
[procedure] procedure-name
, where procedure-name is the name of a stored procedure in java (SPJ) registered in the database. -
[library] library-name
, where library-name is the name of a library object in the database. -
[function] function-name
, where function-name is the name of a user-defined function (UDF) in the database.
-
-
to {grantee [, grantee] … }
specifies one or more auth-names to which you grant privileges.
-
auth-name
specifies the name of an authorization id to which you grant privileges. see authorization ids. the authorization id must be a registered database username, an existing role name, or public. the name is a regular or delimited case-insensitive identifier. see case-insensitive delimited identifiers. if you grant a privilege to public, the privilege remains available to all users, unless it is later revoked from public.
-
with grant option
specifies that the auth-name to which a privilege is granted may in turn grant the same privilege to other users or roles.
-
[granted] by grantor
allows you to grant privileges on behalf of a role. if not specified, the privileges will be granted on your behalf as the current user/grantor.
-
role-name
specifies a role on whose behalf the grant operation is performed. to grant the privileges on behalf of a role, you must be a member of the role, and the role must have the authority to grant the privileges; that is, the role must have been granted the privileges with grant option.
3.32.2. Considerations for GRANT
Authorization and Availability Requirements
To grant a privilege on an object, you must have both that privilege and the right to grant that privilege. Privileges can be granted directly to you or to one of the roles you have been granted. You can grant a privilege on an object if you are the owner of the object (by which you are implicitly granted all privileges on the object) or the owner of the schema containing the object, or if you have been granted both the privilege and the WITH GRANT OPTION for the privilege.
If granting privileges on behalf of a role, you must specify the role in the [GRANTED] BY clause. To grant the privileges on behalf of a role, you must be a member of the role, and the role must have the authority to grant the privileges; that is, the role must have been granted the privileges WITH GRANT OPTION.
If you lack authority to grant one or more of the specified privileges, SQL returns a warning (yet does grant the specified privileges for which you do have authority to grant). If you lack authority to grant any of the specified privileges, SQL returns an error.
3.32.3. Examples of GRANT
-
To grant SELECT and DELETE privileges on a table to two specified users:
GRANT SELECT, DELETE ON TABLE invent.partloc TO ajones, "MO.Neill@company.com";]
-
To grant SELECT privileges on a table to a user:
GRANT SELECT ON TABLE invent.partloc TO ajones;
3.33. GRANT COMPONENT PRIVILEGE Statement
The GRANT COMPONENT PRIVILEGE statement grants one or more component privileges to a user or role. See Privileges and Roles.
GRANT COMPONENT PRIVILEGE is a Trafodion SQL extension.
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
GRANT COMPONENT PRIVILEGE {privilege-name [, privilege-name]...}
ON component-name
TO grantee
[WITH GRANT OPTION] [[GRANTED] BY grantor]
grantee is:
auth-name
grantor is:
role-name
3.33.1. Syntax Description of GRANT COMPONENT PRIVILEGE
-
privilege-name
specifies one or more component privileges to grant. The comma-separated list can include only privileges within the same component.
Component Component Privilege Description SQL_OPERATIONS
ALTER
Privilege to alter database objects
ALTER_TABLE
Privilege to alter tables
ALTER_VIEW
Privilege to alter views
CREATE
Privilege to create database objects
CREATE_CATALOG
Privilege to create catalogs in the database
CREATE_INDEX
Privilege to create indexes
CREATE_LIBRARY
Privilege to create libraries in the database
CREATE_ROUTINE
Privilege to create stored procedures in Java (SPJs), user-defined functions (UDFs), table-mapping functions, and other routines in the database
CREATE_SCHEMA
Privilege to create schemas in the database
CREATE_TABLE
Privilege to create tables in the database
CREATE_VIEW
Privilege to create views in the database
DROP
Privilege to drop database objects
DROP_CATALOG
Privilege to drop catalogs
DROP_INDEX
Privilege to drop indexes
DROP_LIBRARY
Privilege to drop libraries
DROP_ROUTINE
Privilege to drop stored procedures in Java (SPJs), user-defined functions (UDFs), table-mapping functions, and other routines from the database
DROP_SCHEMA
Privilege to drop schemas
DROP_TABLE
Privilege to drop tables
DROP_VIEW
Privilege to drop views
MANAGE_LIBRARY
Privilege to perform library-related commands, such as creating and dropping libraries
MANAGE_LOAD
Privilege to perform LOAD and UNLOAD commands
MANAGE_ROLES
Privilege to create, alter, drop, grant, and revoke roles
MANAGE_STATISTICS
Privilege to update and display statistics
MANAGE_USERS
Privilege to register or unregister users, alter users, and grant or revoke component privileges.
QUERY_CANCEL
Privilege to cancel an executing query.
SHOW
Privilege to run EXPLAIN, GET, INVOKE, and SHOW commands. The SHOW privilege has been granted to PUBLIC by default.
-
ON component-name
specifies a component name on which to grant component privileges. Currently, the only valid component name is SQL_OPERATIONS.
-
TO grantee
specifies an auth-name to which you grant component privileges.
-
auth-name
specifies the name of an authorization ID to which you grant privileges. See Authorization IDs. The authorization ID must be a registered database username, existing role name, or PUBLIC. The name is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers. If you grant a privilege to PUBLIC, the privilege remains available to all users, unless it is later revoked from PUBLIC.
-
WITH GRANT OPTION
specifies that the auth-name to which a component privilege is granted may in turn grant the same component privilege to other users or roles.
-
[GRANTED] BY grantor
allows you to grant component privileges on behalf of a role. If not specified, the privileges will be granted on your behalf as the current user/grantor.
-
role-name
specifies a role on whose behalf the GRANT COMPONENT PRIVILEGE operation is performed. To grant the privileges on behalf of a role, you must be a member of the role, and the role must have the authority to grant the privileges; that is, the role must have been granted the privileges WITH GRANT OPTION.
3.33.2. Considerations for GRANT COMPONENT PRIVILEGE
-
A user or role granted a component privilege WITH GRANT OPTION can grant the same component privilege to other users or roles.
-
If all of the component privileges have already been granted, SQL returns an error.
-
If one or more component privileges has already been granted, SQL silently ignores the granted privileges and proceeds with the grant operation.
Authorization and Availability Requirements
To grant a component privilege, you must have one of these privileges:
-
User administrative privileges (that is, a user who has been granted the MANAGE_USERS component privilege). Initially, DB_ROOT is the only database user who has been granted the MANAGE_USERS component privilege.
-
A user other than a user administrator who has the WITH GRANT OPTION for the component privilege.
-
A user who was granted a role that has the WITH GRANT OPTION privilege for the component privilege.
3.33.3. Examples of GRANT COMPONENT PRIVILEGE
-
Grant a component privilege, CREATE_TABLE, on a component, SQL_OPERATIONS, to SQLUSER1:
GRANT COMPONENT PRIVILEGE CREATE_TABLE ON SQL_OPERATIONS TO sqluser1;
3.34. GRANT ROLE Statement
The GRANT ROLE statement grants one or more roles to a user. See Roles.
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
GRANT ROLE {role-name [,role-name ]...}
TO grantee
grantee is:
database-username
3.34.1. Syntax Description of GRANT ROLE
-
`role-name [,role-name] …
specifies the existing roles to grant.
-
TO grantee
specifies the registered database username to whom to grant the roles.
3.34.2. Considerations for GRANT ROLE
-
To grant roles to other grantees, you must own the roles or have user administrative privileges for the roles. You have user administrative privileges for roles if you have been granted the MANAGE_ROLES component privilege. Initially, DB ROOT is the only database user who has been granted the MANAGE_ROLES component privilege.
-
When you grant a role to a user, the additional privileges are automatically propagated to and detected by active sessions. There is no need for users to disconnect from and reconnect to a session to see the updated set of privileges.
-
If any errors occur in processing a GRANT ROLE statement that names multiple roles, then no grants are done.
-
If you attempt to grant a role but a grant with the same role and grantee already exists, SQL ignores the request and returns a successful operation.
3.34.3. Examples of GRANT ROLE
-
To grant multiple roles to a grantee:
GRANT ROLE clerks, sales TO jsmith;
3.35. INSERT Statement
The INSERT statement is a DML statement that inserts rows in a table or view.
INSERT INTO table [(target-col-list)] insert-source
target-col-list is:
colname [,colname]...
insert-source is:
query-expr [order-by-clause] [access-clause] | DEFAULT VALUES
3.35.1. Syntax Description of INSERT
-
table
names the user table or view in which to insert rows. table must be a base table or an updatable view.
-
(target-col-list)
names the columns in the table or view in which to insert values. The data type of each target column must be compatible with the data type of its corresponding source value. Within the list, each target column must have the same position as its associated source value, whose position is determined by the columns in the table derived from the evaluation of the query expression (query-expr).
If you do not specify all of the columns in table in the target-col-list, column default values are inserted into the columns that do not appear in the list. See Column Default Settings.
If you do not specify target-col-list, row values from the source table are inserted into all columns in table. The order of the column values in the source table must be the same order as that of the columns specified in the CREATE TABLE for table. (This order is the same as that of the columns listed in the result table of SHOWDDL table.)
-
insert-source
specifies the rows of values to be inserted into all columns of table or, optionally, into specified columns of table.
-
query-expr
For the description of query-expr, order-by-clause, and access-clause, see the SELECT Statement.
-
DEFAULT VALUES
is equivalent to a query-expr of the form VALUES (DEFAULT, …). The value of each DEFAULT is the default value defined in the column descriptor of colname, which is contained in the table descriptor of table. Each default value is inserted into its column to form a new row. If you specify DEFAULT VALUES, you cannot specify a column list. You can use DEFAULT VALUES only when all columns in table have default values.
-
3.35.2. Considerations for INSERT
Authorization Requirements
INSERT requires authority to read and write to the table or view receiving the data and authority to read tables or views specified in the query expression (or any of its subqueries) in the INSERT statement.
Transaction Initiation and Termination
The INSERT statement automatically initiates a transaction if no transaction is active. Alternatively, you can explicitly initiate a transaction with the BEGIN WORK statement. After a transaction is started, the SQL statements execute within that transaction until a COMMIT or ROLLBACK is encountered or an error occurs. If AUTOCOMMIT is ON, the transaction terminates at the end of the INSERT statement.
Self-Referencing INSERT and BEGIN WORK or AUTOCOMMIT OFF
A self-referencing INSERT statement is one that references, in the statement’s insert-source, the same table or view into which rows will be inserted (see Examples of Self-Referencing Inserts). A self-referencing INSERT statement will not execute correctly and an error is raised if either BEGIN WORK or AUTOCOMMIT OFF is used unless the compiler’s plan sorts the rows before they are inserted. If you want to use a self-referencing INSERT statement, you should avoid the use of BEGIN WORK or AUTOCOMMIT OFF. For information about AUTOCOMMIT, see the SET TRANSACTION Statement.
Isolation Levels of Transactions and Access Options of Statements
The isolation level of an SQL transaction defines the degree to which the operations on data within that transaction are affected by operations of concurrent transactions. When you specify access options for the DML statements within a transaction, you override the isolation level of the containing transaction. Each statement then executes with its individual access option.
Use of a VALUES Clause for the Source Query Expression
If the query expression consists of the VALUES keyword followed by rows of values, each row consists of a list of value expressions or a row subquery (a subquery that returns a single row of column values). A value in a row can also be a scalar subquery (a subquery that returns a single row consisting of a single column value).
Within a VALUES clause, the operands of a value expression can be numeric, string, datetime, or interval values; however, an operand cannot reference a column (except in the case of a scalar or row subquery returning a value or values in its result table).
Requirements for Inserted Rows
Each row to be inserted must satisfy the constraints of the table or underlying base table of the view. A table constraint is satisfied if the check condition is not false—it is either true or has an unknown value.
Using Compatible Data Types
To insert a row, you must provide a value for each column in the table that has no default value. The data types of the values in each row to be inserted must be compatible with the data types of the corresponding target columns.
Inserting Character Values
Any character string data type is compatible with all other character string data types that have the same character set. For fixed length, an inserted value shorter than the column length is padded on the right with blank characters of the appropriate character set (for example, ISO88591 blanks (HEX20). If the value is longer than the column length, string truncation of non-blank trailing characters returns an error, and the truncated string is not inserted.
For variable length, a shorter inserted value is not padded. As is the case for fixed length, if the value is longer than the column length, string truncation of non-blank trailing characters returns an error, and the truncated string is not inserted.
Inserting Numeric Values
Any numeric data type is compatible with all other numeric data types. If you insert a value into a numeric column that is not large enough, an overflow error occurs. If a value has more digits to the right of the decimal point than specified by the scale for the column definition, the value is truncated.
Inserting Interval Values
A value of interval data type is compatible with another value of interval data type only if the two data types are both year-month or both day-time intervals.
Inserting Date and Time Values
Date, time, and timestamp are the three Trafodion SQL datetime data types. A value with a datetime data type is compatible with another value with a datetime data type only if the values have the same datetime fields.
Inserting Nulls
and inserting values with specific data types, you might want to insert nulls. To insert null, use the keyword NULL. NULL only works with the VALUES clause. Use cast (null as type) for select-list.
3.35.3. Examples of INSERT
-
Insert a row into the CUSTOMER table without using a target-col-list:
INSERT INTO sales.customer VALUES (4777, 'ZYROTECHNIKS', '11211 40TH ST.', 'BURLINGTON', 'MASS.', '01803', 'A2'); --- 1 row(s) inserted.
The column name list is not specified for this INSERT statement. This operation works because the number of values listed in the VALUES clause is equal to the number of columns in the CUSTOMER table, and the listed values appear in the same order as the columns specified in the CREATE TABLE statement for the CUSTOMER table.
By issuing this SELECT statement, this specific order is displayed:
SELECT * FROM sales.customer WHERE custnum = 4777; CUSTNUM CUSTNAME STREET ... POSTCODE CREDIT ------------- -------------- --------------- -------- ------ 4777 ZYROTECHNIKS 11211 4OTH ST. ... 01803 A2 --- 1 row(s) selected.
-
Insert a row into the CUSTOMER table using a target-col-list:
INSERT INTO sales.customer (custnum, custname, street, city, state, postcode) VALUES (1120, 'EXPERT MAILERS', '5769 N. 25TH PL', 'PHOENIX', 'ARIZONA', '85016'); --- 1 row(s) inserted.
Unlike the previous example, the insert source of this statement does not contain a value for the CREDIT column, which has a default value. Asa result, this INSERT must include the column name list.
This SELECT statement shows the default value 'C1' for CREDIT:
SELECT * FROM sales.customer WHERE custnum = 1120; CUSTNUM CUSTNAME STREET ... POSTCODE CREDIT ------------- -------------- --------------- -------- ------ 1120 EXPERT MAILERS 5769 N. 25TH PL ... 85016 C1 --- 1 row(s) selected.
-
Insert multiple rows into the JOB table by using only one INSERT statement:
INSERT INTO persnl.job VALUES (100,'MANAGER'), (200,'PRODUCTION SUPV'), (250,'ASSEMBLER'), (300,'SALESREP'), (400,'SYSTEM ANALYST'), (420,'ENGINEER'), (450,'PROGRAMMER'), (500,'ACCOUNTANT'), (600,'ADMINISTRATOR'), (900,'SECRETARY'); --- 10 row(s) inserted.
-
The PROJECT table consists of five columns using the data types numeric, varchar, date, timestamp, and interval. Insert values by using these types:
INSERT INTO persnl.project VALUES (1000, 'SALT LAKE CITY', DATE '2007-10-02', TIMESTAMP '2007-12-21 08:15:00.00', INTERVAL '30' DAY); --- 1 row(s) inserted.
-
Suppose that CUSTLIST is a view of all columns of the CUSTOMER table except the credit rating. Insert information from the SUPPLIER table into the CUSTOMER table through the CUSTLIST view, and then update the credit rating:
INSERT INTO sales.custlist (SELECT * FROM invent.supplier WHERE suppnum = 10); UPDATE sales.customer SET credit = 'A4' WHERE custnum = 10;
You could use this sequence in the following situation. Suppose that one of your suppliers has become a customer. If you use the same number for both the customer and supplier numbers, you can select the information from the SUPPLIER table for the new customer and insert it into the CUSTOMER table through the CUSTLIST view (as shown in the example).
This operation works because the columns of the SUPPLIER table contain values that correspond to the columns of the CUSTLIST view. Further, the credit rating column in the CUSTOMER table is specified with a default value. If you want a credit rating that is different from the default, you must update this column in the row of new customer data.
Examples of Self-Referencing Inserts
-
This is an example of a self-referencing insert:
insert into table1 select pk+?, b, c from table1
-
This is an example of a self-referencing insert where the target of the insert, table1, is also used in a subquery of the insert-source:
insert into table1 select a+16, b, c from table2 where table2.b not in (select b from table1 where a > 16)
The source table is not affected by the insert.
3.36. INVOKE Statement
The INVOKE statement generates a record description that corresponds to a row in the specified table, view, or index. The record description includes a data item for each column in the table, view, or index, including the primary key but excluding the SYSKEY column. It includes the SYSKEY column of a view only if the view explicitly listed the column in its definition.
INVOKE is a Trafodion SQL extension.
INVOKE table-name
3.36.1. Syntax Description of INVOKE
-
table-name
_ specifies the name of a table, view, or index for which to generate a record description. See Database Object Names.
3.36.2. Considerations for INVOKE
3.36.3. Required Privileges
To issue an INVOKE statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the table.
-
You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.
-
You have the SELECT privilege on the target table.
3.36.4. Examples of INVOKE
-
This command generates a record description of the table T:
SQL> invoke trafodion.seabase.t; -- Definition of Trafodion table TRAFODION.SEABASE.T -- Definition current Wed Mar 5 10:36:06 2014 ( A INT NO DEFAULT NOT NULL NOT DROPPABLE ) PRIMARY KEY (A ASC) --- SQL operation complete.
3.37. MERGE Statement
The MERGE statement:
-
Updates a table if the row exists or inserts into a table if the row does not exist. This is upsert functionality.
-
Updates (merges) matching rows from one table to another.
MERGE INTO table [using-clause]
on-clause
{[when-matched-clause]|[when-not-matched-clause]} ...
using-clause is:
USING (select-query) AS derived-table-name [derived-column-names]
on-clause is:
ON predicate
when-matched-clause is:
WHEN MATCHED THEN UPDATE SET set-clause [WHERE predicate]
WHEN MATCHED THEN DELETE
when-not-matched-clause is:
WHEN NOT MATCHED THEN INSERT insert-values-list
insert-values-list is:
[(column1, ..., columnN )] VALUES (value1, ..., valueN)
3.37.1. Syntax Description of MERGE
-
table
is the ANSI logical name for the table.
-
ON predicate
used to determine if a row is or is not present in the table. The ON predicate must be a predicate on the clustering key of the table if the MERGE has a when-not-matched-clause. The clustering key can be a single or multi-column key.
The ON predicate must select a unique row if the MERGE has a when-not-matched-clause.
3.37.2. Considerations for MERGE
3.37.3. Upsert Using Single Row
A MERGE statement allows you to specify a set of column values that should be updated if the row is found, and another row to be inserted if the row is not found. The ON predicate must select exactly one row that is to be updated if the MERGE statement has an INSERT clause.
In a MERGE statement, at least one of the clauses when-matched or when-not-matched must be specified. Note the following:
-
If a when-matched clause is present and the WHERE predicate in the UPDATE is satisfied, the columns in the SET clause are updated.
-
If a when-matched clause is present and the WHERE predicate in the UPDATE is not satisfied, the columns in the SET clause are not updated.
-
If a when-matched clause is present and the UPDATE has no WHERE predicate, the columns in the SET clause are updated.
-
If a when-not-matched clause is present and columns are explicitly specified in the INSERT clause, the specified values for those columns are inserted. Missing columns are updated using the default values for those columns.
This example updates column b to 20 if the row with key column a with value 10 is found. A new row (10, 30) is inserted if the row is not found in table t.
MERGE INTO t ON a = 10
WHEN MATCHED THEN UPDATE SET b = 20
WHEN NOT MATCHED THEN INSERT VALUES (10, 30)
This example updates column b to 20 if column a with value 10 is found. If column a with value 10 is not found, nothing is done.
MERGE INTO t ON a = 10
WHEN MATCHED THEN UPDATE SET b = 20
This example inserts values (10, 30) if column a with value 10 is not found. If column a with value 10 is found, nothing is done.
MERGE INTO t ON a = 10
WHEN NOT MATCHED THEN INSERT VALUES (10, 30)
Conditional Upsert Using Single Row
In this example, the MERGE statement uses a single-row conditional upsert that inserts one row (keycol, col, seqnum) value if a row with that keycol (parameter-specified) value is not yet in table d. Otherwise, the MERGE statement updates that row’s col and seqnum columns if that row’s seqnum is higher than the current (parameter-specified) sequence number. If the matching row’s seqnum column value is not higher than the current sequence number, then that matched row is not updated.
MERGE INTO d ON keycol = ?
WHEN MATCHED THEN UPDATE SET (col, seqnum) = (?, ?) WHERE seqnum < ?
WHEN NOT MATCHED THEN INSERT (keycol, col, seqnum) VALUES (?, ?, ?)
The optional WHERE predicate in the when-matched-then-update clause is useful when the update is wanted only if the given condition is satisfied. Consider this use case. Suppose object
X is represented as a row in table T. Also, suppose a stream of updates exists for object X. The updates are marked by a sequence number at their source. However, the updates flow through a network which does not guarantee first-in, first-out delivery. In fact, the updates may arrive out-of-order to the database. In this case, the last update (the one with the current highest sequence number) should always win in the database. The MERGE statement shown above can be used to satisfy this use case:
-
A stream of updates for table d exists that are sequenced by a sequence number seqnum at their source
-
The updates race through the network and may arrive in the database in any order, and
-
You want to guarantee that the last update (the one with the highest seqnum) always wins in the database.
Restrictions
-
The MERGE statement does not use ESP parallelism.
-
A merged table cannot be a view.
-
Merge is not allowed if the table has constraints.
-
The on-clause cannot contain a subquery. This statement is not allowed:
MERGE INTO t ON a = (SELECT a FROM t1) WHEN ...
-
The optional WHERE predicate in the when-matched clause cannot contain a subquery or an aggregate function. These statements are not allowed:
MERGE INTO t ON a = 10 WHEN MATCHED THEN UPDATE SET b=4 WHERE b=(SELECT b FROM t1) WHEN NOT MATCHED THEN INSERT VALUES (10,30); MERGE INTO t ON a=10 WHEN MATCHED THEN UPDATE SET b=4 WHERE b=MAX(b) WHEN NOT MATCHED THEN INSERT VALUES (10,30);
-
The UPDATE SET clause in a MERGE statement cannot contain a subquery. This statement is not allowed:
MERGE INTO t ON a = 1 WHEN MATCHED THEN UPDATE SET b = (SELECT a FROM t1)
-
The insert-values-list clause in a MERGE statement cannot contain a subquery. This statement is not allowed:
MERGE INTO t ON a = 1 WHEN NOT MATCHED THEN INSERT VALUES ((SELECT a FROM t1))
-
Use of a non-unique on-clause for a MERGE update is allowed only if no INSERT clause exists.
MERGE INTO t USING (SELECT a,b FROM t1) x ON t.a=x.a WHEN MATCHED THEN UPDATE SET b=x.b;
In this example, t.a=x.a is not a fully qualified unique primary key predicate.
-
Use of a non-unique on-clause for a MERGE delete is allowed only if no INSERT clause exists.
MERGE INTO t USING (SELECT a,b FROM t1) x ON t.a=x.a WHEN MATCHED THEN DELETE;
MERGE From One Table Into Another
The MERGE statement can be used to upsert all matching rows from the source table into the target table. Each row from the source table is treated as the source of a single upsert statement. The using-clause contains the select-query whose output is used as the source to the MERGE statement.
The source select-query must be renamed using the AS clause.
MERGE INTO t ON
USING (_select-query_) AS Z(X) ON col = Z.X
WHEN MATCHED THEN . . .
For each row selected out of the select-query, the MERGE statement is evaluated. Values selected are used in the on-clause to join with the column of the merged table. If the value is found, it is updated. If it is not found, the insert is done. The restrictions are the same as those for <<upsert_using_single_row, Upsert Using Single Row>.
3.37.4. Examples of MERGE
-
This query extracts derived columns a and b from the USING query as derived table z and use each row to join to the merged table t based on the on-clause. For each matched row, column b in table t is updated using column b in derived table z. For rows that are not matched, values z.a and z.b are inserted.
MERGE INTO t USING (SELECT * FROM t1) z(a,b) on a = z.a WHEN MATCHED THEN UPDATE SET b = z.b WHEN NOT MATCHED THEN INSERT VALUES (z.a, z.b);
3.38. PREPARE Statement
The PREPARE statement compiles an SQL statement for later use with the EXECUTE statement in the same Trafodion Command Interface (TrafCI) session.
You can also use PREPARE to check the syntax of a statement without executing the statement in the same TrafCI session.
PREPARE statement-name FROM statement
3.38.1. Syntax Description of PREPARE
-
statement-name
is an SQL identifier that specifies a name to be used for the prepared statement. See Identifiers. The statement name should be a character string and not a numeric value. If you specify the name of an existing prepared statement, the new statement overwrites the previous one.
-
statement
specifies the SQL statement to prepare.
3.38.2. Considerations for PREPARE
Availability of a Prepared Statement
If a PREPARE statement fails, any subsequent attempt to run EXECUTE on the named statement fails. Only the TrafCI session that executes the PREPARE can run EXECUTE on the prepared statement.
The prepared statement is available for running EXECUTE until you terminate the TrafCI session.
A statement must be compiled by PREPARE before you can run EXECUTE on it. However, after the statement is compiled, you can run EXECUTE on the statement multiple times without recompiling the statement.
3.38.3. Examples of PREPARE
-
Prepare a SELECT statement, checking for syntax errors:
SQL>prepare empsal from +>select salary from employee +>where jobcode = 100; *** ERROR[4082] Table, view or stored procedure TRAFODION.INVENT.EMPLOYEE does not exist or is inaccessible. *** ERROR[8822] The statement was not prepared. SQL>
-
Prepare a SELECT statement with an unnamed parameter (?) and later run EXECUTE on it:
SQL>prepare findsal from +>select salary from persnl.employee +>where jobcode = ?; --- SQL command prepared. SQL>execute findsal using 450; SALARY ---------- 32000.00 33000.50 40000.00 32000.00 45000.00 --- 5 row(s) selected. SQL>
-
Prepare a SELECT statement with a named parameter (?param-name) and later run EXECUTE on it:
SQL>prepare findsal from +>select salary from persnl.employee +>where jobcode = ?job; --- SQL command prepared. SQL>set param ?job 450 SQL>execute findsal; SALARY ---------- 32000.00 33000.50 40000.00 32000.00 45000.00 --- 5 row(s) selected. SQL>
For more information, see the EXECUTE Statement.
3.39. REGISTER USER Statement
The REGISTER USER statement registers a user in the SQL database, associating the user’s login name with a database username.
REGISTER USER is a Trafodion SQL extension.
The user’s login name is also the name by which the user is defined in the directory service, so the syntax description below refers to it as the directory-service username. |
REGISTER USER directory-service-username [ AS database-username ]
3.39.1. Syntax Description of REGISTER USER
-
directory-service-username
is the name that identifies the user in the directory service. This is also the name the user specifies when logging in to a Trafodion database. The directory-service-username is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers.
-
database-username
is a regular or delimited case-insensitive identifier that denotes the username as defined in the database. The database username cannot be identical to a registered database username or an existing role name. However, it can be the same as the directory-service username. If you omit the AS database-username clause, the database username will be the same as the directory-service username.
3.39.2. Considerations for REGISTER USER
Who Can Register a User
To register a user, you must have user administrative privileges. You have user administrative privileges if you have been granted the MANAGE_USERS component privilege. Initially, DB ROOT is the only database user who has been granted the MANAGE_USERS component privilege.
Add the User to the Directory Before Registering the User
Add the user to the appropriate directory service before you register the user. Otherwise, REGISTER USER will fail.
AS database-username Clause
Use the AS database-username clause to assign a database username that is different than the username defined in the directory service. In particular, it is often convenient to assign a database username that is shorter and easier to type than the directory-service username.
For example, if the user logs on as John.Allen.Doe.the.Second@mycompany.com
, you might want to assign the user a
database username of JDoe.
Database user names are authorization IDs. If you specify a name already assigned to another user or to an existing role, the command will fail. For more information, see Authorization IDs.
Reserved Names
PUBLIC, _SYSTEM, NONE, and database user names beginning with DB are reserved. You cannot register users with any such name.
Username Length
Database user names are limited to 128 characters.
3.39.3. Examples of REGISTER USER
-
To register a user and assign a database username different than the user’s login name:
REGISTER USER "jsmith@company.com" AS jsmith;
-
To register a user without specifying a database username, so the database username will be the same as the user’s login name:
REGISTER USER "jsmith@company.com";
3.40. REVOKE Statement
The REVOKE statement revokes access privileges on an SQL object from specified users or roles.
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
REVOKE [GRANT OPTION FOR]
{privilege [,privilege]...| ALL [PRIVILEGES]}
ON [object-type] [schema.]object
FROM {grantee [,grantee]...}
[[GRANTED] BY grantor] [RESTRICT | CASCADE]
privilege is:
SELECT
| DELETE
| INSERT
| REFERENCES
| UPDATE
| EXECUTE
| USAGE
object-type is:
TABLE
| PROCEDURE
| LIBRARY
| FUNCTION
grantee is:
auth-name
grantor is:
role-name
3.40.1. Syntax Description of REVOKE
-
GRANT OPTION FOR
specifies that the grantee’s authority to grant the specified privileges to other users or roles (that is, WITH GRANT OPTION) be revoked. This is an optional clause. When this clause is specified, only the ability to grant the privilege to another user is revoked.
-
privilege [, privilege ] … | ALL [ PRIVILEGES ]
specifies the privileges to revoke. You can specify these privileges for an object:
SELECT
Revokes the ability to use the SELECT statement.
DELETE
Revokes the ability to use the DELETE statement.
INSERT
Revokes the ability to use the INSERT statement.
REFERENCES
Revokes the ability to create constraints that reference the object.
UPDATE
Revokes the ability to use the UPDATE statement.
EXECUTE
Revokes the ability to execute a stored procedure using a CALL statement or revokes the ability to execute a user-defined function (UDF).
USAGE
Revokes the ability to access a library using the CREATE PROCEDURE or CREATE FUNCTION statement. Revokes read access to the library’s underlying library file.
ALL
Revokes the ability to use all privileges that apply to the object type. When you specify ALL for a table or view, this includes the SELECT, DELETE, INSERT, REFERENCES, and UPDATE privileges. When the object is a stored procedure or user-defined function (UDF), this includes the EXECUTE privilege. When the object is a library, this includes the UPDATE and USAGE privileges.
-
ON [object-type] object
specifies an object on which to grant privileges. object-type can be:
-
[TABLE] object, where object is a table or view. See Database Object Names.
-
[PROCEDURE] procedure-name, where procedure-name is the name of a stored procedure in Java (SPJ) registered in the database. See "Database Object Names.
-
[LIBRARY] library-name, where library-name is the name of a library object in the database. See "Database Object Names,
-
[FUNCTION] function-name, where function-name is the name of a user-defined function in the database. See "Database Object Names
-
-
FROM {grantee [,grantee] … }
specifies an auth-name from which you revoke privileges.
-
auth-name
specifies the name of an authorization ID from which you revoke privileges. See Authorization IDs. The authorization ID must be a registered database username, existing role name, or PUBLIC. The name is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers.
-
[GRANTED] BY grantor
allows you to revoke privileges on behalf of a role. If not specified, the privileges will be revoked on your behalf as the current user/grantor.
-
role-name
specifies a role on whose behalf the GRANT operation was performed. To revoke the privileges on behalf of a role, you must be a member of the role, and the role must have the authority to revoke the privileges; that is, the role must have been granted the privileges WITH GRANT OPTION.
-
[RESTRICT | CASCADE]
If you specify RESTRICT, the REVOKE operation fails if any privileges were granted or any objects were created based upon the specified privileges.
If you specify CASCADE, any such dependent privileges and objects are removed as part of the REVOKE operation.
The default value is RESTRICT.
3.40.2. Considerations for REVOKE
Authorization and Availability Requirements
You can revoke privileges for which you are the grantor, either through a direct grant or a grant done on your behalf. If you are revoking privileges that were granted on behalf of a role, you must be a member of the role, and you must specify the role in the [GRANTED] BY clause.
If one or more privileges have not been granted, SQL returns a warning.
When you specify the CASCADE option, all objects that were created based upon the privileges being revoked are removed.
3.40.3. Examples of REVOKE
-
To revoke the privilege to grant SELECT and DELETE privileges on a table from a user:
REVOKE GRANT OPTION FOR SELECT, DELETE ON TABLE invent.partloc FROM jsmith;
-
To revoke the privilege to grant SELECT and DELETE privileges on a table from a user and a role:
REVOKE GRANT OPTION FOR SELECT, DELETE ON TABLE invent.partloc FROM jsmith, clerks;
-
To revoke a user’s SELECT privileges on a table:
-- User administrator grants the SELECT privilege to JSMITH: GRANT SELECT ON TABLE invent.partloc TO jsmith WITH GRANT OPTION; -- JSMITH grants the SELECT privilege to AJONES: GRANT SELECT ON TABLE invent.partloc TO ajones; -- If the user administrator attempts to revoke the SELECT -- privilege from JSMITH, this would fail because -- of the privilege granted to AJONES based on the -- privilege granted to JSMITH. -- To successfully revoke the SELECT privilege from -- JSMITH, the SELECT privilege granted to AJONES -- must be revoked first. For this example: -- 1. JSMITH revokes the SELECT privilege granted to AJONES: REVOKE SELECT ON TABLE invent.partloc FROM ajones; -- 2. User administrator revokes the SELECT privilege on the -- table from JSMITH: REVOKE SELECT ON TABLE invent.partloc FROM jsmith RESTRICT; -- The REVOKE operation succeeds. -- An easier way to make the REVOKE operation successful is -- to use the CASCADE option: REVOKE SELECT ON TABLE invent.partloc FROM jsmith CASCADE; -- The REVOKE operation succeeds because the CASCADE option -- causes all specified privileges, and all privileges that -- were granted based upon the specified privileges, to be -- removed.
-
Administration in the shipping department decides that the CLERKS role should no longer be able to grant privileges on the invent.partloc table. Fred has recently moved to another department, so JSMITH revokes the SELECT privilege on the invent.partloc table from Fred, who was granted the privilege by CLERKS. Then, JSMITH revokes the grant option from CLERKS:
REVOKE SELECT on table invent.partloc FROM fred GRANTED BY clerks; REVOKE GRANT OPTION FOR SELECT ON TABLE invent.partloc FROM clerks;
3.41. REVOKE COMPONENT PRIVILEGE Statement
The REVOKE COMPONENT PRIVILEGE statement removes one or more component privileges from a user or role. See Privileges and Roles.
REVOKE COMPONENT PRIVILEGE is a Trafodion SQL extension.
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
REVOKE [GRANT OPTION FOR]
COMPONENT PRIVILEGE {privilege-name[, privilege-name]...}
ON component-name
FROM grantee
[[GRANTED] BY grantor]
grantee is:
auth-name
grantor is:
role-name
3.41.1. Syntax Description of REVOKE COMPONENT PRIVILEGE
-
GRANT OPTION FOR
specifies that the grantee’s authority to grant the specified component privileges to other users or roles (that is, WITH GRANT OPTION) be revoked. This is an optional clause. When this clause is specified, only the ability to grant the component privilege to another user is revoked.
-
privilege-name
specifies one or more component privileges to revoke. The comma-separated list can include only privileges within the same component.
-
ON component-name
specifies a valid component name on which to revoke component privileges. Currently, the only valid component name is SQL_OPERATIONS.
-
FROM grantee
specifies an auth-name from which you revoke the component privileges.
-
auth-name
specifies the name of an authorization ID from which you revoke privileges. See Authorization IDs. The authorization ID must be a registered database username, existing role name, or PUBLIC. The name is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers.
-
[ GRANTED ] BY grantor
allows you to revoke component privileges on behalf of a role. If not specified, the component privileges will be revoked on your behalf as the current user/grantor.
-
role-name
specifies a role on whose behalf the GRANT COMPONENT PRIVILEGE operation was performed. To revoke the privileges on behalf of a role, you must be a member of the role, and the role must have the authority to revoke the privileges; that is, the role must have been granted the privileges WITH GRANT OPTION.
3.41.2. Considerations for REVOKE COMPONENT PRIVILEGE
-
At revoke time, all privileges granted WITH GRANT OPTION are removed. That is, the revoke behavior is CASCADE.
-
If none of the component privileges has been granted, SQL returns an error.
-
If one or more component privileges have not been granted, SQL silently ignores those privileges and proceeds with the revoke operation.
-
Component privileges must be revoked before a role can be dropped or a user unregistered. If any privileges have been granted to a role or user, an error is returned when that role is dropped or the user unregistered. For more information, see the DROP ROLE Statement and the UNREGISTER USER Statement.
Authorization and Availability Requirements
You can revoke component privileges for which you are the grantor, either through a direct grant or a grant done on your behalf. If you are revoking privileges that were granted on behalf of a role, you must be a member of the role, and you must specify the role in the [GRANTED] BY clause.
3.41.3. Examples of REVOKE COMPONENT PRIVILEGE
-
Revoke a component privilege from SQLUSER1:
REVOKE COMPONENT PRIVILEGE CREATE_TABLE ON SQL_OPERATIONS FROM sqluser1;
3.42. REVOKE ROLE Statement
The REVOKE ROLE statement removes one or more roles from a user. See Roles.
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see Enable Secure Trafodion. |
REVOKE ROLE {role-name [,role-name]...}
FROM grantee
[RESTRICT | CASCADE]
grantee is:
database-username
3.42.1. Syntax Description of REVOKE ROLE
-
role-name [, role-name ] …
specifies the valid roles to revoke.
-
FROM grantee
specifies the registered database username from whom you revoke the roles.
-
[ RESTRICT | CASCADE ]
If you specify RESTRICT, the REVOKE ROLE operation fails if any privileges were granted to the role or any objects were created based upon those privileges.
If you specify CASCADE, any dependent privileges are removed as part of the REVOKE ROLE operation.
The default value is RESTRICT.
3.42.2. Considerations for REVOKE ROLE
-
To revoke roles from users, you must own the roles or have user administrative privileges for the roles. You have user administrative privileges for roles if have been granted the MANAGE_ROLES component privilege. Initially, DB ROOT is the only database user who has been granted the MANAGE_ROLES component privilege.
-
If RESTRICT (or nothing) is specified and if you want to revoke a role from a user that has created objects based solely on role privileges, you must drop the objects before revoking the role. However, if you specify CASCADE, the dependent objects are automatically dropped, and the role is revoked.
-
All of the specified roles must have been granted to the specified user. If any role has not been granted to the user, the operation returns an error, and no roles are revoked.
-
When you revoke a role from a user, the reduction in privileges is automatically propagated to and detected by active sessions. There is no need for users to disconnect from and reconnect to a session to see the updated set of privileges.
-
If the REVOKE ROLE names multiple roles and any errors occur in processing, no revokes are performed.
3.42.3. Examples of REVOKE ROLE
-
To revoke multiple roles from a user:
REVOKE ROLE clerks, sales FROM jsmith;
-
To revoke a role with dependent objects from a user:
-- CMILLER grants a role to AJONES: GRANT ROLE sales TO ajones; -- CMILLER grants a privilege to the role: GRANT SELECT ON TABLE invent.partloc TO sales; -- AJONES creates a view based upon the privilege granted -- to the role granted to him: CREATE VIEW invent.partlocview (partnum, loc_code) AS SELECT partnum, loc_code FROM invent.partloc; -- If CMILLER attempts to revoke the role from AJONES, -- this would fail because of the view created based -- upon the privilege granted to the role granted to -- AJONES. -- CMILLER revokes the role from AJONES with the CASCADE option: REVOKE ROLE sales from AJONES CASCADE; -- The REVOKE ROLE operation succeeds, and all dependent object privileges are revoked.
3.43. ROLLBACK WORK Statement
The ROLLBACK WORK statement undoes all database modifications to objects made during the current transaction and ends the transaction. See Transaction Management.
ROLLBACK [WORK]
3.43.1. Syntax Description of ROLLBACK WORK
WORK is an optional keyword that has no effect.
ROLLBACK WORK issued outside of an active transaction generates error 8609.
3.43.2. Considerations for ROLLBACK WORK
Begin and End a Transaction
BEGIN WORK starts a transaction. COMMIT WORK or ROLLBACK WORK ends a transaction.
3.43.3. Example of ROLLBACK WORK
-
Suppose that you add an order for two parts numbered 4130 to the ORDERS and ODETAIL tables. When you update the PARTLOC table to decrement the quantity available, you discover no such part number exists in the given location.
Use ROLLBACK WORK to terminate the transaction without committing the database changes:
BEGIN WORK; INSERT INTO sales.orders VALUES (124, DATE '2007-04-10', DATE '2007-06-10', 75, 7654); INSERT INTO sales.odetail VALUES (124, 4130, 25000, 2); UPDATE invent.partloc SET qty_on_hand = qty_on_hand - 2 WHERE partnum = 4130 AND loc_code = 'K43'; ROLLBACK WORK;
ROLLBACK WORK cancels the insert and update that occurred during the transaction.
3.44. SELECT Statement
The SELECT statement is a DML statement that retrieves values from tables, views, and derived tables determined by the evaluation of query expressions, or joined tables.
sql-query is:
query-specification
| query-expr-and-order
query-specification is:
SELECT [ "[" ANY N "]" | "[" FIRST N "]" ] [ALL | DISTINCT] select-list
FROM table-ref [,table-ref]...
[WHERE search-condition]
[SAMPLE sampling-method]
[TRANSPOSE transpose-set [transpose-set]...
[KEY BY key-colname]]...
[SEQUENCE BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...]
[GROUP BY {colname | colnum} [,{colname | colnum}]...]
[HAVING search-condition]
[access-clause ]
[mode-clause]
query-expr-and-order is:
query-expr [order-by-clause] [access-clause] [mode-clause]
query-expr is:
query-primary
| query-expr UNION [ALL] query-primary
query-primary is:
simple-table | (query-expr)
simple-table is:
VALUES (row-value-const) [,(row-value-const)]...
| TABLE table
| query-specification
row-value-const is:
row-subquery
| {expression | NULL} [,{expression | NULL}]...
order-by-clause is:
[ORDER BY {colname | colnum} [ASC[ENDING] | DESC[ENDING]]
[,{colname | colnum} [ASC[ENDING] | DESC[ENDING]]]...]
[access-clause]
access clause is:
[FOR] access-option ACCESS
access-option is:
READ COMMITTED
[LIMIT num]
select-list is:
* | select-sublist [,select-sublist]...
select-sublist is:
corr.* | [corr.]single-col [[AS]name] | col-expr [[AS] name]
table-ref is:
table [[AS] corr [(col-expr-list)]]
| view [[AS] corr [(col-expr-list)]]
| (query-expr) [AS] corr [(col-expr-list)]
| (delete-statement [RETURN select-list])
[AS] corr [(col-expr-list)]
| (update-statement [RETURN select-list])
[AS] corr [(col-expr-list)]
| (insert-statement) [AS] corr [(col-expr-list)]
| joined-table
joined-table is:
table-ref [join-type] JOIN table-ref join-spec
| table-ref NATURAL [join-type] JOIN table-ref
| table-ref CROSS JOIN table-ref
| (joined-table)
join-type is:
INNER | LEFT [OUTER] | RIGHT [OUTER] | FULL [OUTER]
join-spec is:
ON search-condition
sampling-method is:
RANDOM percent-size
| FIRST rows-size
[SORT BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]...]
| PERIODIC rows-size EVERY number-rows ROWS
[SORT BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]...]
percent-size is:
percent-result PERCENT [ROWS]
| BALANCE WHEN condition
THEN percent-result PERCENT [ROWS]
[WHEN condition
THEN percent-result PERCENT [ROWS]]...
[ELSE percent-result PERCENT [ROWS]] END
rows-size is:
number-rows ROWS
| BALANCE WHEN condition
THEN number-rows ROWS
[WHEN condition
THEN number-rows ROWS]...
[ELSE number-rows ROWS] END
transpose-set is:
transpose-item-list AS transpose-col-list
transpose-item-list is:
expression-list | (expression-list) [,(expression-list)]...
3.44.1. Syntax Description of SELECT
-
"[" ANY N "]" | "[" FIRST N "]"
specifies that N rows are to be returned (assuming the table has at least N rows and that the qualification criteria specified in the WHERE clause, if any, would select at least N rows) and you do not care which N rows are chosen (out of the qualified rows) to actually be returned.
You must enclose ANY N or FIRST N in square brackets ([]). The quotation marks ("") around each square bracket in the syntax diagram indicate that the bracket is a required character that you must type as shown (for example, [ANY 10] or [FIRST 5]). Do not include quotation marks in ANY or FIRST clauses.
[FIRST N] is different from [ANY N] only if you use ORDER BY on any of the columns in the select list to sort the result table of the SELECT statement. N is an unsigned numeric literal with no scale. If N is greater than the number of rows in the table, all rows are returned. [ANY N] and [FIRST N] are disallowed in nested SELECT statements and on either side of a UNION operation.
-
ALL | DISTINCT
specifies whether to retrieve all rows whose columns are specified by the select-list (ALL) or only rows that are not duplicates (DISTINCT). Nulls are considered equal for the purpose of removing duplicates. The default is ALL.
-
select-list
specifies the columns or column expressions to select from the table references in the FROM clause. See the discussion of limitations in Considerations for Select List.
-
*
specifies all columns in a table, view, joined table, or derived table determined by the evaluation of a query expression, as specified in the FROM clause.
-
corr.*
specifies all columns of specific table references by using the correlation name corr of the table references, as specified in the FROM clause. See Correlation Names.
-
corr.single-col [[AS] name]
specifies one column of specific table references by using the correlation name of the table reference, as specified in the FROM clause. See Correlation Names. By using the AS clause, you can associate the column with a name. name is an SQL identifier. See Identifiers.
-
single-col [[AS] name]
specifies a column. By using the AS clause, you can associate the column with a name. name is an SQL identifier. See Identifiers.
-
col-expr [[AS] name]
specifies a derived column determined by the evaluation of an SQL value expression in the list. By using the AS clause, you can associate a derived column, col-expr, with a name. name is an SQL identifier. See Identifiers.
-
-
FROM table-ref [,table-ref]…
specifies a list of tables, views, derived tables, or joined tables that determine the contents of an intermediate result table from which Trafodion SQL returns the columns you specify in select-list.
If you specify only one table-ref, the intermediate result table consists of rows derived from that table reference. If you specify more than one table-ref, the intermediate result table is the cross-product of result tables derived from the individual table references.
-
table [[AS] corr [(col-expr-list)]] | view [[AS] corr [(col-expr-list)]] | (query-expr) [AS] corr [(col-expr-list)] | (delete-statement [RETURN select-list]) [AS] corr [(col-expr-list)] | (update-statement [RETURN select-list]) [AS] corr [(col-expr-list)] | (insert-statement) [AS] corr [(col-expr-list)] | joined-table
specifies a table-ref as a single table, view, derived table determined by the evaluation of a query expression, or a joined table.
You can specify this optional clause for a table or view. This clause is required for a derived table:
-
[AS] corr [(col-expr-list)]
specifies a correlation name, corr, for the preceding table reference table-ref in the FROM clause. See Correlation Names.
-
col-expr [[AS] name] [,col-expr [[AS] name]] …
specifies the items in col-expr-list, a list of derived columns. By using the AS clause, you can associate a derived column, col-expr, with a name. name is an SQL identifier. See Identifiers.
For the specification of a query expression, see the syntax diagram for query-expr above.
-
-
(delete-statement [RETURN select-list]) [AS] corr [(col-expr-list)]
enables an application to read and delete rows with a single operation. For the syntax of delete-statement, see the DELETE Statement.
-
RETURN select-list
specifies the columns or column expressions returned from the deleted row. the items in the select-list can be of these forms:
-
[old.]*
specifies the row from the old table exposed by the embedded delete. the old table refers to column values before the delete operation. new is not allowed. an implicit old.* return list is assumed for a delete operation that does not specify a return list.
-
-
-
col-expr [[AS] name]
specifies a derived column determined by the evaluation of an sql value expression in the list. any column referred to in a value expression is from the row in the old table exposed by the delete. the old table refers to column values before the delete operation.
By using the as clause, you can associate a derived column, col-expr, with a name. name is an SQL identifier. See Identifier.
-
[AS] corr [(col-expr-list)]
specifies a correlation name, corr, and an optional column list for the preceding items in the select list RETURN select-list. See Correlation Names.
-
(update-statement [RETURN select-list]) [AS] corr [(col-expr-list)]
enables an application to read and update rows with a single operation. For the syntax of update-statement, see the UPDATE Statement.
-
-
RETURN select-list
specifies the columns or column expressions returned from the updated row. The items in the select-list can be of these forms:
-
-
[OLD.| NEW.]*
specifies the row from the old or new table exposed by the update. The old table refers to column values before the update operation; the new table refers to column values after the update operation. If a column has not been updated, the new value is equivalent to the old value.
An implicit NEW.* return list is assumed for an update operation that does not specify a return list.
-
col-expr [[AS] name]
specifies a derived column determined by the evaluation of an SQL value expression in the list. Any column referred to in a value expression can be specified as being from the row in the old table exposed by the update or can be specified as being from the row in the new table exposed by the update.
For example:
RETURN old.empno,old.salary,new.salary, (new.salary - old.salary).
By using the AS clause, you can associate a derived column, col-expr, with a name. name is an SQL identifier. See Identifiers.
-
[AS] corr [(col-expr-list)]
specifies a correlation name, corr, and an optional column list for the preceding items in the select list RETURN select-list. See Correlation Names. For example:
RETURN old.empno,old.salary,new.salary, (new.salary - old.salary) AS emp (empno, oldsalary, newsalary, increase).
-
(insert-statement) [AS] corr [(col-expr-list)]
For the syntax of insert-statement, see the INSERT Statement.
-
-
[AS] corr [(col-expr-list)]
specifies a correlation name, corr, and an optional column list. See Correlation Names.
-
joined-table
A joined-table can be specified as:
_table-ref_ [_join-type_] JOIN _table-ref join-spec_ | _table-ref_ NATURAL [_join-type_] JOIN _table-ref_ | _table-ref_ CROSS JOIN _table-ref_ | (_joined-table_)
-
-
-
join-type is: INNER | LEFT [OUTER] | RIGHT [OUTER] | FULL [OUTER]
is a joined table. You specify the join-type by using the CROSS, INNER, OUTER, LEFT, RIGHT, and FULL keywords. If you omit the optional OUTER keyword and use LEFT, RIGHT, or FULL in a join, Trafodion SQL assumes the join is an outer join.
If you specify a CROSS join as the join-type, you cannot specify a NATURAL join or a
-
join-spec.
If you specify an INNER, LEFT, RIGHT, or FULL join as the join-type and you do not specify a NATURAL join, you must use an ON clause as the join-spec, as follows: subqueries are not allowed in the join predicate of FULL OUTER JOIN.
-
ON search-condition
specifies a search-condition for the join. Each column reference in search-condition must be a column that exists in either of the two result tables derived from the table references to the left and right of the JOIN keyword. A join of two rows in the result tables occurs if the condition is satisfied for those rows.
The type of join and the join specification if used determine which rows are joined from the two table references, as follows:
-
table-ref CROSS JOIN table-ref
joins each row of the left table-ref with each row of the right table-ref.
-
table-ref NATURAL JOIN table-ref
joins rows only where the values of all columns that have the same name in both tables match. This option is equivalent to NATURAL INNER.
-
table-ref NATURAL LEFT JOIN table-ref
joins rows where the values of all columns that have the same name in both tables match, plus rows from the left table-ref that do not meet this condition.
-
table-ref NATURAL RIGHT JOIN table-ref
joins rows where the values of all columns that have the same name in both tables match, plus rows from the right table-ref that do not meet this condition.
-
-
table-ref NATURAL FULL JOIN table-ref
joins rows where the values of all columns that have the same name in both tables match, plus rows from either side that do not meet this condition, filling in NULLs for missing values.
-
table-ref JOIN table-ref join-spec
joins only rows that satisfy the condition in the join-spec clause. This option is equivalent to INNER JOIN … ON.
-
table-ref LEFT JOIN table-ref join-spec
joins rows that satisfy the condition in the join-spec clause, plus rows from the left table-ref that do not satisfy the condition.
-
table-ref RIGHT JOIN table-ref join-spec
joins rows that satisfy the condition in the join-spec clause, plus rows from the right table-ref that do not satisfy the condition.
-
table-ref FULL OUTER JOIN table-ref join-spec
combines the results of both left and right outer joins. These joins show records from both tables and fill in NULLs for missing matches on either side
-
simple-table
A simple-table can be specified as:
VALUES (_row-value-const_) [,(_row-value-const_)]... | TABLE _table_ | _query-specification_
A simple-table can be a table value constructor. It starts with the VALUES keyword followed by a sequence of row value constructors, each of which is enclosed in parentheses. A row-value-const is a list of expressions (or NULL) or a row subquery (a subquery that returns a single row of column values). An operand of an expression cannot reference a column (except when the operand is a scalar subquery returning a single column value in its result table).
The use of NULL as a row-value-const element is a Trafodion SQL extension.
A simple-table can be specified by using the TABLE keyword followed by a table name, which is equivalent to the query specification SELECT * FROM table.
A simple-table can be a query-specification—that is, a SELECT statement consisting of SELECT … FROM … with optionally the WHERE, SAMPLE, TRANSPOSE, SEQUENCE BY, GROUP BY, and HAVING clauses.
-
WHERE search-condition
specifies a search-condition for selecting rows. See Search Condition. The WHERE clause cannot contain an aggregate (set) function.
The search-condition is applied to each row of the result table derived from the table reference in the FROM clause or, in the case of multiple table references, the cross-product of result tables derived from the individual table references.
Each column you specify in search-condition is typically a column in this intermediate result table. In the case of nested subqueries used to provide comparison values, the column can also be an outer reference. SeeSubquery.
To comply with ANSI standards, Trafodion SQL does not move aggregate predicates from the WHERE clause to a HAVING clause and does not move non-aggregate predicates from the HAVING clause to the WHERE clause.
-
SAMPLE sampling-method
specifies the sampling method used to select a subset of the intermediate result table of a SELECT statement. Each of the methods uses a sampling size. The three sampling methods—random, first, and periodic—are specified as:
-
RANDOM percent-size
directs Trafodion SQL to choose rows randomly (each row having an unbiased probability of being chosen) without replacement from the result table. The sampling size is determined by using a percent of the result table.
-
FIRST rows-size [SORT BY colname [,colname]…]
directs Trafodion SQL to choose the first rows-size rows from the sorted result table. The sampling size is determined by using the specified number of rows.
-
PERIODIC rows-size EVERY number-rows ROWS [SORT BY colname [,colname] …]
directs Trafodion SQL to choose the first rows from each block (period) of contiguous sorted rows. The sampling size is determined by using the specified number of rows chosen from each block.
-
SAMPLE is a Trafodion SQL extension. See SAMPLE Clause.
-
-
TRANSPOSE transpose-set[transpose-set]… [KEY BY key-colname]
specifies the transpose-sets and an optional key clause within a TRANSPOSE clause. You can use multiple TRANSPOSE clauses in a SELECT statement.
-
transpose-item-list AS transpose-col-list
specifies a transpose-set. You can use multiple transpose sets within a TRANSPOSE clause. The TRANSPOSE clause generates, for each row of the source table derived from the table reference or references in the FROM clause, a row for each item in each transpose-item-list of all the transpose sets.
The result table of a TRANSPOSE clause has all the columns of the source table plus a value column or columns, as specified in each transpose-col-list of all the transpose sets, and an optional key column key-colname.
-
KEY BY key-colname
optionally specifies an optional key column key-colname. It identifies which expression the value in the transpose column list corresponds to by its position in the transpose-item-list. key-colname is an SQL identifier. The data type is exact numeric, and the value is NOT NULL.
-
TRANSPOSE is a Trafodion SQL extension. See TRANSPOSE Clause.
-
-
SEQUENCE BY colname [ASC[ENDING] | DESC[ENDING]] [,colname [ASC[ENDING] | DESC[ENDING]]] …
specifies the order in which to sort the rows of the intermediate result table for calculating sequence functions. You must include a SEQUENCE BY clause if you include a sequence function in select-list. Otherwise, Trafodion SQL returns an error. Further, you cannot include a SEQUENCE BY clause if no sequence function is in select-list.
-
colname
names a column in select-list or a column in a table reference in the FROM clause of the SELECT statement. colname is optionally qualified by a table, view, or correlation name; for example, CUSTOMER.CITY.
-
ASC | DESC
specifies the sort order. The default is ASC. When Trafodion SQL orders an intermediate result table on a column that can contain null, nulls are considered equal to one another but greater than all other non-null values.
-
-
-
GROUP BY [col-expr] {colname | colnum} [,{colname | colnum}]…]
specifies grouping columns that define a set of groups for the result table of the SELECT statement. The expression in the GROUP BY clause must be exactly the same as the expression in the select list. These columns must appear in the list of columns in the table references in the FROM clause of the SELECT statement.
If you include a GROUP BY clause, the columns you refer to in the select-list must be grouping columns or arguments of an aggregate (or set) function.
The grouping columns define a set of groups in which each group consists of rows with identical values in the specified columns. The column names can be qualified by a table or view name or a correlation name; for example, CUSTOMER.CITY.
For example, if you specify AGE, the result table contains one group of rows with AGE equal to 40 and one group of rows with AGE equal to 50. If you specify AGE and then JOB, the result table contains one group for each age and, within each age group, subgroups for each job code.
You can specify GROUP BY using ordinals to refer to the relative position within the SELECT list. For example, GROUP BY 3, 2, 1.
For grouping purposes, all nulls are considered equal to one another. The result table of a GROUP BY clause can have only one null group. See Considerations for GROUP BY.
-
HAVING search-condition
specifies a search-condition to apply to each group of the grouped table resulting from the preceding GROUP BY clause in the SELECT statement.
To comply with ANSI standards, Trafodion SQL does not move aggregate predicates from the WHERE clause to a HAVING clause and does not move non-aggregate predicates from the HAVING clause to the WHERE clause.
If no GROUP BY clause exists, the search-condition is applied to the entire table (which consists of one group) resulting from the WHERE clause (or the FROM clause if no WHERE clause exists).
In search-condition, you can specify any column as the argument of an aggregate (or set) function; for example, AVG (SALARY). An aggregate function is applied to each group in the grouped table.
A column that is not an argument of an aggregate function must be a grouping column. When you refer to a grouping column, you are referring to a single value because each row in the group contains the same value in the grouping column. See Search Condition.
-
[FOR] access-option ACCESS
specifies the access-option when accessing data specified by the SELECT statement or by a table reference in the FROM clause derived from the evaluation of a query expression that is a SELECT statement. See Data Consistency and Access Options.
-
READ COMMITTED
specifies that any data accessed must be from committed rows.
-
UNION [ALL] select-stmt
specifies a set union operation between the result table of a SELECT statement and the result table of another SELECT statement.
The result of the union operation is a table that consists of rows belonging to either of the two contributing tables. If you specify UNION ALL, the table contains all the rows retrieved by each SELECT statement. Otherwise, duplicate rows are removed.
The select lists in the two SELECT statements of a union operation must have the same number of columns, and columns in corresponding positions within the lists must have compatible data types. The select lists must not be preceded by [ANY N] or [FIRST N].
The number of columns in the result table of the union operation is the same as the number of columns in each select list. The column names in the result table of the union are the same as the corresponding names in the select list of the left SELECT statement. A column resulting from the union of expressions or constants has the name (EXPR). See Considerations for UNION.
-
ORDER BY {colname | colnum} [ASC[ENDING] | DESC[ENDING]] [,{colname | colnum} [ASC[ENDING] | DESC[ENDING]]]…
specifies the order in which to sort the rows of the final result table.
-
colname
names a column in select-list or a column in a table reference in the FROM clause of the SELECT statement. colname is optionally qualified by a table, view, or correlation name; for example, CUSTOMER.CITY. If a column has been aliased to another name you must use the alias name.
-
colnum
specifies a column by its position in select-list. Use colnum to refer to unnamed columns, such as derived columns.
-
ASC | DESC
specifies the sort order. The default is ASC. For ordering a result table on a column that can contain null, nulls are considered equal to one another but greater than all other non-null values.
-
-
LIMIT num
limits the number of rows returned by the query with no limit applied if num is null or less than zero. The LIMIT clause is executed after the ORDER BY clause to support TopN queries.
3.44.2. Considerations for SELECT
Authorization Requirements
SELECT requires authority to read all views and tables referred to in the statement, including the underlying tables of views referred to in the statement.
Use of Views With SELECT
When a view is referenced in a SELECT statement, the specification that defines the view is combined with the statement. The combination can cause the SELECT statement to be invalid. If you receive an error message that indicates a problem but the SELECT statement seems to be valid, check the view definition.
For example, suppose that the view named AVESAL includes column A defined as AVG (X). The SELECT statement that contains MAX (A) in its select list is invalid because the select list actually contains MAX (AVG (X)), and an aggregate function cannot have an argument that includes another aggregate function.
Join Limits
We recommend that you limit the number of tables in a join to a maximum of 64, which includes base tables of views referenced in joins. Queries with joins that involve a larger number of tables are not guaranteed to compile. |
Object Names in SELECT
You can use fully qualified names only in the FROM clause of a SELECT statement.
AS and ORDER BY Conflicts
When you use the AS verb to rename a column in a SELECT statement, and the ORDER BY clause uses the original column name, the query fails. If a column has been aliased to another name, you must use the alias name. The ANSI standard does not support this type of query.
Restrictions on Embedded Inserts
-
An embedded INSERT cannot be used in a join.
-
An embedded INSERT cannot appear in a subquery.
-
An embedded INSERT statement cannot have a subquery in the WHERE clause.
-
An INSERT statement cannot contain an embedded INSERT statement.
-
A union between embedded INSERT expressions is not supported.
-
Declaring a cursor on an embedded INSERT statement is not supported.
DISTINCT Aggregate Functions
An aggregate function can accept an argument specified as DISTINCT, which eliminates duplicate values before the aggregate function is applied. For a given grouping, multiple DISTINCT aggregates are allowed and can be used with non distinct aggregates. A restriction exists that DISTINCT STDDEV and VARIANCE cannot be used with multiple DISTINCT aggregates.
Limitations of DISTINCT Aggregates
-
No limit exists to the number of distinct aggregates.
-
Distinct STDDEV and distinct VARIANCE are not supported with multiple distinct aggregates. For example, this statement will result in an error.
SELECT sum(distinct a), stddev(distinct b) from T group by d;
Examples of Multiple Distinct Aggregates
-
This statement contains distinct aggregates:
SELECT sum(distinct a), count(distinct b), avg(distinct c) from T group by d;
-
This statement does not contain multiple distincts. Because each distinct aggregate is on the same column (a), this is treated as one distinct value.
SELECT sum(distinct a), count(distinct a), avg(distinct a) from T group by d;
-
This statement shows that multiple distinct aggregates can be used with non distinct aggregates:
SELECT sum(distinct a), avg(distinct b), sum(c) from T group by d;
Considerations for Select List
-
The * and corr.* forms of a select-list specification are convenient. However, such specifications make the order of columns in the SELECT result table dependent on the order of columns in the current definition of the referenced tables or views.
-
A col-expr is a single column name or a derived column. A derived column is an SQL value expression; its operands can be numeric, string, datetime, or interval literals, columns, functions (including aggregate unctions) defined on columns, scalar subqueries, CASE expressions, or CAST expressions. Any single columns named in col-expr must be from tables or views specified in the FROM clause. For a list of aggregate functions, see Aggregate (Set) Functions.
-
If col-expr is a single column name, that column of the SELECT result table is a named column. All other columns are unnamed columns in the result table (and have the (EXPR) heading) unless you use the AS clause to specify a name for a derived column.
Considerations for GROUP BY
-
If you include a GROUP BY clause, the columns you refer to in the select-list must be either grouping columns or arguments of an aggregate (or set) function. For example, if AGE is not a grouping column, you can refer to AGE only as the argument of a function, such as AVG (AGE).
-
The expression in the GROUP BY clause must be exactly the same as the expression in the select list. An error will be returned if it is not. It cannot contain aggregate functions or subqueries.
-
If the value of col-expr is a numeric constant, it refers to the position of the select list item and is treated as the current GROUP BY using the ordinal feature.
-
You can specify GROUP BY using ordinals to refer to the relative position within the SELECT list. For example, GROUP BY 3, 2, 1.
-
If you do not include a GROUP BY clause but you specify an aggregate function in the select-list, all rows of the result table form the one and only group. The result of AVG, for example, is a single value for the entire table.
Considerations for ORDER BY
When you specify an ORDER BY clause and its ordering columns, consider:
-
ORDER BY is allowed only in the outer level of a query or in the SELECT part of an INSERT/SELECT statement. It is not allowed inside nested SELECT expressions, such as subqueries.
-
If you specify DISTINCT, the ordering column must be in select-list.
-
If you specify a GROUP BY clause, the ordering column must also be a grouping column.
-
If an ORDER BY clause applies to a union of SELECT statements, the ordering column must be explicitly referenced, and not within an aggregate function or an expression, in the select-list of the leftmost SELECT statement.
-
SQL does not guarantee a specific or consistent order of rows unless you specify an ORDER BY clause. ORDER BY can reduce performance, however, so use it only if you require a specific order.
Considerations for UNION
Suppose that the contributing SELECT statements are named SELECT1 and SELECT2, the contributing tables resulting from the SELECT statements are named TABLE1 and TABLE2, and the table resulting from the UNION operation is named RESULT.
Characteristics of the UNION Columns
For columns in TABLE1 and TABLE2 that contribute to the RESULT table:
-
If both columns contain character strings, the corresponding column in RESULT contains a character string whose length is equal to the greater of the two contributing columns.
-
If both columns contain variable-length character strings, RESULT contains a variable-length character string whose length is equal to the greater of the two contributing columns.
-
If both columns are of exact numeric data types, RESULT contains an exact numeric value whose precision and scale are equal to the greater of the two contributing columns.
-
If both columns are of approximate numeric data types, RESULT contains an approximate numeric value whose precision is equal to the greater of the two contributing columns.
-
If both columns are of datetime data type (DATE, TIME, or TIMESTAMP), the corresponding column in RESULT has the same data type.
-
If both columns are INTERVAL data type and both columns are year-month or day-time, RESULT contains an INTERVAL value whose range of fields is the most significant start field to the least significant end field of the INTERVAL fields in the contributing columns. (The year-month fields are YEAR and MONTH. The day-time fields are DAY, HOUR, MINUTE, and SECOND.)
For example, suppose that the column in TABLE1 has the data type INTERVAL HOUR TO MINUTE, and the column in TABLE2 has the data type INTERVAL DAY TO HOUR. The data type of the column resulting from the union operation is INTERVAL DAY TO MINUTE.
-
If both columns are described with NOT NULL, the corresponding column of RESULT cannot be null. Otherwise, the column can be null.
ORDER BY Clause and the UNION Operator
In a query containing a UNION operator, the ORDER BY clause defines an ordering on the result of the union. In this case, the SELECT statement cannot have an individual ORDER BY clause.
You can specify an ORDER BY clause only as the last clause following the final SELECT statement (SELECT2 in this example). The ORDER BY clause in RESULT specifies the ordinal position of the sort column either by using an integer or by using the column name from the select list of SELECT1.
-
This SELECT statement shows correct use of the ORDER BY clause:
SELECT A FROM T1 UNION SELECT B FROM T2 ORDER BY A
-
This SELECT statement is incorrect because the ORDER BY clause does not follow the final SELECT statement:
SELECT A FROM T1 ORDER BY A UNION SELECT B FROM T2
-
This SELECT statement is also incorrect:
SELECT A FROM T1 UNION (SELECT B FROM T2 ORDER BY A)
Because the subquery (SELECT B FROM T2…) is processed first, the ORDER BY clause does not follow the final SELECT.
GROUP BY Clause, HAVING Clause, and the UNION Operator
In a query containing a UNION operator, the GROUP BY or HAVING clause is associated with the SELECT statement it is a part of (unlike the ORDER BY clause, which can be associated with the result of a union operation). The groups are visible in the result table of the particular SELECT statement. The GROUP BY and HAVING clauses cannot be used to form groups in the result of a union operation.
UNION ALL and Associativity
The UNION ALL operation is left associative, meaning that these two queries return the same result:
(SELECT * FROM TABLE1 UNION ALL
SELECT * FROM TABLE2) UNION ALL SELECT * FROM TABLE3;
SELECT * FROM TABLE1 UNION ALL
(SELECT * FROM TABLE2 UNION ALL SELECT * FROM TABLE3);
If both the UNION ALL and UNION operators are present in the query, the order of evaluation is always from left to right. A parenthesized union of SELECT statements is evaluated first, from left to right, followed by the remaining union of SELECT statements.
3.44.3. Examples of SELECT
-
Retrieve information from the EMPLOYEE table for employees with a job code greater than 500 and who are in departments with numbers less than or equal to 3000, displaying the results in ascending order by job code:
SELECT jobcode, deptnum, first_name, last_name, salary FROM persnl.employee WHERE jobcode > 500 AND deptnum <= 3000 ORDER BY jobcode; DEPTNUM FIRST_NAME LAST_NAME SALARY ------- --------------- ----------- ---------- 1500 JONATHAN MITCHELL 32000.00 1500 JIMMY SCHNEIDER 26000.00 2500 MIRIAM KING 18000.00 1000 SUE CRAMER 19000.00 . . .
-
Display selected rows grouped by job code in ascending order:
SELECT jobcode, AVG(salary) FROM persnl.employee WHERE jobcode > 500 AND deptnum <= 3000 GROUP BY jobcode ORDER BY jobcode; JOBCODE EXPR ------- ---------------------- 600 29000.00 900 25100.00 --- 2 row(s) selected.
This select list contains only grouping columns and aggregate functions. Each row of the output summarizes the selected data within one group.
-
Select data from more than one table by specifying the table names in the FROM clause and specifying the condition for selecting rows of the result in the WHERE clause:
SELECT jobdesc, first_name, last_name, salary FROM persnl.employee E, persnl.job J WHERE E.jobcode = J.jobcode AND E.jobcode IN (900, 300, 420); JOBDESC FIRST_NAME LAST_NAME SALARY ------------ ------------ --------------- ----------- SALESREP TIM WALKER 32000.00 SALESREP HERBERT KARAJAN 29000.00 ... ENGINEER MARK FOLEY 33000.00 ENGINEER MARIA JOSEF 18000.10 ... SECRETARY BILL WINN 32000.00 SECRETARY DINAH CLARK 37000.00 ... --- 27 row(s) selected.
This type of condition is sometimes called a join predicate. The query first joins the EMPLOYEE and JOB tables by combining each row of the EMPLOYEE table with each row of the JOB table; the intermediate result is the Cartesian product of the two tables.
This join predicate specifies that any row (in the intermediate result) with equal job codes is included in the result table. The WHERE condition further specifies that the job code must be 900, 300, or 420. All other rows are eliminated.
The four logical steps that determine the intermediate and final results of the previous query are:
-
Join the tables.
EMPLOYEE Table JOB Table EMPNUM …
JOBCODE …
SALARY
JOBCODE
JOBDESC
-
Drop rows with unequal job codes.
EMPLOYEE Table JOB Table EMPNUM …
JOBCODE …
SALARY
JOBCODE
JOBDESC
1
100
175500
100
MANAGER
. . .
. . .
. . .
. . .
. . .
75
300
32000
300
SALESREP
. . .
. . .
. . .
. . .
. . .
178
900
28000
900
SECRETARY
. . .
. . .
. . .
. . .
. . .
207
420
33000
420
ENGINEER
. . .
. . .
. . .
. . .
. . .
568
300
39500
300
SALESREP
-
Drop rows with job codes not equal to 900, 300, or 420.
EMPLOYEE Table JOB Table EMPNUM …
JOBCODE …
SALARY
JOBCODE
JOBDESC
75
300
32000
300
SALESREP
. . .
. . .
. . .
. . .
. . .
178
900
28000
900
SECRETARY
. . .
. . .
. . .
. . .
. . .
207
420
33000
420
ENGINEER
. . .
. . .
. . .
. . .
. . .
568
300
39500
300
SALESREP
-
Process the select list, leaving only four columns.
JOBDESC FIRST_NAME LAST_NAME SALARY SALESREP
TIM
WALKER
32000
. . .
. . .
. . .
. . .
SECRETARY
JOHN
CHOU
28000
. . .
. . .
. . .
. . .
ENGINEER
MARK
FOLEY
33000
. . .
. . .
. . .
. . .
SALESREP
JESSICA
CRINER
39500
The final result is shown in the output:
JOBDESC FIRST_NAME LAST_NAME SALARY ------------ ------------ --------------- ----------- SALESREP TIM WALKER 32000.00 ... SECRETARY JOHN CHOU 28000.00 ...
-
-
Select from three tables, group the rows by job code and (within job code) by department number, and order the groups by the maximum salary of each group:
SELECT E.jobcode, E.deptnum, MIN (salary), MAX (salary) FROM persnl.employee E, persnl.dept D, persnl.job J WHERE E.deptnum = D.deptnum AND E.jobcode = J.jobcode AND E.jobcode IN (900, 300, 420) GROUP BY E.jobcode, E.deptnum ORDER BY 4; JOBCODE DEPTNUM (EXPR) (EXPR) ------- ------- ----------- ----------- 900 1500 17000.00 17000.00 900 2500 18000.00 18000.00 ... 300 3000 19000.00 32000.00 900 2000 32000.00 32000.00 ... 300 3200 22000.00 33000.10 420 4000 18000.10 36000.00 ... --- 16 row(s) selected.
Only job codes 300, 420, and 900 are selected. The minimum and maximum salary for the same job in each department are computed, and the rows are ordered by maximum salary.
-
Select from two tables that have been joined by using an INNER JOIN on matching part numbers:
SELECT OD.*, P.* FROM sales.odetail OD INNER JOIN sales.parts P ON OD.partnum = P.partnum; Order/Num Part/Num Unit/Price Qty/Ord Part/Num Part Description PRICE Qty/Avail ---------- -------- ------------ ---------- -------- ------------------ ------------ ----------- 400410 212 2450.00 12 212 PCSILVER, 20 MB 2500.00 3525 500450 212 2500.00 8 212 PCSILVER, 20 MB 2500.00 3525 100210 244 3500.00 3 244 PCGOLD, 30 MB 3000.00 4426 800660 244 3000.00 6 244 PCGOLD, 30 MB 3000.00 4426 ... ... ... ... ... ... ... ... --- 72 row(s) selected.
-
Select from three tables and display them in employee number order. Two tables are joined by using a LEFT JOIN on matching department numbers, then an additional table is joined on matching job codes:
SELECT empnum, first_name, last_name, deptname, location, jobdesc FROM employee e LEFT JOIN dept d ON e.deptnum = d.deptnum LEFT JOIN job j ON e.jobcode = j.jobcode ORDER BY empnum;
-
Suppose that the JOB_CORPORATE table has been created from the JOB table by using the CREATE LIKE statement. Form the union of these two tables:
SELECT * FROM job UNION SELECT * FROM job_corporate; JOBCODE JOBDESC ------- ------------------ 100 MANAGER 200 PRODUCTION SUPV 250 ASSEMBLER 300 SALESREP 400 SYSTEM ANALYST 420 ENGINEER 450 PROGRAMMER 500 ACCOUNTANT 600 ADMINISTRATOR 900 SECRETARY 100 CORP MANAGER 300 CORP SALESREP 400 CORP SYSTEM ANALYS 500 CORP ACCOUNTANT 600 CORP ADMINISTRATOR 900 CORP SECRETARY --- 16 row(s) selected.
-
A FULL OUTER JOIN combines the results of both left and right outer joins. These joins show records from both tables and fill in NULLs for missing matches on either side:
SELECT * FROM employee FULL OUTER JOIN department ON employee.DepartmentID = department.DepartmentID; LastName DepartmentID DepartmentName DepartmentID -------- ------------ -------------- ------------ Smith 34 Clerical 34 Jones 33 Engineering 33 Robinson 34 Clerical 34 Jasper 36 NULL NULL Steinberg 33 Engineering 33 Rafferty 31 Sales 31 NULL NULL Marketing 35
-
Present two ways to select the same data submitted by customers from California. The first way:
SELECT OD.ordernum, SUM (qty_ordered * price) FROM sales.parts P, sales.odetail OD WHERE OD.partnum = P.partnum AND OD.ordernum IN ( SELECT O.ordernum FROM sales.orders O, sales.customer C WHERE O.custnum = C.custnum AND state = 'CALIFORNIA' ) GROUP BY OD.ordernum; ORDERNUM (EXPR) ---------- --------------------- 200490 1030.00 300350 71025.00 300380 28560.00 --- 3 row(s) selected.
The second way:
SELECT OD.ordernum, SUM (qty_ordered * price) FROM sales.parts P, sales.odetail OD WHERE OD.partnum = P.partnum AND OD.ordernum IN ( SELECT O.ordernum FROM sales.orders O WHERE custnum IN ( SELECT custnum FROM sales.customer WHERE state = 'CALIFORNIA' ) ) GROUP BY OD.ordernum; ORDERNUM (EXPR) ---------- --------------------- 200490 1030.00 300350 71025.00 300380 28560.00 --- 3 row(s) selected.
The price for the total quantity ordered is computed for each order number.
-
Show employees, their salaries, and the percentage of the total payroll that their salaries represent. Note the subquery as part of the expression in the select list:
SELECT empnum , first_name , last_name , salary , CAST(salary * 100 / ( SELECT SUM(salary) FROM persnl.employee) AS NUMERIC(4,2)) FROM persnl.employee ORDER BY salary, empnum; Employee/Number First Name Last Name salary (EXPR) --------------- --------------- -------------------- ----------- ------- 209 SUSAN CHAPMAN 17000.00 .61 235 MIRIAM KING 18000.00 .65 224 MARIA JOSEF 18000.10 .65 ... 23 JERRY HOWARD 137000.10 4.94 32 THOMAS RUDLOFF 138000.40 4.98 1 ROGER GREEN 175500.00 6.33 ... --- 62 row(s) selected.
-
Examples of using expressions in the GROUP BY clause:
SELECT a+1 FROM t GROUP BY a+1; SELECT cast(a AS int) FROM t GROUP BY cast(a AS int); SELECT a+1 FROM t GROUP BY 1;
-
Examples of unsupported expressions in the GROUP BY clause:
SELECT sum(a) FROM t GROUP BY sum(a); SELECT (SELECT a FROM t1) FROM t GROUP BY (SELECT a FROM t1); SELECT a+1 FROM t GROUP BY 1+a;
3.45. SET SCHEMA Statement
The SET SCHEMA statement sets the default logical schema for unqualified object names for the current SQL session.
SET SCHEMA default-schema-name
3.45.1. Syntax Description of SET SCHEMA
-
default-schema-name
specifies the name of a schema. See Schemas.
default-schema-name is an SQL identifier. For example, you can use MYSCHEMA or myschema or a delimited identifier "My_Schema". See Identifiers.
3.45.2. Considerations for SET SCHEMA
The default schema you specify with SET SCHEMA remains in effect until the end of the session or until you execute another SET SCHEMA statement. If you do not set a schema name for the session using SET SCHEMA, the default schema is SEABASE, which exists in the TRAFODION catalog.
For information on how to create a schema, see Creating and Dropping Schemas.
3.45.3. Examples of SET SCHEMA
-
Set the default schema name:
SET SCHEMA myschema;
3.46. SET TRANSACTION Statement
The SET TRANSACTION statement sets the autocommit attribute for transactions. It stays in effect until the end of the session or until the next SET TRANSACTION statement, whichever comes first. Therefore, the SET TRANSACTION statement can set the autocommit attribute of all subsequent transactions in the session.
SET TRANSACTION autocommit-option
autocommit-option is:
AUTOCOMMIT [ON] | AUTOCOMMIT OFF
3.46.1. Syntax Description of SET TRANSACTION
-
autocommit-option
specifies whether Trafodion SQL commits or rolls back automatically at the end of statement execution. This option applies to any statement for which the system initiates a transaction.
If this option is set to ON, Trafodion SQL automatically commits any changes or rolls back any changes made to the database at the end of statement execution. AUTOCOMMIT is on by default at the start of a session.
If this option is set to OFF, the current transaction remains active until the end of the session unless you explicitly commit or rollback the transaction. AUTOCOMMIT is a Trafodion SQL extension; you cannot use in it with any other option.
Using the AUTOCOMMIT option in a SET TRANSACTION statement does not reset other transaction attributes that may have been specified in a previous SET TRANSACTION statement. Similarly, a SET TRANSACTION statement that does not specify the AUTOCOMMIT attribute does not reset this attribute.
3.46.2. Considerations for SET TRANSACTION
Implicit Transactions
Most DML statements are transaction initiating—the system automatically initiates a transaction when the statement begins executing.
The exceptions (statements that are not transaction initiating) are:
-
COMMIT, FETCH, ROLLBACK, and SET TRANSACTION
-
EXECUTE, which is transaction initiating only if the associated statement is transaction-initiating
Explicit Transactions
You can issue an explicit BEGIN WORK even if the autocommit option is on. The autocommit option is temporarily disabled until you explicitly issue COMMIT or ROLLBACK.
3.46.3. Examples of SET TRANSACTION
-
The following SET TRANSACTION statement turns off autocommit so that the current transaction remains active until the end of the session unless you explicitly commit or rollback the transaction. Trafodion SQL does not automatically commit or roll back any changes made to the database at the end of statement execution. Instead, Trafodion SQL commits all the changes when you issue the COMMIT WORK statement.
SET TRANSACTION AUTOCOMMIT OFF; --- SQL operation complete. BEGIN WORK; --- SQL operation complete. DELETE FROM persnl.employee WHERE empnum = 23; --- 1 row(s) deleted. INSERT INTO persnl.employee (empnum, first_name, last_name, deptnum, salary) VALUES (50, 'JERRY','HOWARD', 1000, 137000.00); --- 1 row(s) inserted. UPDATE persnl.dept SET manager = 50 WHERE deptnum = 1000; --- 1 row(s) updated. COMMIT WORK; --- SQL operation complete.
3.47. SHOWCONTROL Statement
The SHOWCONTROL statement displays the default attributes in effect.
SHOWCONTROL is a Trafodion SQL extension.
SHOWCONTROL {ALL | [QUERY] DEFAULT [attribute-name[, MATCH {FULL | PARTIAL }]]}
3.47.1. Syntax Description of SHOWCONTROL
-
ALL
displays all the hard-coded default attributes that have been set for the Trafodion instance.
-
[QUERY] DEFAULT
displays the CONTROL QUERY DEFAULT statements in effect for the session. For more information, see the Control Query Default Statement.
-
attribute-name[, MATCH {FULL | PARTIAL }]
displays only the defaults that match, either fully or partially, the attribute used in CONTROL QUERY DEFAULT statements. The match is not case-sensitive. For descriptions of these attributes, see the Trafodion Control Query Default (CQD) Reference Guide.
MATCH FULL specifies that attribute-name must be the same as the attribute name used in a control query default statement. match partial specifies that attribute-name must be included in the attribute name used in a control query default statement. the default is match partial.
If attribute-name is a reserved word, such as MIN, MAX, or TIME, you must capitalize attribute-name and delimit it within double quotes ("). The only exceptions to this rule are the reserved words CATALOG and SCHEMA, which you can either capitalize and delimit within double quotes or specify without quotation marks.
3.47.2. Examples of SHOWCONTROL
-
Issue multiple CONTROL QUERY DEFAULT statements followed by a SHOWCONTROL DEFAULT command:
CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL '7200'; --- SQL operation complete. CONTROL QUERY DEFAULT HIST_NO_STATS_REFRESH_INTERVAL '7200'; --- SQL operation complete. SHOWCONTROL DEFAULT; CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL 7200 HIST_NO_STATS_REFRESH_INTERVAL 7200 --- SQL operation complete.
3.48. SHOWDDL Statement
The SHOWDDL statement describes the DDL syntax used to create an object as it exists in the metadata, or it returns a description of a user, role, or component in the form of a GRANT statement.
SHOWDDL is a Trafodion SQL extension.
SHOWDDL showddl-spec
showddl-spec
[TABLE | LIBRARY | PROCEDURE] [schema-name.]object-name[, PRIVILEGES ]
| COMPONENT component-name
| USER database-username
| ROLE role-name[, GRANTEES ]
3.48.1. Syntax Description of SHOWDDL
-
object-name
specifies the ANSI name of an existing table, view, library, or procedure. See Database Object Names. If object-name is not fully qualified, SHOWDDL uses the default schema for the session.
-
PRIVILEGES
describes the PRIVILEGES associated with the object. If specified, privileges are displayed for an object in the form of GRANT statements.
-
component-name
specifies an existing component. Currently, the only valid component name is SQL_OPERATIONS.
-
database-username
specifies a registered database username.
-
role-name
specifies an existing role.
-
GRANTEES
displays all users who have been granted the role in the form of GRANT ROLE statements. This is an optional clause.
3.48.2. Considerations for SHOWDDL
-
SHOWDDL can differ from the original DDL used to create an object.
-
SHOWDDL can be used within TrafCI.
-
SHOWDDL [TABLE \| LIBRARY \| PROCEDURE] displays the following information:
-
A constraint may be disabled.
-
A table may be off line.
-
An active DDL lock may exist on an object.
-
-
SHOWDDL USER displays user information as a REGISTER USER statement.
-
SHOWDDL ROLE displays the role information as a CREATE ROLE statement.
Required Privileges
To issue a SHOWDDL statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the database object.
-
You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.
-
You have the SELECT privilege on the target object.
Differences Between SHOWDDL Output and Original DDL
-
All column constraints (NOT NULL, PRIMARY KEY, and CHECK) are transformed into table constraints. All NOT NULL constraints are consolidated into a single check constraint.
-
Check constraints are moved out of the CREATE TABLE statement and encapsulated in a separate ALTER TABLE ADD CONSTRAINT statement.
-
SHOWDDL generates ALTER TABLE ADD COLUMN statements for each column that was added to the table.
-
All ANSI names in the output are qualified with the schema name.
-
SHOWDDL displays constraint names even though they might not have been specified during the creation of the constraint.
-
SHOWDDL always generates a Java signature for the SPJ.
PRIVILEGES Option
The PRIVILEGES option includes the GRANT statements as they apply to the option. Each privilege is specified in separate GRANT statements even if they were granted in a single statement.
3.48.3. Examples of SHOWDDL
-
This SHOWDDL statement displays the statement that created the specified table in the database and the privileges granted on that table:
SQL>showddl tab41; CREATE TABLE TRAFODION.SCH41.TAB41 ( A INT DEFAULT NULL , B INT DEFAULT NULL ) ; -- GRANT DELETE, INSERT, SELECT, UPDATE, REFERENCES ON TRAFODION."SCH41"."TAB41" TO PAULLOW41 WITH GRANT OPTION; --- SQL operation complete.
-
This SHOWDDL statement displays the statement that registered the specified user in the database:
SQL>showddl user sqluser_admin; REGISTER USER "SQLUSER_ADMIN"; --- SQL operation complete.
-
This SHOWDDL statement displays the statement that created the specified role in the database and the users who have been granted this role:
SQL>showddl role db rootrole; CREATE ROLE "DB ROOTROLE"; SHOWDDL Statement 161 -- GRANT ROLE "DB ROOTROLE" TO "DB ROOT" WITH ADMIN OPTION; --- SQL operation complete.
3.49. SHOWDDL SCHEMA Statement
The SHOWDDL SCHEMA statement displays the DDL syntax used to create a schema as it exists in the metadata and shows the authorization ID that owns the schema.
SHOWDDL SCHEMA is a Trafodion SQL extension.
SHOWDDL SCHEMA [catalog-name.]schema-name
3.49.1. Syntax Description for SHOWDDL SCHEMA
-
schema-name
specifies the ANSI name of an existing catalog and schema. If schema-name is not fully qualified, SHOWDDL uses the default catalog for the session, TRAFODION. For more information, see Database Object Names.
3.49.2. Considerations for SHOWDDL SCHEMA
If not specified, the catalog is the current default catalog, TRAFODION.
Required Privileges
To issue a SHOWDDL SCHEMA statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the schema.
-
You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.
3.49.3. Examples of SHOWDDL SCHEMA
-
This SHOWDDL SCHEMA statement displays the DDL syntax used to create the schema, MYSCHEMA, as it exists in the metadata and shows the authorization ID that owns the schema:
SHOWDDL SCHEMA MYSCHEMA; CREATE PRIVATE SCHEMA "TRAFODION"."MYSCHEMA" AUTHORIZATION "DB ROOT"; --- SQL operation complete.
3.50. SHOWSTATS Statement
The SHOWSTATS statement displays the histogram statistics for one or more groups of columns within a table. These statistics are used to devise optimized access plans.
SHOWSTATS is a Trafodion SQL extension.
SHOWSTATS FOR TABLE table-name ON group-list [DETAIL]
group-list is:
column-list[, column-list]...
| EVERY COLUMN[, column-list]...
| EVERY KEY[, column-list]...
| EXISTING COLUMN[S][, column-list]...
column-list for a single-column group is:
column-name
| (column-name)
| column-name TO column-name
| (column-name) TO (column-name)
| column-name TO (column-name)
| (column-name) TO column-name
column-list for a multicolumn group is:
(column-name, column-name[, column-name]...)
3.50.1. Syntax Description of SHOWSTATS
-
table-name
is the ANSI name of the table for which statistics are to be displayed.
-
ON group-list
specifies one or more groups of columns, group-list, for which to display histogram statistics.
-
group-list is: column-list [, column-list]… | EVERY COLUMN [,column-list]… | EVERY KEY [, column-list]… | EXISTING COLUMN[S] [, column-list]…
specifies the ways in which group-list can be defined. The column list represents both a single-column group and a multi-column group.
-
EVERY COLUMN
indicates that histogram statistics are to be displayed for each individual column of table and any multi columns that make up the primary key and indexes. For columns that do not have histograms, this option returns
No histogram data for column(s) ---]
. -
EVERY KEY
indicates that histogram statistics are to be displayed for columns that make up the primary key and indexes.
-
EXISTING COLUMN[S]
indicates that histogram statistics are to be displayed only for columns of table that actually have histograms. This option yields a more concise report because columns with no histogram data are omitted. This option includes any existing multicolumn histograms.
-
DETAIL
displays statistics for corresponding histogram intervals and other details.
If you do not select the DETAIL keyword, the default display lists the basic histogram information, including the histogram ID, number of intervals, total rows, total UEC, and the column names. The detailed display additionally includes the low value and high value as well as interval data.
-
column-list for a single-column group is: column-name | (column-name) | column-name TO column-name | (column-name) TO (column-name) | column-name TO (column-name) | (column-name) TO column-name
specifies the ways in which the column-name can be defined for single-column groups. A range of columns specified using the TO keyword causes all columns in that range to be included, defined by their order of declaration in the table.
-
column-list for a multicolumn group is: (column-name, column-name[,column-name]…)
specifies the ways in which the column-name can be defined for multicolumn groups. For example, (abc, def) indicates the multicolumn histogram consisting of columns abc and def, not two single-column histograms.
For more information about the column list syntax and specifying columns, see the UPDATE STATISTICS Statement.
-
3.50.2. Considerations for SHOWSTATS
Required Privileges
To issue a SHOWSTATS statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the database object.
-
You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.
-
You have the SELECT privilege on the target object.
-
You have the MANAGE_STATISTICS component privilege for the SQL_OPERATIONS component.
3.50.3. Examples of SHOWSTATS
-
This example displays histogram statistics for table A using the EVERY KEY keyword. In addition, the DETAIL keyword is selected:
SHOWSTATS FOR TABLE A ON EVERY KEY DETAIL;
-
This example displays statistics for table CAT.SCH.A and selects all columns from abc through def:
SHOWSTATS FOR TABLE CAT.SCH.A ON ABC TO DEF;
-
This example displays statistics for table A. The list of column names contained within parenthesis refers to a multicolumn group:
SHOWSTATS FOR TABLE A ON (ABC,DEF);
-
This example displays statistics for table A using the EXISTING COLUMNS keyword. In addition, the DETAIL keyword is selected:
SHOWSTATS FOR TABLE A ON EXISTING COLUMNS DETAIL;
Default output example:
>>SHOWSTATS FOR TABLE A ON EXISTING COLUMNS; Histogram data for Table CAT.SCH.A Table ID: 341261536378386 Hist ID # Ints Rowcount UEC Colname(s) ========== ====== =========== ============================== 623327638 1 11 10 ABC, DEF, GHI 623327633 10 11 10 ABC 623327628 9 11 9 DEF 623327623 10 11 10 GHI --- SQL operation complete. >>SHOWSTATS FOR TABLE A ON ABC; Histogram data for Table CAT.SCH.A Table ID: 341261536378386 Hist ID # Ints Rowcount UEC Colname(s) ========== ====== =========== ============================== 623327633 10 11 10 ABC --- SQL operation complete. >>SHOWSTATS FOR TABLE A ON DEF DETAIL; Detailed Histogram data for Table CAT.SCH.A Table ID: 341261536378386 Hist ID: 623327628 Column(s): DEF Total Rows: 11 Total UEC: 9 Low Value: (1) High Value: (199) Intervals: 9 Number Rowcount UEC Boundary ====== =========== ============================== 0 0 0 (1) 1 1 1 (1) 2 3 1 (2) 3 1 1 (4) 4 1 1 (11) 5 1 1 (12) 6 1 1 (14) 7 1 1 (99) 8 1 1 (123) 9 1 1 (199) --- SQL operation complete.
3.51. TABLE Statement
The TABLE statement is equivalent to the query specification SELECT * FROM table.
TABLE table
3.51.1. Syntax Description of Table Statement
-
table
names the user table or view.
3.51.2. Considerations for TABLE
Relationship to SELECT Statement
The result of the TABLE statement is one form of a simple-table, which refers to the definition of a table reference within a SELECT statement. See the SELECT Statement.
3.51.3. Examples of TABLE Statement
-
This TABLE statement returns the same result as SELECT * FROM job:
TABLE job; Job/Code Job Description -------- -------------------- 100 MANAGER 200 PRODUCTION SUPV 250 ASSEMBLER 300 SALESREP 400 SYSTEM ANALYST 420 ENGINEER 450 PROGRAMMER 500 ACCOUNTANT 600 ADMINISTRATOR 900 SECRETARY --- 10 row(s) selected.
3.52. UNREGISTER USER Statement
The UNREGISTER USER statement removes a database username from the SQL database. The user can no longer log on to the database.
UNREGISTER USER is a Trafodion SQL extension.
UNREGISTER USER database-username [RESTRICT | CASCADE]
3.52.1. Syntax Description of UNREGISTER USER
-
database-username
is the name of a currently registered database user. database-username is a regular or delimited case-insensitive identifier. See Case-Insensitive Delimited Identifiers.
-
[ RESTRICT | CASCADE ]
If you specify RESTRICT, the UNREGISTER USER operation fails if there are any objects or schemas in the database owned by the user or any privileges or roles granted to the user.
If you specify CASCADE, all objects and schemas owned by the user are dropped, and all privileges and roles granted to the user are revoked as part of the UNREGISTER USER operation.
The default value is RESTRICT.
3.52.2. Considerations for UNREGISTER USER
-
To unregister a user, you must have user administrative privileges. You have user administrative privileges if you have been granted the MANAGE_USERS component privilege. Initially,
DB ROOT is the only database user who has been granted the MANAGE_USERS component privilege.
-
You cannot unregister any username beginning with DB . Role names beginning with DB are reserved by Trafodion.
-
UNREGISTER USER fails if you specify RESTRICT (or nothing) and if the user owns any objects or schemas or if the user has been granted any privileges or roles.
3.52.3. Examples of UNREGISTER USER
-
To unregister a user:
UNREGISTER USER "jsmith@company.com";
3.53. UPDATE Statement
The UPDATE statement is a DML statement that updates data in a row or rows in a table or updatable view. Updating rows in a view updates the rows in the table on which the view is based.
Searched UPDATE is:
UPDATE table
{ set-clause-type1 | set-clause-type2 }
set-clause-type1 is:
SET set-clause[, set-clause ]..
set-clause is:
column-name = {expression | NULL}
set-clause-type2 is:
SET (column1, ..., columnN) = {(value1, ..., valueN) | (query-expr)}
[WHERE search-condition]
[[FOR] access-option ACCESS]
access-option is:
READ COMMITTED
3.53.1. Syntax Description of UPDATE
-
table
names the user table or view to update. table must be a base table or an updatable view. To refer to a table or view, use the ANSI logical name. See Database Object Names.
-
set-clause-type1
This type of SET clause associates a value with a specific column in the table being updated. For each set-clause, the value of the specified target column-name is replaced by the value of the update source expression (or NULL). The data type of each target column must be compatible with the data type of its source value.
-
column-name
names a column in table to update. You cannot qualify or repeat a column name. You cannot update the value of a column that is part of the primary key.
-
expression
is an SQL value expression that specifies a value for the column. The expression cannot contain an aggregate function defined on a column. The data type of expression must be compatible with the data type of column-name.
If expression refers to columns being updated, Trafodion SQL uses the original values to evaluate the expression and determine the new value. See Expressions.
-
NULL
can also specify the value of the update source.
-
-
set-clause-type2
This type of SET clause allows multiple columns to be specified on the left side of the assignment operator. These columns are updated using multiple values specified on the right side of the assignment operator. The right side of the assignment operator could be simple values or a subquery.
-
column1, …, columnN
names columns in table to update. You cannot qualify or repeat a column name. You cannot update the value of a column that is part of the primary key.
-
value1, …, valueN
are values specified on the right side of the assignment operator for the columns specified on the left side of the assignment operator. The data type of each value must be compatible with the data type of the corresponding column on the left side of the assignment operator.
-
-
query-expr
is a SELECT subquery. Only one subquery can be specified on the right side of a SET clause. The subquery cannot refer to the table being updated. For the syntax and description of query-expr, see the SELECT Statement.
-
WHERE search-condition
specifies a search-condition that selects rows to update. Within the search-condition, columns being compared are also being updated in the table or view. See Search Condition.
If you do not specify a search-condition, all rows in the table or view are updated.
Do not use an UPDATE statement with a WHERE clause that contains a SELECT for the same table. Reading from and inserting into, updating in, or deleting from the same table generates an error. Use a positioned (WHERE CURRENT OF) UPDATE instead. See MERGE Statement.
-
[FOR] access-option ACCESS
specifies the access-option required for data used in the evaluation of a search condition. See Data Consistency and Access Options.
-
READ COMMITTED
specifies that any data used in the evaluation of the search condition must be from committed rows.
3.53.2. Considerations for UPDATE
Performance
An UPDATE of primary key columns could perform poorly when compared to an UPDATE of non-key columns. This is because the UPDATE operation involves moving records in disk by deleting all the records in the before-image and then inserting the records in the after-image back into the table.
Authorization Requirements
UPDATE requires authority to read and write to the table or view being updated and authority to read any table or view specified in subqueries used in the search condition. A column of a view can be updated if its underlying column in the base table can be updated.
Transaction Initiation and Termination
The UPDATE statement automatically initiates a transaction if no active transaction exists. Otherwise, you can explicitly initiate a transaction with the BEGIN WORK statement. When a transaction is started, the SQL statements execute within that transaction until a COMMIT or ROLLBACK is encountered or an error occurs.
Isolation Levels of Transactions and Access Options of Statements
The isolation level of a Trafodion SQL transaction defines the degree to which the operations on data within that transaction are affected by operations of concurrent transactions. When you specify access options for the DML statements within a transaction, you override the isolation level of the containing transaction. Each statement then executes with its individual access option.
Conflicting Updates in Concurrent Applications
If you are using the READ COMMITTED isolation level within a transaction, your application can read different committed values for the same data at different times. Further, two concurrent applications can update (possibly in error) the same column in the same row.
Requirements for Data in Row
Each row to be updated must satisfy the constraints of the table or underlying base table of the view. No column updates can occur unless all of these constraints are satisfied. (A table constraint is satisfied if the check condition is not false—that is, it is either true or has an unknown value.)
In addition, a candidate row from a view created with the WITH CHECK OPTION must satisfy the view selection criteria. The selection criteria are specified in the WHERE clause of the AS query-expr clause in the CREATE VIEW statement.
Reporting of Updates
When an UPDATE completes successfully, Trafodion SQL reports the number of times rows were updated during the operation.
Under certain conditions, updating a table with indexes can cause Trafodion SQL to update the same row more than once, causing the number of reported updates to be higher than the actual number of changed rows. However, both the data in the table and the number of reported updates are correct. This behavior occurs when all of these conditions are true:
-
The optimizer chooses an alternate index as the access path.
-
The index columns specified in WHERE search-condition are not changed by the update.
-
Another column within the same index is updated to a higher value (if that column is stored in ascending order), or a lower value (if that column is stored in descending order).
When these conditions occur, the order of the index entries ensures that Trafodion SQL will encounter the same row (satisfying the same search-condition) at a later time during the processing of the table. The row is then updated again by using the same value or values.
For example, suppose that the index of MYTABLE consists of columns A and B, and the UPDATE statement is specified:
UPDATE MYTABLE SET B = 20 WHERE A > 10;
If the contents of columns A and B are 1 and 12 respectively before the UPDATE, after the UPDATE Trafodion SQL will encounter the same row indexed by the values 1 and 20.
Updating Character Values
For a fixed-length character column, an update value shorter than the column length is padded with single-byte ASCII blanks (HEX20) to fill the column. If the update value is longer than the column length, string truncation of non blank trailing characters returns an error, and the column is not updated.
For a variable-length character column, an update value is not padded; its length is the length of the value specified. As is the case for fixed length, if the update value is longer than the column length, string truncation of non blank trailing characters returns an error, and the column is not updated.
SET Clause Restrictions and Error Cases
The SET clause has the following restrictions:
-
The number of columns on the left side of each assignment operator should match the number of values or SELECT list elements on the right side. The following examples are not allowed:
UPDATE t SET (a,b)=(10,20,30) UPDATE t set (b,c)=(SELECT r,t,s FROM x)
-
If multi-column update syntax is specified and the right side contains a subquery, only one element, the subquery, is not allowed.
UPDATE t SET (a,b)=(10, (SELECT a FROM t1))
-
More than one subquery is not allowed if multiple-column syntax is used.
UPDATE t SET (a,b)=(SELECT x,y FROM z), (c,d)=(SELECT x,y FROM a))
-
If a subquery is used, it must return at most one row.
3.53.3. Examples of UPDATE
-
Update a single row of the ORDERS table that contains information about order number 200300 and change the delivery date:
UPDATE sales.orders SET deliv_date = DATE '2008-05-02' WHERE ordernum = 200300;
-
Update several rows of the CUSTOMER table:
UPDATE sales.customer SET credit = 'A1' WHERE custnum IN (21, 3333, 324);
-
Update all rows of the CUSTOMER table to the default credit 'C1':
UPDATE sales.customer SET credit = 'C1';
-
Update the salary of each employee working for all departments located in Chicago:
UPDATE persnl.employee SET salary = salary * 1.1 WHERE deptnum IN (SELECT deptnum FROM persnl.dept WHERE location = 'CHICAGO');
The subquery is evaluated for each row of the DEPT table and returns department numbers for departments located in Chicago.
-
This is an example of a self-referencing UPDATE statement, where the table being updated is scanned in a subquery:
UPDATE table3 SET b = b + 2000 WHERE a, b = (SELECT a, b FROM table3 WHERE b > 200);
3.54. UPSERT Statement
The UPSERT statement either updates a table if the row exists or inserts into a table if the row does not exist.
UPSERT is a Trafodion SQL extension.
UPSERT [USING LOAD] INTO table [(target-col-list)] {query-expr | values-clause}
target-col-list is:
column-name[, column-name]...
values-clause is:
VALUES ( expression[, expression]... )
3.54.1. Syntax Description of UPSERT
-
USING LOAD
allows the UPSERT to occur without a transaction. Use this clause when inserting data into an empty table. If you do not specify this clause, the UPSERT occurs within a transaction.
-
table
names the user table in which to insert or update rows. table must be a base table. (target-col-list)
names the columns in the table in which to insert or update values. The data type of each target
column must be compatible with the data type of its corresponding source value. Within the list, each target column must have the same position as its associated source value, whose position is determined by the columns in the table derived from the evaluation of the query expression (query-expr).
If you do not specify all of the columns in the target table in the target-col-list, column default values are inserted into or updated in the columns that do not appear in the list. See Column Default Settings.
If you do not specify target-col-list, row values from the source table are inserted into or updated in all columns in table. The order of the column values in the source table must be the same order as that of the columns specified in the CREATE TABLE for table. (This order is the same as that of the columns listed in the result table of SHOWDDL table.)
-
column-name
names a column in the target table in which to either insert or update data. You cannot qualify or repeat a column name.
-
query-expr
is a SELECT subquery that returns data to be inserted into or updated in the target table. The subquery cannot refer to the table being operated on. For the syntax and description of query-expr, see the SELECT Statement.
-
VALUES ( expression[, expression]… )
specifies an SQL value expression or a set of expressions that specify values to be inserted into or updated in the target table. The data type of expression must be compatible with the data type of the corresponding column in the target table. See Expressions.
3.54.2. Examples of UPSERT
-
This UPSERT statement either inserts or updates the part number and price in the PARTS table using the part number and unit price from the ODETAIL table where the part number is 244:
UPSERT INTO sales.parts (partnum, price) SELECT partnum, unit_price FROM sales.odetail WHERE partnum = 244;
-
This UPSERT statement either inserts or updates rows in the EMPLOYEE table using the results of querying the EMPLOYEE_EUROPE table:
UPSERT INTO persnl.employee SELECT * FROM persnl.employee_europe;
-
This UPSERT statement either inserts or updates a row in the DEPT table using the specified values:
UPSERT INTO persnl.dept VALUES (3500,'CHINA SALES',111,3000,'HONG KONG');
-
This UPSERT statement either inserts or updates a row in the DEPT table using the specified values:
UPSERT INTO persnl.dept (deptnum, deptname, manager) VALUES (3600,‘JAPAN SALES’, 996);
3.55. VALUES Statement
The VALUES statements starts with the VALUES keyword followed by a sequence of row value constructors, each of which is enclosed in parenthesis. It displays the results of the evaluation of the expressions and the results of row subqueries within the row value constructors.
VALUES (row-value-const) [, (row-value-const)]...
row-value-const is:
row-subquery
| {expression | NULL} [,{expression | NULL}...
3.55.1. Syntax Description of VALUES
-
row-value-const
specifies a list of expressions (or NULL) or a row subquery (a subquery that returns a single row of column values). An operand of an expression cannot reference a column (except when the operand is a scalar subquery returning a single column value in its result table).
The results of the evaluation of the expressions and the results of the row subqueries in the row value constructors must have compatible data types.
3.55.2. Considerations for VALUES
Relationship to SELECT Statement
The result of the VALUES statement is one form of a simple-table, which is part of the definition of a table reference within a SELECT statement. See the SELECT Statement.
Relationship to INSERT Statement
For a VALUES clause that is the direct source of an INSERT statement, Trafodion SQL also allows the keyword DEFAULT in a VALUES clause, just like NULL is allowed. For more information, see the INSERT Statement.
3.55.3. Examples of VALUES
-
This VALUES statement displays two rows with simple constants:
VALUES (1,2,3), (4,5,6); (EXPR) (EXPR) (EXPR) ------ ------ ----- 1 2 3 4 5 6 --- 2 row(s) selected.
-
This VALUES statement displays the results of the expressions and the row subquery in the lists:
VALUES (1+2, 3+4), (5, (select count (*) from t)); (EXPR) (EXPR) ------ ----------------- ------ 3 7 5 2 --- 2 row(s) selected.
4. SQL Utilities
A utility is a tool that runs within Trafodion SQL and performs tasks. This section describes the Trafodion SQL utilities:
Uses the Trafodion Bulk Loader to load data from a source table, either a Trafodion table or a Hive table, into a target Trafodion table. |
|
Loads indexes. |
|
Purges data from tables and indexes. |
|
Unloads data from Trafodion tables into an HDFS location that you specify. |
|
Updates the histogram statistics for one or more groups of columns within a table. These statistics are used to devise optimized access plans. |
Trafodion SQL utilities are entered interactively or from script files using a client-based tool, such as the Trafodion Command Interface (TrafCI). To install and configure a client application that enables you to connect to and issue SQL utilities, see the Trafodion Client Installation Guide. |
4.1. LOAD Statement
The LOAD statement uses the Trafodion Bulk Loader to load data from a source table, either a Trafodion table or a Hive table, into a target Trafodion table. The Trafodion Bulk Loader prepares and loads HFiles directly in the region servers and bypasses the write path and the cost associated with it. The write path begins at a client, moves to a region server, and ends when data eventually is written to an HBase data file called an HFile.
The Trafodion bulk load process takes place in the following phases:
-
Disable Indexes (if incremental index build not used)
-
Prepare (takes most time, heart of the bulk load operation)
-
Read source files (Trafodion Table, Hive table, or Hive external table)
-
Data encoded in Trafodion encoding
-
Data repartitioned and sorted to match regions of target table
-
Data written to HFiles
-
Data repartitioned and written to index HFiles (if incremental index build IS used)
-
-
Complete (with or without Snapshot recovery)
-
Take a snapshot of the table
-
Merge HFiles into HBase table (very fast – move, not a copy)
-
Delete snapshot or restore from snapshot if merge fails
-
-
Populate Indexes (if incremental index build is NOT used)
-
Cleanup
-
HFiles temporary space cleanup
-
LOAD is a Trafodion SQL extension.
LOAD [WITH option[[,] option]...] INTO target-table SELECT ... FROM source-table
option is:
TRUNCATE TABLE
| NO RECOVERY
| NO POPULATE INDEXES
| NO DUPLICATE CHECK
| NO OUTPUT
| INDEX TABLE ONLY
| UPSERT USING LOAD
4.1.1. Syntax Description of LOAD
-
target-table
is the name of the target Trafodion table where the data will be loaded. See Database Object Names.
-
source-table
is the name of either a Trafodion table or a Hive table that has the source data. Hive tables can be accessed in Trafodion using the HIVE.HIVE schema (for example, hive.hive.orders). The Hive table needs to already exist in Hive before Trafodion can access it. If you want to load data that is already in an HDFS folder, then you need to create an external Hive table with the right fields and pointing to the HDFS folder containing the data. You can also specify a WHERE clause on the source data as a filter.
-
[WITH option[[,] option]…]
is a set of options that you can specify for the load operation. You can specify one or more of these options:
-
TRUNCATE TABLE
causes the Bulk Loader to truncate the target table before starting the load operation. By default, the Bulk Loader does not truncate the target table before loading data.
-
NO RECOVERY
specifies that the Bulk Loader not use HBase snapshots for recovery. By default, the Bulk Loader handles recovery using the HBase snapshots mechanism.
-
-
NO POPULATE INDEXES
specifies that the Bulk Loader not handle index maintenance or populate the indexes. By default, the Bulk Loader handles index maintenance, disabling indexes before starting the load operation and populating them after the load operation is complete.
-
NO DUPLICATE CHECK
causes the Bulk Loader to ignore duplicates in the source data. By default, the Bulk Loader checks if there are duplicates in the source data and generates an error when it detects duplicates.
-
`NO OUTPUT
prevents the LOAD statement from displaying status messages. By default, the LOAD statement prints status messages listing the steps that the Bulk Loader is executing.
-
INDEX TABLE ONLY
specifies that the target table, which is an index, be populated with data from the parent table.
-
UPSERT USING LOAD
specifies that the data be inserted into the target table using row set inserts without a transaction.
-
4.1.2. Considerations for LOAD
Required Privileges
To issue a LOAD statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the target table.
-
You have these privileges:
-
SELECT and INSERT privileges on the target table
-
DELETE privilege on the target table if TRUNCATE TABLE is specified
-
-
You have the MANAGE_LOAD component privilege for the SQL_OPERATIONS component.
Configuration Before Running LOAD
Before running the LOAD statement, make sure that you have configured the staging folder, source table, and HBase according to these guidelines.
Staging Folder for HFiles
The Bulk Loader uses an HDFS folder as a staging area for the HFiles before calling HBase APIs to merge them into the Trafodion table.
By default, Trafodion uses /bulkload as the staging folder. This folder must be owned by the same user as the one under which Trafodion runs. Trafodion also must have full permissions on this folder. The HBase user (that is, the user under which HBase runs) must have read/write access to this folder.
Example:
drwxr-xr-x - trafodion trafodion 0 2014-07-07 09:49 /bulkload.
Improving Throughput
The following CQD (Control Query Default) settings help improve the Bulk Loader throughput:
-
TRAF_LOAD_MAX_HFILE_SIZE
Specifies the HFile size limit beyond which the current file is closed and a new file is created for the same partition. Adjust this setting to minimize HBase splitting/merging.
Default: 10GB
-
TRAF_LOAD_PREP_TMP_LOCATION
Specifies the HDFS directory where HFiles are created during load.
Default:
/bulkload
Also, consider using NO DUPLICATE CHECK
to improve througput if your
source data is clean.
Hive Source Table
To load data stored in HDFS, you need to create a Hive table with the right fields and types pointing to the HDFS folder containing the data before you start the load.
HBase Snapshots
If you do not specify the NO RECOVERY OPTION in the LOAD statement, the Bulk Loader uses HBase snapshots as a mechanism for recovery. Snapshots are a lightweight operation where some metadata is copied. (Data is not copied.)
A snapshot is taken before the load starts and is removed after the load completes successfully. If something goes wrong and it is possible to recover, the snapshot is used to restore the table to its initial state before the load started. To use this recovery mechanism, HBase needs to be configured to allow snapshots.
Incremental Loads
The Bulk Loader allows for incremental loads by default. Snapshots are taken before second phase starts and deleted once the bulk load completes.
If something goes wrong with the load, then the snapshot is restored to go to the previous state.
Non-Incremental Loads
These following bulk load options can be used to do non-incremental load:
-
NO RECOVERY
: Do not take a snapshot of the table. -
TRUNCATE TABLE
: Truncates the table before starting the load.
Space Usage
The target table values for SYSKEY, SALT, identity, divisioning columns are created automatically the during transformation step. The size of the HBase files is determined based on encoding, compression, HDFS replication factor, and row format. Target table can be pre-split into regions using salting, a Java Program, by seeding the table with data.
Performance
The overall throughput is influenced by row format, row length, number of columns, skew in data, etc. LOAD sas upsert semantics (duplicate constraint not checked with existing data). LOAD has lower CPU abd disk activity than similar trickle load (INSERT, UPSERT, or UPSERT USING LOAD), Also, LOAD has lower compaction activity after completion than Trickle Load.
Hive Scans
Direct access for Hive table data supports:
-
Only text input format and sequence files.
-
Only structured data types.
Tables must be created/dropped/altered through Hive itself.
Trafodion:
-
Reads Hive metadata to determine information about table.
-
UPDATE STATISTICS can be performed on Hive tables - improves performance!
-
Can write to Hive tables in both Text and Sequence formats (used by UNLOAD).
4.1.3. Examples of LOAD
-
For customer demographics data residing in
/hive/tpcds/customer_demographics
, create an external Hive table using the following Hive SQL:create external table customer_demographics ( cd_demo_sk int , cd_gender string , cd_marital_status string , cd_education_status string , cd_purchase_estimate int , cd_credit_rating string , cd_dep_count int , cd_dep_employed_count int , cd_dep_college_count int ) row format delimited fields terminated by '|' location '/hive/tpcds/customer_demographics';
-
The Trafodion table where you want to load the data is defined using this DDL:
create table customer_demographics_salt ( cd_demo_sk int not null , cd_gender char(1) , cd_marital_status char(1) , cd_education_status char(20) , cd_purchase_estimate int , cd_credit_rating char(10) , cd_dep_count int , cd_dep_employed_count int , cd_dep_college_count int , primary key (cd_demo_sk) ) salt using 4 partitions on (cd_demo_sk);
-
This example shows how the LOAD statement loads the customer_demographics_salt table from the Hive table,
hive.hive.customer_demographics
:>>load into customer_demographics_salt +>select * from hive.hive.customer_demographics where cd_demo_sk <= 5000; Task: LOAD Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT Task: DISABLE INDEX Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT Task: DISABLE INDEX Status: Ended Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT Task: PREPARATION Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT Rows Processed: 5000 Task: PREPARATION Status: Ended ET: 00:00:03.199 Task: COMPLETION Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT Task: COMPLETION Status: Ended ET: 00:00:00.331 Task: POPULATE INDEX Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT Task: POPULATE INDEX Status: Ended ET: 00:00:05.262
4.2. POPULATE INDEX Utility
The POPULATE INDEX utility performs a fast INSERT of data into an index from the parent table. You can execute this utility in a client-based tool like TrafCI.
POPULATE INDEX index ON table [index-option]
index-option is:
ONLINE | OFFLINE
4.2.1. Syntax Description of POPULATE INDEX
-
index
is an SQL identifier that specifies the simple name for the index. You cannot qualify index with its schema name. Indexes have their own name space within a schema, so an index name might be the same as a table or constraint name. However, no two indexes in a schema can have the same name.
-
table
is the name of the table for which to populate the index. See Database Object Names.
-
ONLINE
specifies that the populate operation should be done on-line. That is, ONLINE allows read and write DML access on the base table while the populate operation occurs. Additionally, ONLINE reads the audit trail to replay updates to the base table during the populate phase. If a lot of audit is generated and you perform many CREATE INDEX operations, we recommend that you avoid ONLINE operations because they can add more contention to the audit trail. The default is ONLINE.
-
OFFLINE
specifies that the populate should be done off-line. OFFLINE allows only read DML access to the base table. The base table is unavailable for write operations at this time. OFFLINE must be specified explicitly. SELECT is allowed.
4.2.2. Considerations for POPULATE INDEX
When POPULATE INDEX is executed, the following steps occur:
-
The POPULATE INDEX operation runs in many transactions.
-
The actual data load operation is run outside of a transaction.
If a failure occurs, the rollback is faster because it does not have to process a lot of audit. Also, if a failure occurs, the index remains empty, unaudited, and not attached to the base table (off-line).
-
When an off-line POPULATE INDEX is being executed, the base table is accessible for read DML operations. When an on-line POPULATE INDEX is being executed, the base table is accessible for read and write DML operations during that time period, except during the commit phase at the very end.
-
If the POPULATE INDEX operation fails unexpectedly, you may need to drop the index again and re-create and repopulate.
-
On-line POPULATE INDEX reads the audit trail to replay updates by allowing read/write access. If you plan to create many indexes in parallel or if you have a high level of activity on the audit trail, you should consider using the OFFLINE option.
Errors can occur if the source base table or target index cannot be accessed, or if the load fails due to some resource problem or problem in the file system.
Required Privileges
To perform a POPULATE INDEX operation, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the table.
-
You have the SELECT and INSERT (or ALL) privileges on the associated table.
4.2.3. Examples of POPULATE INDEX
-
This example loads the specified index from the specified table:
POPULATE INDEX myindex ON myschema.mytable;
-
This example loads the specified index from the specified table, which uses the default schema:
POPULATE INDEX index2 ON table2;
4.3. PURGEDATA Utility
The PURGEDATA utility performs a fast DELETE of data from a table and its related indexes. You can execute this utility in a client-based tool like TrafCI.
PURGEDATA object
4.3.1. Syntax Description of PURGEDATA
object
is the name of the table from which to purge the data. See Database Object Names.
4.3.2. Considerations for PURGEDATA
-
The object can be a table name.
-
Errors are returned if table cannot be accessed or if a resource or file-system problem causes the delete to fail.
-
PURGEDATA is not supported for volatile tables.
Required Privileges
To perform a PURGEDATA operation, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the table.
-
You have the SELECT and DELETE (or ALL) privileges on the associated table.
Availability
PURGEDATA marks the table OFFLINE and sets the corrupt bit while processing. If PURGEDATA fails before it completes, the table and its dependent indexes will be unavailable, and you must run PURGEDATA again to complete the operation and remove the data. Error 8551 with an accompanying file system error 59 or error 1071 is returned in this case.
4.3.3. Examples of PURGEDATA
-
This example purges the data in the specified table. If the table has indexes, their data is also purged.
PURGEDATA myschema.mytable;
4.4. UNLOAD Statement
The UNLOAD statement unloads data from Trafodion tables into an HDFS location that you specify. Extracted data can be either compressed or uncompressed based on what you choose.
UNLOAD is a Trafodion SQL extension.
UNLOAD [WITH option[ option]...] INTO 'target-location' SELECT ... FROM source-table ...
option is:
DELIMITER { 'delimiter-string' | delimiter-ascii-value }
| RECORD_SEPARATOR { 'separator-literal' | separator-ascii-value }
| NULL_STRING 'string-literal'
| PURGEDATA FROM TARGET
| COMPRESSION GZIP
| MERGE FILE merged_file-path [OVERWRITE]
| NO OUTPUT
| { NEW | EXISTING } SNAPSHOT HAVING SUFFIX 'string'
4.4.1. Syntax Description of UNLOAD
-
'target-location'
is the full pathname of the target HDFS folder where the extracted data will be written. Enclose the name of folder in single quotes. Specify the folder name as a full pathname and not as a relative path. You must have write permissions on the target HDFS folder. If you run UNLOAD in parallel, multiple files will be produced under the target-location. The number of files created will equal the number of ESPs.
-
SELECT … FROM source-table …
is either a simple query or a complex one that contains GROUP BY, JOIN, or UNION clauses. source-table is the name of a Trafodion table that has the source data. See Database Object Names.
-
[WITH option[ option]…]
is a set of options that you can specify for the unload operation. If you specify an option more than once, Trafodion returns an error with SQLCODE -4489. You can specify one or more of these options:
-
DELIMITER { 'delimiter-string' | delimiter-ascii-value }
specifies the delimiter as either a delimiter string or an ASCII value. If you do not specify this option, Trafodion uses the character "|" as the delimiter.
-
delimiter-string can be any ASCII or Unicode string. You can also specify the delimiter as an ASCII value. Valid values range from 1 to 255. Specify the value in decimal notation; hexadecimal or octal notation are currently not supported. If you are using an ASCII value, the delimiter can be only one character wide. Do not use quotes when specifying an ASCII value for the delimiter.
-
-
RECORD_SEPARATOR { 'separator-literal' | separator-ascii-value }
specifies the character that will be used to separate consecutive records or rows in the output file. You can specify either a literal or an ASCII value for the separator. The default value is a newline character.
-
separator-literal can be any ASCII or Unicode character. You can also specify the separator as an ASCII value. Valid values range from 1 to 255. Specify the value in decimal notation; hexadecimal or octal notation are currently not supported. If you are using an ASCII value, the separator can be only one character wide. Do not use quotes when specifying an ASCII value for the separator.
-
-
NULL_STRING 'string-literal'
specifies the string that will be used to indicate a NULL value. The default value is the empty string ''.
-
PURGEDATA FROM TARGET
causes files in the target HDFS folder to be deleted before the unload operation.
-
COMPRESSION GZIP
uses gzip compression in the extract node, writing the data to disk in this compressed format. GZIP is currently the only supported type of compression. If you do not specify this option, the extracted data will be uncompressed.
-
MERGE FILE merged_file-path [OVERWRITE]
merges the unloaded files into one single file in the specified merged-file-path. If you specify compression, the unloaded data will be in compressed format, and the merged file will also be in compressed format. If you specify the optional OVERWRITE keyword, the file is overwritten if it already exists; otherwise, Trafodion raises an error if the file already exists.
-
NO OUTPUT
prevents the UNLOAD statement from displaying status messages. By default, the UNLOAD statement prints status messages listing the steps that the Bulk Unloader is executing.
-
-
{ NEW | EXISTING } SNAPSHOT HAVING SUFFIX 'string'
initiates an HBase snapshot scan during the unload operation. During a snapshot scan, the Bulk Unloader will get a list of the Trafodion tables from the query explain plan and will create and verify snapshots for the tables. Specify a suffix string, 'string', which will be appended to each table name.
4.4.2. Considerations for UNLOAD
-
You must have write permissions on the target HDFS folder.
-
If a WITH option is specified more than once, Trafodion returns an error with SQLCODE -4489.
Required Privileges
To issue an UNLOAD statement, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the target table.
-
You have the SELECT privilege on the target table.
-
You have the MANAGE_LOAD component privilege for the SQL_OPERATIONS component.
4.4.3. Examples of UNLOAD
-
This example shows how the UNLOAD statement extracts data from a Trafodion table,
TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS
, into an HDFS folder,/bulkload/customer_demographics
:>>UNLOAD +>WITH PURGEDATA FROM TARGET +>MERGE FILE 'merged_customer_demogs.gz' OVERWRITE +>COMPRESSION GZIP +>INTO '/bulkload/customer_demographics' +>select * from trafodion.hbase.customer_demographics +><<+ cardinality 10e10 ,+ cardinality 10e10 >>; Task: UNLOAD Status: Started Task: EMPTY TARGET Status: Started Task: EMPTY TARGET Status: Ended ET: 00:00:00.014 Task: EXTRACT Status: Started Rows Processed: 200000 Task: EXTRACT Status: Ended ET: 00:00:04.743 Task: MERGE FILES Status: Started Task: MERGE FILES Status: Ended ET: 00:00:00.063 --- 200000 row(s) unloaded.
4.5. UPDATE STATISTICS Statement
The UPDATE STATISTICS statement updates the histogram statistics for one or more groups of columns within a table. These statistics are used to devise optimized access plans.
UPDATE STATISTICS is a Trafodion SQL extension.
UPDATE STATISTICS FOR TABLE table [CLEAR | on-clause]
on-clause is:
ON column-group-list CLEAR
| ON column-group-list [histogram-option]...
column-group-list is:
column-list [,column-list]...
| EVERY COLUMN [,column-list]...
| EVERY KEY [,column-list]...
| EXISTING COLUMN[S] [,column-list]...
| NECESSARY COLUMN[S] [,column-list]...
column-list for a single-column group is:
column-name
| (column-name)
| column-name TO column-name
| (column-name) TO (column-name)
| column-name TO (column-name)
| (column-name) TO column-name
column-list for a multicolumn group is:
(column-name, column-name [,column-name]...)
histogram-option is:
GENERATE n INTERVALS
| SAMPLE [sample-option]
sample-option is:
[r ROWS]
| RANDOM percent PERCENT
| PERIODIC size ROWS EVERY period ROWS
4.5.1. Syntax Description of UPDATE STATISTICS
-
table
names the table for which statistics are to be updated. To refer to a table, use the ANSI logical name. See Database Object Names.
-
CLEAR
deletes some or all histograms for the table table. Use this option when new applications no longer use certain histogram statistics.
If you do not specify column-group-list, all histograms for table are deleted. If you specify column-group-list, only columns in the group list are deleted.
-
ON column-group-list
specifies one or more groups of columns for which to generate histogram statistics with the option of clearing the histogram statistics. You must use the ON clause to generate statistics stored in histogram tables.
-
column-list
specifies how column-group-list can be defined. The column list represents both a single-column group and a multi-column group.
-
Single-column group:
-
column-name | (column-name) | column-name TO column-name | (column-name) TO (column-name)
specifies how you can specify individual columns or a group of individual columns.
To generate statistics for individual columns, list each column. You can list each single column name within or without parentheses.
-
-
Multicolumn group:
-
(column-name, column-name [,column-name]…)
specifies a multi-column group.
To generate multi-column statistics, group a set of columns within parentheses, as shown. You cannot specify the name of a column more than once in the same group of columns.
One histogram is generated for each unique column group. Duplicate groups, meaning any permutation of the same group of columns, are ignored and processing continues. When you run UPDATE STATISTICS again for the same user table, the new data for that table replaces the data previously generated and stored in the table’s histogram tables. Histograms of column groups not specified in the ON clause remain unchanged in histogram tables.
For more information about specifying columns, see Generating and Clearing Statistics for Columns.
-
-
-
EVERY COLUMN
The EVERY COLUMN keyword indicates that histogram statistics are to be generated for each individual column of table and any multi-columns that make up the primary key and indexes. For example, table has columns A, B, C, D defined, where A, B, C compose the primary key. In this case, the ON EVERY COLUMN option generates a single column histogram for columns A, B, C, D, and two multi-column histograms of (A, B, C) and (A, B).
The EVERY COLUMN option does what EVERY KEY does, with additional statistics on the individual columns.
-
EVERY KEY
The EVERY KEY keyword indicates that histogram statistics are to be generated for columns that make up the primary key and indexes. For example, table has columns A, B, C, D defined. If the primary key comprises columns A, B, statistics are generated for (A, B), A and B. If the primary key comprises columns A, B, C, statistics are generated for (A,B,C), (A,B), A, B, C. If the primary key comprises columns A, B, C, D, statistics are generated for (A, B, C, D), (A, B, C), (A, B), and A, B, C, D.
-
EXISTING COLUMN[S]
The EXISTING COLUMN keyword indicates that all existing histograms of the table are to be updated. Statistics must be previously captured to establish existing columns.
-
NECESSARY COLUMN[S]
The NECESSARY COLUMN[S] keyword generates statistics for histograms that the optimizer has requested but do not exist. Update statistics automation must be enabled for NECESSARY COLUMN[S] to generate statistics. To enable automation, see Automating Update Statistics.
-
histogram-option
-
GENERATE n INTERVALS
The GENERATE n INTERVALS option for UPDATE STATISTICS accepts values between 1 and 10,000. Keep in mind that increasing the number of intervals per histograms may have a negative impact on compile time.
Increasing the number of intervals can be used for columns with small set of possible values and large variance of the frequency of these values. For example, consider a column ‘CITY’ in table SALES, which stores the city code where the item was sold, where number of cities in the sales data is 1538. Setting the number of intervals to a number greater or equal to the number of cities (that is, setting the number of intervals to 1600) guarantees that the generated histogram captures the number of rows for each city. If the specified value n exceeds the number of unique values in the column, the system generates only as many intervals as the number of unique values.
-
SAMPLE [sample-option]
is a clause that specifies that sampling is to be used to gather a subset of the data from the table. UPDATE STATISTICS stores the sample results and generates histograms.
If you specify the SAMPLE clause without additional options, the result depends on the number of rows in the table. If the table contains no more than 10,000 rows, the entire table will be read (no sampling). If the number of rows is greater than 10,000 but less than 1 million, 10,000 rows are randomly sampled from the table. If there are more than 1 million rows in the table, a random row sample is used to read 1 percent of the rows in the table, with a maximum of 1 million rows sampled.
As a guideline, the default sample of 1 percent of the rows in the table, with a maximum of 1 million rows, provides good statistics for the optimizer to generate good plans. If you do not specify the SAMPLE clause, if the table has fewer rows than specified, or if the sample size is greater than the system limit, Trafodion SQL reads all rows from table. See SAMPLE Clause.
-
sample-option
-
r_ rows
A row sample is used to read r rows from the table. The value r must be an integer that is greater than zero
-
-
-
-
RANDOM percent PERCENT
directs Trafodion SQL to choose rows randomly from the table. The value percent must be a value between zero and 100 (0 < percent <= 100). In addition, only the first four digits to the right of the decimal point are significant. For example, value 0.00001 is considered to be 0.0000, Value 1.23456 is considered to be 1.2345.
-
PERIODIC size ROWS EVERY period ROW
directs Trafodion SQL to choose the first size number of rows from each period of rows. The value size must be an integer that is greater than zero and less than or equal to the value period. (0 < size <= period). The size of the period is defined by the number of rows specified for period. The value period must be an integer that is greater than zero (period > 0).
4.5.2. Considerations for UPDATE STATISTICS
Using Statistics
Use UPDATE STATISTICS to collect and save statistics on columns. The SQL compiler uses histogram statistics to determine the selectivity of predicates, indexes, and tables. Because selectivity directly influences the cost of access plans, regular collection of statistics increases the likelihood that Trafodion SQL chooses efficient access plans.
While UPDATE STATISTICS is running on a table, the table is active and available for query access.
When a user table is changed, either by changing its data significantly or its definition, re-execute the UPDATE STATISTICS statement for the table.
Histogram Statistics
Histogram statistics are used by the compiler to produce the best plan for a given SQL query. When histograms are not available, default assumptions are made by the compiler and the resultant plan might not perform well. Histograms that reflect the latest data in a table are optimal.
The compiler does not need histogram statistics for every column of a table. For example, if a column is only in the select list, its histogram statistics will be irrelevant. A histogram statistic is useful when a column appears in:
-
A predicate
-
A GROUP BY column
-
An ORDER BY clause
-
A HAVING clause
-
Or similar clause
In addition to single-column histogram statistics, the compiler needs multi-column histogram statistics, such as when group by column-5, column-3, column-19 appears in a query. Then, histogram statistics for the combination (column-5, column-3, column-19) are needed.
Required Privileges
To perform an UPDATE STATISTICS operation, one of the following must be true:
-
You are DB ROOT.
-
You are the owner of the target table.
-
You have the MANAGE_STATISTICS component privilege for the SQL_OPERATIONS component.
Locking
UPDATE STATISTICS momentarily locks the definition of the user table during the operation but not the user table itself. The UPDATE STATISTICS statement uses READ UNCOMMITTED isolation level for the user table.
Transactions
Do not start a transaction before executing UPDATE STATISTICS. UPDATE STATISTICS runs multiple transactions of its own, as needed. Starting your own transaction in which UPDATE STATISTICS runs could cause the transaction auto abort time to be exceeded during processing.
Generating and Clearing Statistics for Columns
To generate statistics for particular columns, name each column, or name the first and last columns of a sequence of columns in the table. For example, suppose that a table has consecutive columns CITY, STATE, ZIP. This list gives a few examples of possible options you can specify:
Single-Column Group | Single-Column Group Within Parentheses | Multicolumn Group |
---|---|---|
ON CITY, STATE, ZIP |
ON (CITY),(STATE),(ZIP) |
ON (CITY, STATE) or ON (CITY,STATE,ZIP) |
ON CITY TO ZIP |
ON (CITY) TO (ZIP) |
|
ON ZIP TO CITY |
ON (ZIP) TO (CITY) |
|
ON CITY, STATE TO ZIP |
ON (CITY), (STATE) TO (ZIP) |
|
ON CITY TO STATE, ZIP |
ON (CITY) TO (STATE), (ZIP) |
The TO specification is useful when a table has many columns, and you want histograms on a subset of columns. Do not confuse (CITY) TO (ZIP) with (CITY, STATE, ZIP), which refers to a multi-column histogram.
You can clear statistics in any combination of columns you specify, not necessarily with the column-group-list you used to create statistics. However, those statistics will remain until you clear them.
Column Lists and Access Plans
Generate statistics for columns most often used in data access plans for a table—that is, the primary key, indexes defined on the table, and any other columns frequently referenced in predicates in WHERE or GROUP BY clauses of queries issued on the table. Use the EVERY COLUMN option to generate histograms for every individual column or multi columns that make up the primary key and indexes.
The EVERY KEY option generates histograms that make up the primary key and indexes.
If you often perform a GROUP BY over specific columns in a table, use multi-column lists in the UPDATE STATISTICS statement (consisting of the columns in the GROUP BY clause) to generate histogram statistics that enable the optimizer to choose a better plan. Similarly, when a query joins two tables by two or more columns, multi-column lists (consisting of the columns being joined) help the optimizer choose a better plan.
Automating Update Statistics
To enable update statistics automation, set the Control Query Default (CQD) attribute, USTAT_AUTOMATION_INTERVAL, in a session where you will run update statistics operations. For example:
control query default USTAT_AUTOMATION_INTERVAL '1440';
The value of USTAT_AUTOMATION_INTERVAL is intended to be an automation interval (in minutes), but, in Trafodion Release 1.0, this value does not act as a timing interval. Instead, any value greater than zero enables update statistics automation.
After enabling update statistics automation, prepare each of the queries that you want to optimize. For example:
prepare s from select...;
The PREPARE statement causes the Trafodion SQL compiler to compile and optimize a query without executing it. When preparing queries with update statistic automation enabled, any histograms needed by the optimizer that are not present will cause those columns to be marked as needing histograms.
Next, run this UPDATE STATISTICS statement against each table, using ON NECESSARY COLUMN[S] to generate the needed histograms:
update statistics for table _table-name_ on necessary columns sample;
4.5.3. Examples of UPDATE STATISTICS
-
This example generates four histograms for the columns jobcode, empnum, deptnum, and (empnum, deptnum) for the table EMPLOYEE. Depending on the table’s size and data distribution, each histogram should contain ten intervals.
UPDATE STATISTICS FOR TABLE employee ON (jobcode),(empnum, deptnum) GENERATE 10 INTERVALS; --- SQL operation complete.
-
This example generates histogram statistics using the ON EVERY COLUMN option for the table DEPT. This statement performs a full scan, and Trafodion SQL determines the default number of intervals.
UPDATE STATISTICS FOR TABLE dept ON EVERY COLUMN; --- SQL operation complete.
-
Suppose that a construction company has an ADDRESS table of potential sites and a DEMOLITION_SITES table that contains some of the columns of the ADDRESS table. The primary key is ZIP. Join these two tables on two of the columns in common:
SELECT COUNT(AD.number), AD.street, AD.city, AD.zip, AD.state FROM address AD, demolition_sites DS WHERE AD.zip = DS.zip AND AD.type = DS.type GROUP BY AD.street, AD.city, AD.zip, AD.state;
To generate statistics specific to this query, enter these statements:
UPDATE STATISTICS FOR TABLE address ON (street), (city), (state), (zip, type); UPDATE STATISTICS FOR TABLE demolition_sites ON (zip, type);
-
This example removes all histograms for table DEMOLITION_SITES:
UPDATE STATISTICS FOR TABLE demolition_sites CLEAR;
-
This example selectively removes the histogram for column STREET in table ADDRESS:
UPDATE STATISTICS FOR TABLE address ON street CLEAR;
5. SQL Language Elements
Trafodion SQL language elements, which include data types, expressions, functions, identifiers, literals, and predicates, occur within the syntax of SQL statements. The statement and command topics support the syntactical and semantic descriptions of the language elements in this section.
5.1. Authorization IDs
An authorization ID is used for an authorization operation. Authorization is the process of validating that a database user has permission to perform a specified SQL operation. Externally, the authorization ID is a regular or delimited case-insensitive identifier that can have a maximum of 128 characters. See Case-Insensitive Delimited Identifiers. Internally, the authorization ID is associated with a 32-bit number that the database generates and uses for efficient access and storage.
All authorization IDs share the same name space. An authorization ID can be a database user name or a role name. Therefore, a database user and a role cannot share the same name.
An authorization ID can be the PUBLIC authorization ID, which represents all present and future authorization IDs. An authorization ID cannot be SYSTEM, which is the implicit grantor of privileges to the creator of objects.
5.2. Character Sets
You can specify ISO88591 or UTF8 for a character column definition. The use of UTF8 permits you to store characters from many different languages.
5.3. Columns
A column is a vertical component of a table and is the relational representation of a field in a record. A column contains one data value for each row of the table.
A column value is the smallest unit of data that can be selected from or updated in a table. Each column has a name that is an SQL identifier and is unique within the table or view that contains the column.
5.3.1. Column References
A qualified column name, or column reference, is a column name qualified by the name of the table or view to which the column belongs, or by a correlation name.
If a query refers to columns that have the same name but belong to different tables, you must use a qualified column name to refer to the columns within the query. You must also refer to a column by a qualified column name if you join a table with itself within a query to compare one row of the table with other rows in the same table.
The syntax of a column reference or qualified column name is:
{table-name | view-name | correlation-name}.column-name
If you define a correlation name for a table in the FROM clause of a statement, you must use that correlation name if you need to qualify the column name within the statement.
If you do not define an explicit correlation name in the FROM clause, you can qualify the column name with the name of the table or view that contains the column. See Correlation Names.
5.3.2. Derived Column Names
A derived column is an SQL value expression that appears as an item in the select list of a SELECT statement. An explicit name for a derived column is an SQL identifier associated with the derived column. The syntax of a derived column name is:
column-expression [[AS] column-name]
The column expression can simply be a column reference. The expression is optionally followed by the AS keyword and the name of the derived column.
If you do not assign a name to derived columns, the headings for unnamed columns in query result tables appear as (EXPR). Use the AS clause to assign names that are meaningful to you, which is important if you have more than one derived column in your select list.
Examples of Derived Column Names
These two examples show how to use names for derived columns.
-
The first example shows (EXPR) as the column heading of the SELECT result table:
SELECT AVG (salary) FROM persnl.employee; (EXPR) ---------------- 49441.52 --- 1 row(s) selected.
-
The second example shows AVERAGE SALARY as the column heading:
SELECT AVG (salary) AS "AVERAGE SALARY" FROM persnl.employee; "AVERAGE SALARY" ---------------- 49441.52 --- 1 row(s) selected.
5.3.3. Column Default Settings
You can define specific default settings for columns when the table is created. The CREATE TABLE statement defines the default settings for columns within tables. The default setting for a column is the value inserted in a row when an INSERT statement omits a value for a particular column.
5.4. Constraints
An SQL constraint is an object that protects the integrity of data in a table by specifying a condition that all the values in a particular column or set of columns of the table must satisfy.
Trafodion SQL enforces these constraints on SQL tables:
CHECK |
Column or table constraint specifying a condition must be satisfied for each row in the table. |
FOREIGN KEY |
Column or table constraint that specifies a referential constraint for the table, declaring that a column or set of columns (called a foreign key) in a table can contain only values that match those in a column or set of columns in the table specified in the REFERENCES clause. |
NOT NULL |
Column constraint specifying the column cannot contain nulls. |
PRIMARY KEY |
Column or table constraint specifying the column or set of columns as the primary key for the table. |
UNIQUE |
Column or table constraint that specifies that the column or set of columns cannot contain more than one occurrence of the same value or set of values. |
5.4.1. Creating or Adding Constraints on SQL Tables
To create constraints on an SQL table when you create the table, use the NOT NULL, UNIQUE, CHECK, FOREIGN KEY, or PRIMARY KEY clause of the CREATE TABLE statement.
For more information on Trafodion SQL commands, see CREATE TABLE Statement and ALTER TABLE Statement.
5.4.2. Constraint Names
When you create a constraint, you can specify a name for it or allow a name to be generated by Trafodion SQL. You can optionally specify both column and table constraint names. Constraint names are ANSI logical names. See Database Object Names. Constraint names are in the same name space as tables and views, so a constraint name cannot have the same name s a table or view.
The name you specify can be fully qualified or not. If you specify the schema parts of the name, they must match those parts of the affected table and must be unique among table, view, and constraint names in that schema. If you omit the schema portion of the name you specify, Trafodion SQL expands the name by using the schema for the table.
If you do not specify a constraint name, Trafodion SQL constructs an SQL identifier as the name for the constraint and qualifies it with the schema of the table. The identifier consists of the table name concatenated with a system-generated unique identifier.
5.5. Correlation Names
A correlation name is a name you can associate with a table reference that is a table, view, or subquery in a SELECT statement to:
-
Distinguish a table or view from another table or view referred to in a statement
-
Distinguish different uses of the same table
-
Make the query shorter
A correlation name can be explicit or implicit.
5.5.1. Explicit Correlation Names
An explicit correlation name for a table reference is an SQL identifier associated with the table reference in the FROM clause of a SELECT statement. See Identifiers. The correlation name must be unique within the FROM clause. For more information about the FROM clause, table references, and correlation names, see SELECT Statement.
The syntax of a correlation name for the different forms of a table reference within a FROM clause is the same:
{table | view | (query-expression)} [AS]correlation-name
A table or view is optionally followed by the AS keyword and the correlation name. A derived table, resulting from the evaluation of a query expression, must be followed by the AS keyword and the correlation name. An explicit correlation name is known only to the statement in which you define it. You can use the same identifier as a correlation name in another statement.
5.5.2. Implicit Correlation Names
A table or view reference that has no explicit correlation name has an implicit correlation name. The implicit correlation name is the table or view name qualified with the schema names.
You cannot use an implicit correlation name for a reference that has an explicit correlation name within the statement.
5.5.3. Examples of Correlation Names
This query refers to two tables, ORDERS and CUSTOMER, that contain columns named CUSTNUM. In the WHERE clause, one column reference is qualified by an implicit correlation name (ORDERS) and the other by an explicit correlation name ©:
SELECT ordernum, custname FROM orders, customer c
WHERE orders.custnum = c.custnum AND orders.custnum = 543;
5.6. Database Objects
A database object is an SQL entity that exists in a name space. SQL statements can access Trafodion SQL database objects. The subsections listed below describe these Trafodion SQL database objects.
5.6.1. Ownership
In Trafodion SQL, the creator of an object owns the object defined in the schema and has all privileges on the object. In addition, you can use the GRANT and REVOKE statements to grant access privileges for a table or view to specified users.
For more information, see the GRANT Statement and REVOKE Statement. For information on privileges on tables and views, see CREATE TABLE Statement and CREATE VIEW Statement.
5.7. Database Object Names
DML statements can refer to Trafodion SQL database objects. To refer to a database object in a statement, use an appropriate database object name. For information on the types of database objects see Database Objects.
5.7.1. Logical Names for SQL Objects
You may refer to an SQL table, view, constraint, library, function, or procedure by using a one-part, two-part, or three-part logical name, also called an ANSI name:
catalog-name.schema-name.object-name
In this three-part name, catalog-name is the name of the catalog, which is TRAFODION for Trafodion SQL objects that map to HBase tables. schema-name is the name of the schema, and object-name is the simple name of the table, view, constraint, library, function, or procedure. Each of the parts is an SQL identifier. See Identifiers.
Trafodion SQL automatically qualifies an object name with a schema name unless you explicitly specify schema names with the object name. If you do not set a schema name for the session using a SET SCHEMA statement, the default schema is SEABASE, which exists in the TRAFODION catalog. See SET SCHEMA Statement. A one-part name object-name is qualified implicitly with the default schema.
You can qualify a column name in a Trafodion SQL statement by using a three-part, two-part, or one-part object name, or a correlation name.
5.7.2. SQL Object Namespaces
Trafodion SQL objects are organized in a hierarchical manner. Database objects exist in schemas, which are themselves contained in a catalog called TRAFODION. A catalog is a collection of schemas. Schema names must be unique within the catalog.
Multiple objects with the same name can exist provided that each belongs to a different name space. Trafodion SQL supports these namespaces:
-
Index
-
Functions and procedures
-
Library
-
Schema label
-
Table value object (table, view, constraint)
Objects in one schema can refer to objects in a different schema. Objects of a given name space are required to have unique names within a given schema.
5.8. Data Types
Trafodion SQL data types are character, datetime, interval, or numeric (exact or approximate):
Fixed-length and variable-length character data types. |
|
DATE, TIME, and TIMESTAMP data types. |
|
Year-month intervals (years and months) and day-time intervals (days, hours, minutes, seconds, and fractions of a second). |
|
Exact and approximate numeric data types. |
Each column in a table is associated with a data type. You can use the CAST expression to convert data to the data type that you specify. For more information, see CAST Expression.
The following table summarizes the Trafodion SQL data types:
Type | SQL Designation | Description | Size or Range1 |
---|---|---|---|
Fixed-length character |
CHAR[ACTER] |
Fixed-length character data |
1 to 32707 characters2 |
NCHAR |
Fixed-length character data in predefined national character set |
1 to 32707 bytes3 7 |
|
NATIONAL CHAR[ACTER] |
Fixed-length character data in predefined national character set |
1 to 32707 bytes3 7 |
|
Variable-length character |
VARCHAR |
Variable-length ASCII character string |
1 to 32703 characters4 |
CHAR[ACTER] VARYING |
Variable-length ASCII character string |
1 to 32703 characters4 |
|
NCHAR VARYING |
Variable-length ASCII character string |
1 to 32703 bytes4 8 |
|
NATIONAL CHAR[ACTER] VARYING |
Variable-length ASCII character string |
1 to 32703 characters4 8 |
|
Numeric |
NUMERIC (1,scale) to |
Binary number with optional scale; signed or unsigned for 1 to 9 digits |
1 to 128 digits; stored: |
SMALLINT |
Binary integer; signed or unsigned |
0 to 65535 unsigned, -32768 to +32767 signed; stored in 2 bytes |
|
INTEGER |
Binary integer; signed or unsigned |
0 to 4294967295 unsigned, -2147483648 to +2147483647 signed; stored in 4 bytes |
|
LARGEINT |
Binary integer; signed only |
-263 to +(263)-1; stored in 8 bytes |
|
Numeric (extended numeric precision) |
NUMERIC (precision 19 to 128) |
Binary integer; signed or unsigned |
Stored as multiple chunks of 16-bit integers, with a minimum storage length of 8 bytes. |
Floating point number |
FLOAT[(precision)] |
Floating point number; precision designates from 1 through 52 bits of precision |
+/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308; stored in 8 bytes |
REAL |
Floating point number (32 bits) |
+/- 1.17549435e-38 through +/ 3.40282347e+38; stored in 4 bytes |
|
DOUBLE PRECISION |
Floating-point numbers (64 bits) with 1 through 52 bits of precision (52 bits of binary precision and 1 bits of exponent) |
+/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308; stored in 8 byte |
|
Decimal number |
DECIMAL (1,scale) to DECIMAL (18,scale) |
Decimal number with optional scale; stored as ASCII characters; signed or unsigned for 1 to 9 digits; signed required for 10 or more digits |
1 to 18 digits. Byte length equals the number of digits. Sign is stored as the first bit of the leftmost byte. |
Date-Time |
Point in time, using the Gregorian calendar and a 24 hour clock system. The five supported designations are listed below. |
YEAR 0001-9999 |
|
DATE |
Date |
Format as YYYY-MM-DD; actual database storage size is 4 bytes |
|
TIME |
Time of day, 24 hour clock, no time precision. Format as HH:MM:SS; actual database storage size is 3 bytes |
||
TIME (with time precision) |
Time of day, 24 hour clock, with time precision |
Format as HH:MM:SS.FFFFFF; actual database storage size is 7 bytes |
|
TIMESTAMP |
Point in time, no time precision |
Format as YYYY-MM-DD HH:MM:SS; actual database storage size is 7 bytes |
|
TIMESTAMP (with time precision) Point in time, with time precision |
Format as YYYY-MM-DD HH:MM:SS.FFFFFF; actual database storage size is 1 byte |
Interval |
INTERVAL |
-
scale is the number of digits to the right of the decimal.
-
precision specifies the allowed number of decimal digits.
-
The size of a column that allows null values is 2 bytes larger than the size for the defined data type.
-
The maximum row size is 32708 bytes, but the actual row size is less than that because of bytes used by null indicators, varchar column length indicators, and actual data encoding.
-
Storage size is the same as that required by CHAR data type but store only half as many characters depending on character set selection.
-
Storage size is reduced by 4 bytes for storage of the varying character length.
-
The maximum number of digits in an INTERVAL value is 18, including the digits in all INTERVAL fields of the value. Any INTERVAL field that is a starting field can have up to 18 digits minus the number of other digits in the INTERVAL value.
-
The maximum is 32707 if the national character set was specified at installation time to be ISO88591. The maximum is 16353 if the national character set was specified at installation time as UTF8.
-
The maximum is 32703 if the national character set was specified at installation time to be ISO88591. The maximum is 16351 if the national character set was specified at installation time as UTF8.
-
5.8.1. Comparable and Compatible Data Types
Two data types are comparable if a value of one data type can be compared to a value of the other data type.
Two data types are compatible if a value of one data type can be assigned to a column of the other data type, and if columns of the two data types can be combined using arithmetic operations. Compatible data types are also comparable.
Assignment and comparison are the basic operations of Trafodion SQL. Assignment operations are performed during the execution of INSERT and UPDATE statements. Comparison operations are performed during the execution of statements that include predicates, aggregate (or set) functions, and GROUP BY, HAVING, and ORDER BY clauses.
The basic rule for both assignment and comparison is that the operands have compatible data types. Data types with different character sets cannot be compared without converting one character set to the other. However, the SQL compiler will usually generate the necessary code to do this conversion automatically.
Character Data Types
Values of fixed and variable length character data types of the same character set are all character strings and are all mutually comparable and mutually assignable.
When two strings are compared, the comparison is made with a temporary copy of the shorter string that has been padded on the right with blanks to have the same length as the longer string.
Datetime Data Types
Values of type datetime are mutually comparable and mutually assignable only if the types have the same datetime fields. A DATE, TIME, or TIMESTAMP value can be compared with another value only if the other value has the same data type.
All comparisons are chronological. For example, this predicate is true:
TIMESTAMP '2008-09-28 00:00:00' > TIMESTAMP '2008-06-26 00:00:00'
Interval Data Types
Values of type INTERVAL are mutually comparable and mutually assignable only if the types are either both year-month intervals or both day-time intervals.
For example, this predicate is true:
INTERVAL '02-01' YEAR TO MONTH > INTERVAL '00-01' YEAR TO MONTH
The field components of the INTERVAL do not have to be the same. For example, this predicate is also true:
INTERVAL '02-01' YEAR TO MONTH > INTERVAL '01' YEAR
Numeric Data Types
Values of the approximate data types FLOAT, REAL, and DOUBLE PRECISION, and values of the exact data types NUMERIC, DECIMAL, INTEGER, SMALLINT, and LARGEINT, are all numbers and are all mutually comparable and mutually assignable.
When an approximate data type value is assigned to a column with exact data type, rounding might occur, and the fractional part might be truncated. When an exact data type value is assigned to a column with approximate data type, the result might not be identical to the original number.
When two numbers are compared, the comparison is made with a temporary copy of one of the numbers, according to defined rules of conversion. For example, if one number is INTEGER and the other is DECIMAL, the comparison is made with a temporary copy of the integer converted to a decimal.
Extended Numeric Precision
Trafodion SQL provides support for extended numeric precision data type. Extended numeric precision is an extension to the NUMERIC(x,y) data type where no theoretical limit exists on precision. It is a software data type, which means that the underlying hardware does not support it and all computations are performed by software. Computations using this data type may not match the performance of other hardware supported data types.
Considerations for Extended NUMERIC Precision Data Type
Consider these points and limitations for extended NUMERIC precision data type:
-
May cost more than other data type options.
-
Is a software data type.
-
Cannot be compared to data types that are supported by hardware.
-
If your application requires extended NUMERIC precision arithmetic expressions, specify the required precision in the table DDL or as explicit extended precision type casts of your select list items. The default system behavior is to treat user-specified extended precision expressions as extended precision values. Conversely, non-user-specified (that is, temporary, intermediate) extended precision expressions may lose precision. In the following example, the precision appears to lose one digit because the system treats the sum of two NUMERIC(18,4) type columns as NUMERIC(18,4). NUMERIC(18) is the longest non-extended precision numeric type. NUMERIC(19) is the shortest extended precision numeric type. The system actually computes the sum of 2 NUMERIC(18,4) columns as an extended precision NUMERIC(19,4) sum. But because no user-specified extended precision columns exist, the system casts the sum back to the user-specified type of NUMERIC(18,4).
CREATE TABLE T(a NUMERIC(18,4), B NUMERIC(18,4)); INSERT INTO T VALUES (1.1234, 2.1234); >> SELECT A+B FROM T; (EXPR) -------------- 3.246
If this behavior is not acceptable, you can use one of these options:
-
Specify the column type as NUMERIC(19,4). For example, CREATE TABLE T(A NUMERIC(19,4), B NUMERIC(19,4)); or
-
Cast the sum as NUMERIC(19,4). For example, SELECT CAST(A+B AS NUMERIC(19,4)) FROM T; or
-
Use an extended precision literal in the expression. For example, SELECT A+B*1.00000000000000000000 FROM T;.
Note the result for the previous example when changing to NUMERIC(19,4):
SELECT CAST(A+B AS NUMERIC(19,4)) FROM T; (EXPR) ------------ 3.2468
When displaying output results in the command interface of a client-based tool, casting a select list item to an extended precision numeric type is acceptable. However, when retrieving an extended precision select list item into an application program’s host variable, you must first convert the extended precision numeric type into a string data type. For example:
SELECT CAST(CAST(A+B AS NUMERIC(19,4)) AS CHAR(24)) FROM T; (EXPR) ------------ 3.2468
An application program can convert an externalized extended precision value in string form into a numeric value it can handle. But, an application program cannot correctly interpret an extended precision value in internal form.
-
Rules for Extended NUMERIC Precision Data Type
These rules apply:
-
No limit on maximum precision.
-
Supported in all DDL and DML statements where regular NUMERIC data type is supported.
-
Allowed as part of key columns for hash partitioned tables only.
-
NUMERIC type with precision 10 through 18.
-
UNSIGNED is supported as extended NUMERIC precision data type
-
SIGNED is supported as 64-bit integer
-
-
CAST function allows conversion between regular NUMERIC and extended NUMERIC precision data type.
-
Parameters in SQL queries support extended NUMERIC precision data type.
Example of Extended NUMERIC Precision Data Type
>>CREATE TABLE t( n NUMERIC(128,30));
--- SQL operation complete.
>>SHOWDDL TABLE t;
CREATE TABLE SCH.T
(
N NUMERIC(128, 30) DEFAULT NULL
)
;
--- SQL operation complete.
>>
5.8.2. Character String Data Types
Trafodion SQL includes both fixed-length character data and variable-length character data. You cannot compare character data to numeric, datetime, or interval data.
-
character-type
is:CHAR[ACTER] [(_length_ [CHARACTERS])] [_char-set_] [UPSHIFT] [[NOT]CASESPECIFIC] | CHAR[ACTER] VARYING(_length_) [CHARACTERS][_char-set_] [UPSHIFT] [[NOT]CASESPECIFIC] | VARCHAR(_length_) [CHARACTERS] [_char-set_] [UPSHIFT] [[NOT]CASESPECIFIC] | NCHAR [(_length_)] [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC] | NCHAR VARYING (_length_) [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC] | NATIONAL CHAR[ACTER] [(_length_)] [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC] | NATIONAL CHAR[ACTER] VARYING (_length_) [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC]
-
char-set
isCHARACTER SET char-set-name
CHAR, NCHAR, and NATIONAL CHAR are fixed-length character types. CHAR VARYING, VARCHAR, NCHAR VARYING and NATIONAL CHAR VARYING are varying-length character types.
-
length
is a positive integer that specifies the number of characters allowed in the column. You must specify a value for length.
-
char-set-name
is the character set name, which can be ISO88591 or UTF8.
-
CHAR[ACTER] [(length [CHARACTERS])] [char-set] [UPSHIFT] [[NOT]CASESPECIFIC]
specifies a column with fixed-length character data.
-
CHAR[ACTER] VARYING (length) [CHARACTERS] [char-set] [UPSHIFT] [[NOT]CASESPECIFIC]
specifies a column with varying-length character data. VARYING specifies that the number of characters stored in the column can be fewer than the length.
Values in a column declared as VARYING can be logically and physically shorter than the maximum length, but the maximum internal size of a VARYING column is actually four bytes larger than the size required for an equivalent column that is not VARYING.
-
VARCHAR (length) [char-set] [UPSHIFT] [[NOT]CASESPECIFIC]
specifies a column with varying-length character data. VARCHAR is equivalent to data type CHAR[ACTER] VARYING.
-
NCHAR [(length)] [UPSHIFT] [[NOT]CASESPECIFIC], NATIONAL CHAR[ACTER] [(length)] [UPSHIFT] [[NOT]CASESPECIFIC]
specifies a column with data in the predefined national character set.
-
NCHAR VARYING [(length)] [UPSHIFT] [[NOT]CASESPECIFIC], NATIONAL CHAR[ACTER] VARYING (length) [UPSHIFT] [[NOT]CASESPECIFIC]
specifies a column with varying-length data in the predefined national character set.
Considerations for Character String Data Types
Difference Between CHAR and VARCHAR
You can specify a fixed-length character column as CHAR(n), where n is the number of characters you want to store. However, if you store five characters into a column specified as CHAR(10), ten characters are stored where the rightmost five characters are blank.
If you do not want to have blanks added to your character string, you can specify a variable-length character column as VARCHAR(n), where n is the maximum number of characters you want to store. If you store five characters in a column specified as VARCHAR(10), only the five characters are stored logically—without blank padding.
NCHAR Columns in SQL Tables
In Trafodion SQL, the NCHAR type specification is equivalent to:
-
NATIONAL CHARACTER
-
NATIONAL CHAR
-
CHAR … CHARACTER SET …, where the character set is the character set for NCHAR
Similarly, you can use NCHAR VARYING, NATIONAL CHARACTER VARYING, NATIONAL CHAR VARYING, and VARCHAR … CHARACTER SET … , where the character set is the character set for NCHAR. The character set for NCHAR is determined when Trafodion SQL is installed.
5.8.3. Datetime Data Types
A value of datetime data type represents a point in time according to the Gregorian calendar and a 24-hour clock in local civil time (LCT). A datetime item can represent a date, a time, or a date and time.
When a numeric value is added to or subtracted from a date type, the numeric value is automatically casted to an INTERVAL DAY value. When a numeric value is added to or subtracted from a time type or a timestamp type, the numeric value is automatically casted to an INTERVAL SECOND value. For information on CAST, see CAST Expression.
Trafodion SQL accepts dates, such as October 5 to 14, 1582, that were omitted from the Gregorian calendar. This functionality is a Trafodion SQL extension.
The range of times that a datetime value can represent is:
January 1, 1 A.D., 00:00:00.000000 (low value) December 31, 9999, 23:59:59.999999 (high value)
Trafodion SQL has three datetime data types:
-
datetime-type
is:DATE | TIME [(_time-precision_)] | TIMESTAMP [(_timestamp-precision_)]
-
DATE
specifies a datetime column that contains a date in the external form yyyy-mm-dd and stored in four bytes.
-
TIME [(time-precision)]
specifies a datetime column that, without the optional time-precision, contains a time in the external form hh:mm:ss and is stored in three bytes. time-precision is an unsigned integer that specifies the number of digits in the fractional seconds and is stored in four bytes. The default for time-precision is 0, and the maximum is 6.
-
TIMESTAMP [(timestamp-precision)]
specifies a datetime column that, without the optional timestamp-precision, contains a timestamp in the external form yyyy-mm-dd hh:mm:ss and is stored in seven bytes. timestamp-precision is an unsigned integer that specifies the number of digits in the fractional seconds and is stored in four bytes. The default for timestamp-precision is 6, and the maximum is 6.
Considerations for Datetime Data Types
Datetime Ranges
The range of values for the individual fields in a DATE, TIME, or TIMESTAMP column is specified as:
yyyy |
Year, from 0001 to 9999 |
mm |
Month, from 01 to 12 |
dd |
Day, from 01 to 31 |
hh |
Hour, from 00 to 23 |
mm |
Minute, from 00 to 59 |
ss |
Second, from 00 to 59 |
msssss |
Microsecond, from 000000 to 999999 |
When you specify datetime_value (FORMAT ‘string’) in the DML statement and the specified format is ‘mm/dd/yyyy’,’MM/DD/YYYY’, or ‘yyyy/mm/dd’ or ‘yyyy-mm-dd’, the datetime type is automatically cast.
5.8.4. Interval Data Types
Values of interval data type represent durations of time in year-month units (years and months) or in day-time units (days, hours, minutes, seconds, and fractions of a second).
-
interval-type is:
INTERVAL[-] { start-field TO end-field | single-field }
-
start-field is:
{YEAR | MONTH | DAY | HOUR | MINUTE} [(_leading-precision_)]
-
`end-field is:
YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(_fractional-precision_)]
-
single-field is:
_start-field_ | SECOND [(_leading-precision_, _fractional-precision_)]
-
INTERVAL[-] { start-field TO end-field | single-field }
specifies a column that represents a duration of time as a year-month or day-time range or a single-field. The optional sign indicates if this is a positive or negative integer. If you omit the sign, it defaults to positive.
If the interval is specified as a range, the start-field and end-field must be in one of these categories:
-
{YEAR | MONTH | DAY | HOUR | MINUTE} [(leading-precision)]
specifies the start-field. A start-field can have a leading-precision up to 18 digits (the maximum depends on the number of fields in the interval). The leading-precision is the number of digits allowed in the start-field. The default for leading-precision is 2.
-
YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(fractional-precision)]
specifies the end-field. If the end-field is SECOND, it can have a fractional-precision up to 6 digits. The fractional-precision is the number of digits of precision after the decimal point. The default for fractional-precision is 6.
-
start-field | SECOND [(leading-precision, fractional-precision)]
specifies the single-field. If the single-field is SECOND, the leading-precision is the number of digits of precision before the decimal point, and the fractional-precision is the number of digits of precision after the decimal point. The default for leading-precision is 2, and the default for fractional-precision is 6. The maximum for leading-precision is 18, and the maximum for fractional-precision is 6.
Considerations for Interval Data Types
Adding or Subtracting Imprecise Interval Values
Adding or subtracting an interval that is any multiple of a MONTH, a YEAR, or a combination of these may result in a runtime error. For example, adding 1 MONTH to January 31, 2009 will result in an error because February 31 does not exist and it is not clear whether the user would want rounding back to February 28, 2009, rounding up to March 1, 2009 or perhaps treating the interval 1 MONTH as if it were 30 days resulting in an answer of March 2, 2009. Similarly, subtracting 1 YEAR from February 29, 2008 will result in an error. See the descriptions for the ADD_MONTHS Function, DATE_ADD Function, DATE_SUB Function , and DATEADD Function for ways to add or subtract such intervals without getting errors at runtime.
Interval Leading Precision
The maximum for the leading-precision depends on the number of fields in the interval and on the fractional-precision. The maximum is computed as:
[[18 - _fractional-precision_ - 2 * (_n_ - 1)]]
_max-leading-precision_ = 18 - _fractional-precision_ - 2 * (_N_ - 1)
where N is the number of fields in the interval.
For example, the maximum number of digits for the leading-precision in a column with data type INTERVAL YEAR TO MONTH is computed as: 18 – 0 – 2 * (2 – 1) = 16
Interval Ranges
Within the definition of an interval range (other than a single field), the start-field and end-field can be any of the specified fields with these restrictions:
-
An interval range is either year-month or day-time—that is, if the start-field is YEAR, the end-field is MONTH; if the start-field is DAY, HOUR, or MINUTE, the end-field is also a time field.
-
The start-field must precede the end-field within the hierarchy: YEAR, MONTH, DAY, HOUR, MINUTE, and SECOND.
Signed Intervals
To include a quoted string in a signed interval data type, the sign must be outside the quoted string. It can be before the entire literal or immediately before the duration enclosed in quotes.
For example, for the interval “minus (5 years 5 months) these formats are valid:
INTERVAL - '05-05'YEAR TO MONTH
- INTERVAL '05-05' YEAR TO MONTH
Overflow Conditions
When you insert a fractional value into an INTERVAL data type field, if the fractional value is 0 (zero) it does not cause an overflow. Inserting value INTERVAL '1.000000' SECOND(6) into a field SECOND(0) does not cause a loss of value. Provided that the value fits in the target column without a loss of precision, Trafodion SQL does not return an overflow error.
However, if the fractional value is > 0, an overflow occurs. Inserting value INTERVAL '1.000001' SECOND(6) causes a loss of value.
5.8.5. Numeric Data Types
Numeric data types are either exact or approximate. A numeric data type is compatible with any other numeric data type, but not with character, datetime, or interval data types.
-
exact-numeric-type
is:NUMERIC [(_precision_ [,_scale_])] [SIGNED|UNSIGNED] | SMALLINT [SIGNED|UNSIGNED] | INT[EGER] [SIGNED|UNSIGNED] | LARGEINT | DEC[IMAL] [(_precision_ [,_scale_])] [SIGNED|UNSIGNED]
-
approximate-numeric-type
is:FLOAT [(_precision_)] | REAL | DOUBLE PRECISION
Exact numeric data types are types that can represent a value exactly: NUMERIC, SMALLINT, INTEGER, LARGEINT, and DECIMAL.
Approximate numeric data types are types that do not necessarily represent a value exactly: FLOAT, REAL, and DOUBLE PRECISION.
A column in a Trafodion SQL table declared with a floating-point data type is stored in IEEE floating-point format and all computations on it are done assuming that. Trafodion SQL tables can contain only IEEE floating-point data.
-
NUMERIC [(precision [,scale])] [SIGNED|UNSIGNED]
specifies an exact numeric column—a two-byte binary number, SIGNED or UNSIGNED. precision specifies the total number of digits and cannot exceed 128. If precision is between 10 and 18, you must use a signed value to obtain the supported hardware data type. If precision is over 18, you will receive the supported software data type. You will also receive the supported software data type if the precision type is between 10 and 18, and you specify UNSIGNED. scale specifies the number of digits to the right of the decimal point.
The default is NUMERIC (9,0) SIGNED.
-
SMALLINT [SIGNED|UNSIGNED]
specifies an exact numeric column—a two-byte binary integer, SIGNED or UNSIGNED. The column stores integers in the range unsigned 0 to 65535 or signed -32768 to +32767. The default is SIGNED.
-
INT[EGER] [SIGNED|UNSIGNED]
specifies an exact numeric column—a 4-byte binary integer, SIGNED or UNSIGNED. The column stores integers in the range unsigned 0 to 4294967295 or signed -2147483648 to +2147483647.
The default is SIGNED.
-
LARGEINT
specifies an exact numeric column—an 8-byte signed binary integer. The column stores integers in the range -263 to +263 -1 (approximately 9.223 times 10 to the eighteenth power).
-
DEC[IMAL] [(precision [,scale])] [SIGNED|UNSIGNED]
specifies an exact numeric column—a decimal number, SIGNED or UNSIGNED,stored as ASCII characters. precision specifies the total number of digits and cannot exceed 18. If precision is 10 or more, the value must be SIGNED. The sign is stored as the first bit of the leftmost byte. scale specifies the number of digits to the right of the decimal point.
The default is DECIMAL (9,0) SIGNED.
-
FLOAT [( precision )]
specifies an approximate numeric column. The column stores floating-point numbers and designates from 1 through 54 bits of precision. The range is from +/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308 stored in 8 bytes.
An IEEE FLOAT precision data type is stored as an IEEE DOUBLE, that is, in 8 bytes, with the specified precision.
The default precision is 54.
-
REAL
specifies a 4-byte approximate numeric column. The column stores 32-bit floating-point numbers with 23 bits of binary precision and 8 bits of exponent.
The minimum and maximum range is from +/- 1.17549435e-38 through +/ 3.40282347e+38.
-
DOUBLE PRECISION
specifies an 8-byte approximate numeric column.
The column stores 64-bit floating-point numbers and designates from 1 through 52 bits of precision.
An IEEE DOUBLE PRECISION data type is stored in 8 bytes with 52 bits of binary precision and 1 bits of exponent. The minimum and maximum range is from +/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308.
5.9. Expressions
An SQL value expression, called an expression, evaluates to a value. Trafodion SQL supports these types of expressions:
Operands can be combined with the concatenation operator (||). |
|
Operands can be combined in specific ways with arithmetic operators. |
|
Operands can be combined in specific ways with addition and subtraction operators. |
|
Operands can be combined in specific ways with arithmetic operators. |
The data type of an expression is the data type of the value of the expression.
A value expression can be a character string literal, a numeric literal, a dynamic parameter, or a column name that specifies the value of the column in a row of a table. A value expression can also include functions and scalar subqueries.
5.9.1. Character Value Expressions
The operands of a character value expression—called character primaries—can be combined with the concatenation operator (||). The data type of a character primary is character string.
-
character-expression
is:character-primary | character-expression || character-primary
-
character-primary
is:character-string-literal | column-reference | character-type-host-variable | dynamic parameter | character-value-function | aggregate-function | sequence-function | scalar-subquery | CASE-expression | CAST-expression | (character-expression)
Character (or string) value expressions are built from operands that can be:
-
Character string literals
-
Character string functions
-
Column references with character values
-
Dynamic parameters
-
Aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return character values
Examples of Character Value Expressions
These are examples of character value expressions:
Expression | Description |
---|---|
'ABILENE' |
Character string literal. |
'ABILENE ' ||' TEXAS' |
The concatenation of two string literals. |
'ABILENE ' ||' TEXAS ' || x’55 53 41' |
The concatenation of three string literals to form the literal: 'ABILENE TEXAS USA' |
'Customer ' || custname |
The concatenation of a string literal with the value in column CUSTNAME. |
CAST (order_date AS CHAR(10)) |
CAST function applied to a DATE value. |
5.9.2. Datetime Value Expressions
The operands of a datetime value expression can be combined in specific ways with arithmetic operators.
In this syntax diagram, the data type of a datetime primary is DATE, TIME, or TIMESTAMP. The data type of an interval term is INTERVAL.
-
datetime-expression
is:datetime-primary | interval-expression + datetime-primary | datetime-expression + interval-term | datetime-expression - interval-term
-
datetime-primary
is:datetime-literal | column-reference | datetime-type-host-variable | dynamic parameter | datetime-value-function | aggregate-function | sequence-function | scalar-subquery | CASE-expression | CAST-expression | (datetime-expression)
-
interval-term
is:interval-factor | numeric-term * interval-factor
-
interval-factor
is:[+|-] interval-primary
-
interval-primary
is:interval-literal | column-reference | interval-type-host-variable | dynamic parameter | aggregate-function | sequence-function | scalar-subquery | CASE-expression | CAST-expression | (interval-expression)
Datetime value expressions are built from operands that can be:
-
Interval value expressions
-
Datetime or interval literals
-
Dynamic parameters
-
Column references with datetime or interval values
-
Dynamic parameters
-
Datetime or interval value functions
-
Any aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return datetime or interval values
Considerations for Datetime Value Expressions
Data Type of Result
In general, the data type of the result is the data type of the datetime-primary part of the datetime expression. For example, datetime value expressions include:
Datetime Expression | Description | Result Data Type |
---|---|---|
CURRENT_DATE + INTERVAL '1' DAY |
The sum of the current date and an interval value of one day. |
DATE |
CURRENT_DATE + est_complete |
The sum of the current date and the interval value in column EST_COMPLETE. |
DATE |
( SELECT ship_timestamp FROM project WHERE projcode=1000) + INTERVAL '07:04' DAY TO HOUR |
The sum of the ship timestamp for the specified project and an interval value of seven days, four hours. |
TIMESTAMP |
The datetime primary in the first expression is CURRENT_DATE, a function that returns a value with DATE data type. Therefore, the data type of the result is DATE.
In the last expression, the datetime primary is this scalar subquery:
( SELECT ship_timestamp FROM project WHERE projcode=1000 )
The preceding subquery returns a value with TIMESTAMP data type. Therefore, the data type of the result is TIMESTAMP.
Restrictions on Operations With Datetime or Interval Operands
You can use datetime and interval operands with arithmetic operators in a datetime value expression only in these combinations:
Operand 1 | Operator | Operand 2 | Result Type |
---|---|---|---|
Datetime |
+ or – |
Interval |
Datetime |
Interval |
+ |
Datetime |
Datetime |
When a numeric value is added to or subtracted from a DATE type, the numeric value is automatically casted to an INTERVAL DAY value. When a numeric value is added to or subtracted from a time type or a timestamp type, the numeric value is automatically casted to an INTERVAL SECOND value. For information on CAST, see CAST Expression. For more information on INTERVALS, see Interval Value Expressions
When using these operations, note:
-
Adding or subtracting an interval of months to a DATE value results in a value of the same day plus or minus the specified number of months. Because different months have different lengths, this is an approximate result.
-
Datetime and interval arithmetic can yield unexpected results, depending on how the fields are used. For example, execution of this expression (evaluated left to right) returns an error:
DATE '2007-01-30' + INTERVAL '1' MONTH + INTERVAL '7' DAY
In contrast, this expression (which adds the same values as the previous expression, but in a different order) correctly generates the value 2007-03-06:
DATE '2007-01-30' + INTERVAL '7' DAY + INTERVAL '1' MONTH
You can avoid these unexpected results by using the ADD_MONTHS Function.
Examples of Datetime Value Expressions
The PROJECT table consists of five columns that use the data types NUMERIC, VARCHAR, DATE, TIMESTAMP, and INTERVAL DAY. Suppose that you have inserted values into the PROJECT table. For example:
INSERT INTO persnl.project
VALUES (1000,'SALT LAKE CITY',DATE '2007-04-10',
TIMESTAMP '2007-04-21:08:15:00.00',INTERVAL '15' DAY);
The next examples use these values in the PROJECT table:
PROJCODE | START_DATE | SHIP_TIMESTAMP | EST_COMPLETE |
---|---|---|---|
1000 |
2007-04-10 |
2007-04-21 08:15:00.00 |
15 |
945 |
2007-10-20 |
2007-12-21 08:15:00.00 |
30 |
920 |
2007-02-21 |
2007-03-12 09:45:00.00 |
20 |
134 |
2007-1 -20 |
2008-01-01 00:00:00.00 |
30 |
-
Add an interval value qualified by YEAR to a datetime value:
SELECT start_date + INTERVAL '1' YEAR FROM persnl.project WHERE projcode = 1000; (EXPR) ---------- 2008-04-10 --- 1 row(s) selected.
-
Subtract an interval value qualified by MONTH from a datetime value:
SELECT ship_timestamp - INTERVAL '1' MONTH FROM persnl.project WHERE projcode = 134; (EXPR) -------------------------- 2007-12-01 00:00:00.000000 --- 1 row(s) selected.
The result is 2007-12-01 00:00:00.00. The YEAR value is decremented by 1 because subtracting a month from January 1 causes the date to be in the previous year.
-
Add a column whose value is an interval qualified by DAY to a datetime value:
SELECT start_date + est_complete FROM persnl.project WHERE projcode = 920; (EXPR) ---------- 2007-03-12 --- 1 row(s) selected.
The result of adding 20 days to 2008-02-21 is 2008-03-12. Trafodion SQL correctly handles 2008 as a leap year.
-
Subtract an interval value qualified by HOUR TO MINUTE from a datetime value:
SELECT ship_timestamp - INTERVAL '15:30' HOUR TO MINUTE FROM persnl.project WHERE projcode = 1000; (EXPR) -------------------------- 2008-04-20 16:45:00.000000
The result of subtracting 15 hours and 30 minutes from 2007-04-21 08:15:00.00 is 2007-04-20 16:45:00.00.
5.9.3. Interval Value Expressions
The operands of an interval value expression can be combined in specific ways with addition and subtraction operators. In this syntax diagram, the data type of a datetime expression is DATE, TIME, or TIMESTAMP; the data type of an interval term or expression is INTERVAL.
-
interval-expression
is:interval-term | interval-expression + interval-term | interval-expression - interval-term | (datetime-expression - datetime-primary) [interval-qualifier]
-
interval-term
is:interval-factor | interval-term * numeric-factor | interval-term / numeric-factor | numeric-term * interval-factor
-
interval-factor
is:[+|-] interval-primary
-
interval-primary
is:interval-literal | column-reference | interval-type-host-variable | dynamic-parameter | aggregate-function | sequence-function | scalar-subquery | CASE-expression | CAST-expression | (interval-expression)
-
numeric-factor
is:[+|-] numeric-primary | [+|-] numeric-primary ** numeric-factor
Interval value expressions are built from operands that can be:
-
Integers
-
Datetime value expressions
-
Interval literals
-
Column references with datetime or interval values
-
Dynamic parameters
-
Datetime or interval value functions
-
Aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return interval values
For interval-term, datetime-expression, and datetime-primary, see Datetime Value Expressions.
If the interval expression is the difference of two datetime expressions, by default, the result is expressed in the least significant unit of measure for that interval. For date differences, the interval is expressed in days. For timestamp differences, the interval is expressed in fractional seconds.
If the interval expression is the difference or sum of interval operands, the interval qualifiers of the operands are either year-month or day-time. If you are updating or inserting a value that is the result of adding or subtracting two interval qualifiers, the interval qualifier of the result depends on the interval qualifier of the target column.
Considerations for Interval Value Expressions
Start and End Fields
Within the definition of an interval range, the start-field and end-field can be any of the specified fields with these restrictions:
-
An interval is either year-month or day-time. If the start-field is YEAR, the end-field is MONTH; if the start-field is DAY, HOUR, or MINUTE, the end-field is also a time field.
-
The start-field must precede the end-field within the hierarchy YEAR, MONTH, DAY, HOUR, MINUTE, and SECOND.
Within the definition of an interval expression, the start-field and end-field of all operands in the expression must be either year-month or day-time.
Interval Qualifier
The rules for determining the interval qualifier of the result expression vary. For example, interval value expressions include:
Datetime Expression | Description | Result Data Type |
---|---|---|
CURRENT_DATE - start_date |
By default, the interval difference between the current date and the value in column START_DATE is expressed in days. You are not required to specify the interval qualifier. |
INTERVAL DAY (12) |
INTERVAL '3' DAY - INTERVAL '2' DAY |
The difference of two interval literals. The result is 1 day. |
INTERVAL DAY (3) |
INTERVAL '3' DAY + INTERVAL '2' DAY |
The sum of two interval literals. The result is 5 days. |
INTERVAL DAY (3) |
INTERVAL '2' YEAR - INTERVAL '3' MONTH |
The difference of two interval literals. The result is 1 year, 9 months. |
INTERVAL YEAR (3) TO MONTH |
Restrictions on Operations
You can use datetime and interval operands with arithmetic operators in an interval value expression only in these combinations:
Operand 1 | Operator | Operand 2 | Result Type |
---|---|---|---|
Datetime |
- |
Datetime |
Interval |
Interval |
+ or – |
Interval |
Interval |
Interval |
* or / |
Numeric |
Interval |
Numeric |
* |
Interval |
Interval |
This table lists valid combinations of datetime and interval arithmetic operators, and the data type of the result:
Operands | Result type |
---|---|
Date + Interval or Interval + Date |
Date |
Date + Numeric or Numeric + Date |
Date |
Date - Numeric |
Date |
Date – Interval |
Date |
Date – Date |
Interval |
Time + Interval or Interval + Time |
Time |
Time + Numeric or Numeric + Time |
Time |
Time - Number |
Time |
Time – Interval |
Time |
Timestamp + Interval or Interval + Timestamp |
Timestamp |
Timestamp + Numeric or Numeric + Timestamp |
Timestamp |
Timestamp - Numeric |
Timestamp |
Timestamp – Interval |
Timestamp |
year-month Interval + year-month Interval |
year-month Interval |
day-time Interval + day-time Interval |
day-time Interval |
year-month Interval – year-month Interval |
year-month Interval |
day-time Interval – day-time Interval |
day-time Interval |
Time – Time |
Interval |
Timestamp – Timestamp |
Interval |
Interval * Number or Number * Interval |
Interval |
Interval / Number |
Interval |
Interval – Interval or Interval + Interval |
Interval |
When using these operations, note:
-
If you subtract a datetime value from another datetime value, both values must have the same data type. To get this result, use the CAST expression. For example:
CAST (ship_timestamp AS DATE) - start_date
-
If you subtract a datetime value from another datetime value, and you specify the interval qualifier, you must allow for the maximum number of digits in the result for the precision. For example:
(CURRENT_TIMESTAMP - ship_timestamp) DAY(4) TO SECOND(6)
-
If you are updating a value that is the result of adding or subtracting two interval values, an SQL error occurs if the source value does not fit into the target column’s range of interval fields. For example, this expression cannot replace an INTERVAL DAY column:
INTERVAL '1' MONTH + INTERVAL '7' DAY
-
If you multiply or divide an interval value by a numeric value expression, Trafodion SQL converts the interval value to its least significant subfield and then multiplies or divides it by the numeric value expression. The result has the same fields as the interval that was multiplied or divided. For example, this expression returns the value 5-02:
INTERVAL '2-7' YEAR TO MONTH * 2
Examples of Interval Value Expressions
The PROJECT table consists of five columns using the data types NUMERIC, VARCHAR, DATE, TIMESTAMP, and INTERVAL DAY. Suppose that you have inserted values into the PROJECT table. For example:
INSERT INTO persnl.project
VALUES (1000,'SALT LAKE CITY',DATE '2007-04-10',
TIMESTAMP '2007-04-21:08:15:00.00',INTERVAL '15' DAY);
The next example uses these values in the PROJECT table:
PROJCODE | START_DATE | SHIP_TIMESTAMP | EST_COMPLETE |
---|---|---|---|
1000 |
2007-04-10 |
2007-04-21:08:15:00.0000 |
15 |
2000 |
2007-06-10 |
2007-07-21:08:30:00.0000 |
30 |
2500 |
2007-10-10 |
2007-12-21:09:00:00.0000 |
60 |
3000 |
2007-08-21 |
2007-10-21:08:10:00.0000 |
60 |
4000 |
2007-09-21 |
2007-10-21:10:15:00.0000 |
30 |
5000 |
2007-09-28 |
2007-10-28:09:25:01.1 1 |
30 |
-
Suppose that the CURRENT_TIMESTAMP is 2000-01-06 1 :14:41.748703. Find the number of days, hours, minutes, seconds, and fractional seconds in the difference of the current timestamp and the SHIP_TIMESTAMP in the PROJECT table:
SELECT projcode, (CURRENT_TIMESTAMP - ship_timestamp) DAY(4) TO SECOND(6) FROM samdbcat.persnl.project; Project/Code (EXPR) ------------ --------------------- 1000 1355 02:58:57.087086 2000 1264 02:43:57.087086 2500 1111 02:13:57.087086 3000 1172 03:03:57.087086 4000 1172 00:58:57.087086 5000 1165 01:48:55.975986 --- 6 row(s) selected.
5.9.4. Numeric Value Expressions
The operands of a numeric value expression can be combined in specific ways with arithmetic operators. In this syntax diagram, the data type of a term, factor, or numeric primary is numeric.
numeric-expression` is:
numeric-term
| numeric-expression + numeric-term
| numeric-expression - numeric-term
numeric-term is:
numeric-factor
| numeric-term * numeric-factor
| numeric-term / numeric-factor
numeric-factor is:
[+|-] numeric-primary
| [+|-] numeric-primary ** numeric-factor
numeric-primary is:
unsigned-numeric-literal
| column-reference
| numeric-type-host-variable
| dynamic parameter
| numeric-value-function
| aggregate-function
| sequence-function
| scalar-subquery
| CASE-expression
| CAST-expression
| (numeric-expression)
As shown in the preceding syntax diagram, numeric value expressions are built from operands that can be:
-
Numeric literals
-
Column references with numeric values
-
Dynamic parameters
-
Numeric value functions
-
Aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return numeric values
Considerations for Numeric Value Expressions
Order of Evaluation
-
Expressions within parentheses
-
Unary operators
-
Exponentiation
-
Multiplication and division
-
Addition and subtraction
Operators at the same level are evaluated from left to right for all
operators except exponentiation. Exponentiation operators at the same
level are evaluated from right to left. For example,
X + Y + Z
is evaluated as (X + Y) + Z
, whereas X ** Y ** Z
is evaluated as X ** (Y ** Z)
.
Additional Rules for Arithmetic Operations
Numeric expressions are evaluated according to these additional rules:
-
An expression with a numeric operator evaluates to null if any of the operands is null.
-
Dividing by 0 causes an error.
-
Exponentiation is allowed only with numeric data types. If the first operand is 0 (zero), the second operand must be greater than 0, and the result is 0. If the second operand is 0, the first operand cannot be 0, and the result is 1. If the first operand is negative, the second operand must be a value with an exact numeric data type and a scale of zero.
-
Exponentiation is subject to rounding error. In general, results of exponentiation should be considered approximate.
Precision, Magnitude, and Scale of Arithmetic Results
The precision, magnitude, and scale are computed during the evaluation of an arithmetic expression. Precision is the maximum number of digits in the expression. Magnitude is the number of digits to the left of the decimal point. Scale is the number of digits to the right of the decimal point.
For example, a column declared as NUMERIC (18, 5) has a precision of 18, a magnitude of 13, and a scale of 5. As another example, the literal 12345.6789 has a precision of 9, a magnitude of 5, and a scale of 4.
The maximum precision for exact numeric data types is 128 digits. The maximum precision for the REAL data type is approximately 7 decimal digits, and the maximum precision for the DOUBLE PRECISION data type is approximately 16 digits.
When Trafodion SQL encounters an arithmetic operator in an expression, it applies these rules (with the restriction that if the precision becomes greater than 18, the resulting precision is set to 18 and the resulting scale is the maximum of 0 and (18- (resulted precision - resulted scale)).
-
If the operator is + or -, the resulting scale is the maximum of the scales of the operands. The resulting precision is the maximum of the magnitudes of the operands, plus the scale of the result, plus 1.
-
If the operator is *, the resulting scale is the sum of the scales of the operands. The resulting precision is the sum of the magnitudes of the operands and the scale of the result.
-
If the operator is /, the resulting scale is the sum of the scale of the numerator and the magnitude of the denominator. The resulting magnitude is the sum of the magnitude of the numerator and the scale of the denominator.
For example, if the numerator is NUMERIC (7, 3) and the denominator is NUMERIC (7, 5), the resulting scale is 3 plus 2 (or 5), and the resulting magnitude is 4 plus 5 (or 9). The expression result is NUMERIC (14, 5).
Conversion of Numeric Types for Arithmetic Operations
Trafodion SQL automatically converts between floating-point numeric types (REAL and DOUBLE PRECISION) and other numeric types. All numeric values in the expression are first converted to binary, with the maximum precision needed anywhere in the evaluation.
Examples of Numeric Value Expressions
These are examples of numeric value expressions:
-57 |
Numeric literal. |
salary * 1.10 |
The product of the values in the SALARY column and a numeric literal. |
unit_price * qty_ordered |
The product of the values in the UNIT_PRICE and QTY_ORDERED columns. |
12 * (7 - 4) |
An expression whose operands are numeric literals. |
COUNT (DISTINCT city) |
Function applied to the values in a column. |
5.10. Identifiers
SQL identifiers are names used to identify tables, views, columns, and other SQL entities. The two types of identifiers are regular and delimited. A delimited identifier is enclosed in double quotes ("). Case-insensitive delimited identifiers are used only for user names and role names. Either regular, delimited, or case-sensitive delimited identifiers can contain up to 128 characters.
5.10.1. Regular Identifiers
Regular identifiers begin with a letter (A through Z and a through z), but can also contain digits (0 through 9) or underscore characters (_). Regular identifiers are not case-sensitive. You cannot use a reserved word as a regular identifier.
5.10.2. Delimited Identifiers
Delimited identifiers are character strings that appear within double quote characters (") and consist of alphanumeric characters, including the underscore character (_) or a dash (-). Unlike regular identifiers, delimited identifiers are case-sensitive. Trafodion SQL does not support spaces or special characters in delimited identifiers given the constraints of the underlying HBase file system. You can use reserved words as delimited identifiers.
5.10.3. Case-Insensitive Delimited Identifiers
Case-insensitive delimited identifiers, which are used for user names and roles, are character strings that appear within double quote characters (") and consist of alphanumeric characters (A through Z and a through z), digits (0 through 9), underscores (_), dashes (-), periods (.), at symbols (@), and forward slashes (/), except for the leading at sign (@) or leading forward slash (/) character.
Unlike other delimited identifiers, case-insensitive-delimited
identifiers are case-insensitive. Identifiers are up-shifted before
being inserted into the SQL metadata. Thus, whether you specify a user’s
name as "Penelope.Quan@company.com"
, "PENELOPE.QUAN@company.com"
, or
"penelope.quan@company.com"
, the value stored in the metadata will be the
same: PENELOPE.QUAN@COMPANY.COM
.
You can use reserved words as case-insensitive delimited identifiers.
5.10.4. Examples of Identifiers
-
These are regular identifiers:
mytable SALES2006 Employee_Benefits_Selections CUSTOMER_BILLING_INFORMATION
Because regular identifiers are case insensitive, SQL treats all these identifiers as alternative representations of mytable:
mytable MYTABLE MyTable mYtAbLe
-
These are delimited identifiers:
"mytable" "table" "CUSTOMER-BILLING-INFORMATION"
Because delimited identifiers are case-sensitive, SQL treats the identifier "mytable" as different from the identifiers "MYTABLE" or "MyTable".
You can use reserved words as delimited identifiers. For example, table is not allowed as a regular identifier, but "table" is allowed as a delimited identifier.
5.11. Indexes
An index is an ordered set of pointers to rows of a table. Each index is based on the values in one or more columns. Indexes are transparent to DML syntax.
A one-to-one correspondence always exists between index rows and base table rows.
5.11.1. SQL Indexes
Each row in a Trafodion SQL index contains:
-
The columns specified in the CREATE INDEX statement
-
The clustering key of the underlying table (the user-defined clustering key)
An index name is an SQL identifier. Indexes have their own name space within a schema, so an index name might be the same as a table or constraint name. However, no two indexes in a schema can have the same name.
5.12. Keys
5.12.1. Clustering Keys
Every table has a clustering key, which is the set of columns that determine the order of the rows on disk. Trafodion SQL organizes records of a table or index by using a b-tree based on this clustering key. Therefore, the values of the clustering key act as logical row-ids.
5.12.2. SYSKEY
When the STORE BY clause is specified with the key-column-list clause, an additional column is appended to the key-column-list called the SYSKEY.
A SYSKEY (or system-defined clustering key) is a clustering key column which is defined by Trafodion SQL rather than by the user. Its type is LARGEINT SIGNED. When you insert a record in a table, Trafodion SQL automatically generates a value for the SYSKEY column. You cannot supply the value.
You cannot specify a SYSKEY at insert time and you cannot update it after it has been generated. To see the value of the generated SYSKEY, include the SYSKEY column in the select list:
SELECT *, SYSKEY FROM t4;
5.12.3. Index Keys
A one-to-one correspondence always exists between index rows and base table rows. Each row in a Trafodion SQL index contains:
-
The columns specified in the CREATE INDEX statement
-
The clustering (primary) key of the underlying table (the user-defined clustering key)
For a non-unique index, the clustering key of the index is composed of both items. The clustering key cannot exceed 2048 bytes. Because the clustering key includes all the columns in the table, each row is also limited to 2048 bytes.
For varying-length character columns, the length referred to in these byte limits is the defined column length, not the stored length. (The stored length is the expanded length, which includes two extra bytes for storing the data length of the item.)
5.12.4. Primary Keys
A primary key is the column or set of columns that define the uniqueness constraint for a table. The columns cannot contain nulls, and only one primary key constraint can exist on a table.
5.13. Literals
A literal is a constant you can use in an expression, in a statement, or as a parameter value. An SQL literal can be one of these data types:
A series of characters enclosed in single quotes. |
|
Begins with keyword DATE, TIME, or TIMESTAMP and followed by a character string. |
|
Begins with keyword INTERVAL and followed by a character string and an interval qualifier. |
|
A simple numeric literal (one without an exponent) or a numeric literal in scientific notation. |
5.13.1. Character String Literals
A character string literal is a series of characters enclosed in single quotes.
You can specify either a string of characters or a set of hexadecimal code values representing the characters in the string.
-
'string' | [character-set | N] X'hex-code-value. . . ' | [character-set | N] X'hex-code-value[hex-code-value. . .][space. . .]' _ character-set_
specifies the character set ISO88591 or UTF8. The character-set specification of the string literal should correspond with the character set of the column definition, which is either ISO88591 or UTF8. If you omit the _character-set specification, Trafodion SQL initially assumes the ISO88591 character set if the string literal consists entirely of 7-bit ASCII characters and UTF8 otherwise. (However, the initial assumption will later be changed if the string literal is used in a context that requires a character set different from the initial assumption.)
-
N
associates the string literal with the character set of the NATIONAL CHARACTER (NCHAR) data type. The character set for NCHAR is determined during the installation of Trafodion SQL. This value can be either UTF8 (the default) or ISO88591.
-
'string'
is a series of any input characters enclosed in single quotes. A single quote within a string is represented by two single quotes (''). A string can have a length of zero if you specify two single quotes ('') without a space in between.
-
X
indicates the hexadecimal string.
-
'hex-code-value'
represents the code value of a character in hexadecimal form enclosed in single quotes. It must contain an even number of hexadecimal digits. For ISO88591, each value must be two digits long. For UTF8, each value can be 2, 4, 6, or 8 hexadecimal digits long. If hex-code-value is improperly formatted (for example, it contains an invalid hexadecimal digit or an odd number of hexadecimal digits), an error is returned.
-
space
is space sequences that can be added before or after hex-code-value for readability. The encoding for space must be the TERMINAL_CHARSET for an interactive interface and the SQL module character set for the programmatic interface.
Considerations for Character String Literals
Using String Literals
A string literal can be as long as a character column. See Character String Data Types.
You can also use string literals in string value expressions—for example, in expressions that use the concatenation operator (||) or in expressions that use functions returning string values.
When specifying string literals:
-
Do not put a space between the character set qualifier and the character string literal. If you use this character string literal in a statement, Trafodion SQL returns an error.
-
To specify a single quotation mark within a string literal, use two consecutive single quotation marks.
-
To specify a string literal whose length is more than one line, separate the literal into several smaller string literals, and use the concatenation operator (||) to concatenate them.
-
Case is significant in string literals. Lowercase letters are not equivalent to the corresponding uppercase letters.
-
Leading and trailing spaces within a string literal are significant.
-
Alternately, a string whose length is more than one line can be written as a literal followed by a space, CR, or tab character, followed by another string literal.
Examples of Character String Literals
-
These data type column specifications are shown with examples of literals that can be stored in the columns.
Character String Data Type Character String Literal Example CHAR (12) UPSHIFT
'PLANNING'
VARCHAR (18)
'NEW YORK'
-
These are string literals:
'This is a string literal.' 'abc^&*' '1234.56' 'This literal contains '' a single quotation mark.'
-
This is a string literal concatenated over three lines:
'This literal is' || ' in three parts,' || 'specified over three lines.'
-
This is a hexadecimal string literal representing the VARCHAR pattern of the ISO88591 string 'Strauß':
_ISO88591 X'53 74 72 61 75 DF'
5.13.2. Datetime Literals
A datetime literal is a DATE, TIME, or TIMESTAMP constant you can use in an expression, in a statement, or as a parameter value. Datetime literals have the same range of valid values as the corresponding datetime data types. You cannot use leading or trailing spaces within a datetime string (within the single quotes).
A datetime literal begins with the DATE, TIME, or TIMESTAMP keyword and can appear in default, USA, or European format.
DATE 'date' | TIME 'time' | TIMESTAMP 'timestamp'
date is:
yyyy-mm-dd Default
| mm/dd/yyyy USA
| dd.mm.yyyy European
time is:
hh:mm:ss.msssss Default
| hh:mm:ss.msssss [am | pm] USA
| hh.mm.ss.msssss European
timestamp is:
yyyy-mm-dd hh:mm:ss.msssss Default
| mm/dd/yyyy hh:mm:ss.msssss [am | pm] USA
| dd.mm.yyyy hh.mm.ss.msssss European
-
date,time,timestamp
specify the datetime literal strings whose component fields are:
yyyy
Year, from 0001 to 9999
mm
Month, from 01 to 12
dd
Day, from 01 to 31
hh
Hour, from 00 to 23
mm
Minute, from 00 to 59
ss
Second, from 00 to 59
msssss
Microsecond, from 000000 to 999999
am
AM or am, indicating time from midnight to before noon
pm
PM or pm, indicating time from noon to before midnight
Examples of Datetime Literals
-
These are DATE literals in default, USA, and European formats, respectively:
DATE '2008-01-22' DATE '01/22/2008' DATE '22.01.2008'
-
These are TIME literals in default, USA, and European formats, respectively:
TIME '13:40:05' TIME '01:40:05 PM' TIME '13.40.05'
-
These are TIMESTAMP literals in default, USA, and European formats, respectively:
TIMESTAMP '2008-01-22 13:40:05' TIMESTAMP '01/22/2008 01:40:05 PM' TIMESTAMP '22.01.2008 13.40.05'
5.13.3. Interval Literals
An interval literal is a constant of data type INTERVAL that represents a positive or negative duration of time as a year-month or day-time interval; it begins with the keyword INTERVAL optionally preceded or followed by a minus sign (for negative duration). You cannot include leading or trailing spaces within an interval string (within single quotes).
[-]INTERVAL [-]{'year-month' | 'day:time'} interval-qualifier
year-month is:
years [-months] | months
day:time is:
days [[:]hours [:minutes [:seconds [.fraction]]]]
| hours [:minutes [:seconds [.fraction]]]
| minutes [:seconds [.fraction]]
| seconds [.fraction]
interval-qualifier is:
start-field TO end-field | single-field
start-field is:
{YEAR | MONTH | DAY | HOUR | MINUTE} [(leading-precision)]
end-field is:
YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(fractional-precision)]
single-field is:
start-field | SECOND [(leading-precision,fractional-precision)]
-
start-field TO end-field
must be year-month or day-time.The start-field you specify must precede the end-field you specify in the list of field names.
-
{YEAR | MONTH | DAY | HOUR | MINUTE} [(leading-precision)]
specifies the start-field. A start-field can have a leading-precision up to 18 digits (the maximum depends on the number of fields in the interval). The leading-precision is the number of digits allowed in the start-field. The default for leading-precision is 2.
-
YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(fractional-precision)]
specifies the end-field. If the end-field is SECOND, it can have a fractional-precision up to 6 digits. The fractional-precision is the number of digits of precision after the decimal point. The default for fractional-precision is 6.
-
start-field | SECOND [(leading-precision, fractional-precision)]
specifies the single-field. If the single-field is SECOND, the leading-precision is the number of digits of precision before the decimal point, and the fractional-precision is the number of digits of precision after the decimal point.
The default for leading-precision is 2, and the default for fractional-precision is 1. The maximum for leading-precision is 18, and the maximum for fractional-precision is 6.
-
'year-month' | 'day:time'
specifies the date and time components of an interval literal. The day and hour fields can be separated by a space or a colon. The interval literal strings are:
years
Unsigned integer that specifies a number of years. years can be up to 18 digits, or 16 digits if months is the end-field. The maximum for the leading-precision is specified within the interval qualifier by either YEAR(18) or YEAR(16) TO MONTH.
months
Unsigned integer that specifies a number of months. Used as a starting field, months can have up to 18 digits. The maximum for the leading-precision is specified by MONTH(18). Used as an ending field, the value of months must be in the range 0 to 1 .
days
Unsigned integer that specifies number of days. days can have up to 18 digits if no end-field exists; 16 digits if hours is the end-field; 14 digits if minutes is the end-field; and 13-f digits if seconds is the end-field, where f is the fraction less than or equal to 6. These maximums are specified by DAY(18), DAY(16) TO HOUR, DAY(14) TO MINUTE, and DAY(13-f) TO SECOND(f).
hours
Unsigned integer that specifies a number of hours. Used as a starting field, hours can have up to 18 digits if no end-field exists; 16 digits if minutes is the end-field; and 14-f digits if seconds is the end-field, where f is the fraction less than or equal to 6. These maximums are specified by HOUR(18), HOUR(16) TO MINUTE, and HOUR(14-f) TO SECOND(f). Used as an ending field, the value of hours must be in the range 0 to 23.
minutes
Unsigned integer that specifies a number of minutes. Used as a starting field, minutes can have up to 18 digits if no end-field exists; and 16-f digits if seconds is the end-field, where f is the fraction less than or equal to 6. These maximums are specified by MINUTE(18), and MINUTE(16-f) TO SECOND(f). Used as an ending field, the value of minutes must be in the range 0 to 59.
seconds
Unsigned integer that specifies a number of seconds. Used as a starting field, seconds can have up to 18 digits, minus the number of digits f in the fraction less than or equal to 6. This maximum is specified by SECOND(18-f, f). The value of seconds must be in the range 0 to 59.9(n), where n is the number of digits specified for seconds precision.
fraction
Unsigned integer that specifies a fraction of a second. When seconds is used as an ending field, fraction is limited to the number of digits specified by the fractional-precision field following the SECOND keyword.
Considerations for Interval Literals
Length of Year-Month and Day-Time Strings
An interval literal can contain a maximum of 18 digits, in the string following the INTERVAL keyword, plus a hyphen (-) that separates the year-month fields, and colons (:) that separate the day-time fields. You can also separate day and hour with a space.
Examples of Interval Literals
INTERVAL '1' MONTH |
Interval of 1 month |
INTERVAL '7' DAY |
Interval of 7 days |
INTERVAL '2-7' YEAR TO MONTH |
Interval of 2 years, 7 months |
INTERVAL '5:2:15:36.33' DAY TO SECOND(2) |
Interval of 5 days, 2 hours, 15 minutes, and 36.33 seconds |
INTERVAL - '5' DAY |
Interval that subtracts 5 days |
INTERVAL '100' DAY(3) |
Interval of 100 days. This example requires an explicit leading precision of 3 because the default is 2. |
INTERVAL '364 23' DAY(3) TO HOUR |
Interval of 364 days, 23 hours. The separator for the day and hour fields can be a space or a colon. |
5.13.4. Numeric Literals
A numeric literal represents a numeric value. Numeric literals can be represented as an exact numeric literal (without an exponent) or as an approximate numeric literal by using scientific notation (with an exponent).
exact-numeric-literal is:
[+|-]unsigned-integer[.[unsigned-integer]]
| [+|-].unsigned-integer
approximate-numeric-literal is:
mantissa{E|e}exponent
mantissa is:
exact-numeric-literal
exponent is:
[+|-]unsigned-integer
unsigned-integer is:
digit. . .
-
exact-numeric-literal
is an exact numeric value that includes an optional plus sign (+) or minus sign (-), up to 128 digits (0 through 9), and an optional period (.) that indicates a decimal point. Leading zeros do not count toward the 128-digit limit; trailing zeros do.
A numeric literal without a sign is a positive number. An exact numeric literal that does not include a decimal point is an integer. Every exact numeric literal has the data type NUMERIC and the minimum precision required to represent its value.
-
approximate-numeric-literal
is an exact numeric literal followed by an exponent expressed as an uppercase E or lowercase e followed by an optionally signed integer.
Numeric values expressed in scientific notation are treated as data type REAL if they include no more than seven digits before the exponent, but treated as type DOUBLE PRECISION if they include eight or more digits. Because of this factor, trailing zeros after a decimal can sometimes increase the precision of a numeric literal used as a DOUBLE PRECISION value.
+For example, if XYZ is a table that consists of one DOUBLE PRECISION column, the inserted value:
INSERT INTO XYZ VALUES (1.00000000E-10)
has more precision than:
INSERT INTO XYZ VALUES (1.0E-10)
Examples of Numeric Literals
These are all numeric literals, along with their display format:
Literal | Display Format |
---|---|
477 |
477 |
580.45 |
580.45 |
+005 |
5 |
-.3175 |
-.3175 |
1300000000 |
1300000000 |
99. |
99 |
-0.123456789012345678 |
-.123456789012345678 |
99E-2 |
9.9000000E-001 |
12.3e+5 |
1.2299999E+006 |
5.14. Null
Null is a special symbol, independent of data type, that represents an unknown. The Trafodion SQL keyword NULL represents null. Null indicates that an item has no value. For sorting purposes, null is greater than all other values. You cannot store null in a column by using INSERT or UPDATE, unless the column allows null.
A column that allows null can be null at any row position. A nullable column has extra bytes associated with it in each row. A special value stored in these bytes indicates that the column has null for that row.
5.14.1. Using Null Versus Default Values
Various scenarios exist in which a row in a table might contain no value for a specific column. For example:
-
A database of telemarketing contacts might have null AGE fields if contacts did not provide their age.
-
An order record might have a DATE_SHIPPED column empty until the order is actually shipped.
-
An employee record for an international employee might not have a social security number.
You allow null in a column when you want to convey that a value in the column is unknown (such as the age of a telemarketing contact) or not applicable (such as the social security number of an international employee).
In deciding whether to allow nulls or use defaults, also note:
-
Nulls are not the same as blanks. Two blanks can be compared and found equal, while the result of a comparison of two nulls is indeterminate.
-
Nulls are not the same as zeros. Zeros can participate in arithmetic operations, while nulls are excluded from any arithmetic operation.
5.14.2. Defining Columns That Allow or Prohibit Null
The CREATE TABLE and ALTER TABLE statements define the attributes for columns within tables. A column allows nulls unless the column definition includes the NOT NULL clause or the column is part of the primary key of the table.
Null is the default for a column (other than NOT NULL) unless the column definition includes a DEFAULT clause (other than DEFAULT NULL) or the NO DEFAULT clause. The default value for a column is the value Trafodion SQL inserts in a row when an INSERT statement omits a value for a particular column.
Null in DISTINCT, GROUP BY, and ORDER BY Clauses
In evaluating the DISTINCT, GROUP BY, and ORDER BY clauses, Trafodion SQL considers all nulls to be equal. Additional considerations for these clauses are:
DISTINCT |
Nulls are considered duplicates; therefore, a result has at most one null. |
GROUP BY |
The result has at most one null group. |
ORDER BY |
Nulls are considered greater than non-null values. |
Null and Expression Evaluation Comparison
Expression Type | Condition | Result |
---|---|---|
Boolean operators (AND, OR, NOT) |
Either operand is null. |
For AND, the result is null. For OR, the result is true if the other operand is true, or null if the other operand is null or false. For NOT, the result is null. |
Arithmetic operators |
Either or both operands are null. |
The result is null. |
NULL predicate |
The operand is null. |
The result is true. |
Aggregate (or set) functions (except COUNT) |
Some rows have null columns. The function is evaluated after eliminating nulls. |
The result is null if set is empty. |
COUNT(*) |
The function does not eliminate nulls. |
The result is the number of rows in the table whether or not the rows are null. |
COUNT COUNT DISTINCT |
The function is evaluated after eliminating nulls. |
The result is zero if set is empty. |
Comparison: =, <>, <, >, <=, >=, LIKE |
Either operand is null. |
The result is null. |
IN predicate |
Some expressions in the IN value list are null. |
The result is null if all of the expressions are null. |
Subquery |
No rows are returned. |
The result is null. |
5.15. Predicates
A predicate determines an answer to a question about a value or group of values. A predicate returns true, false, or, if the question cannot be answered, unknown. Use predicates within search conditions to choose rows from tables or views.
Determines whether a sequence of values is within a range of sequences of values. |
|
Comparison Predicates |
Compares the values of sequences of expressions, or compares the values of sequences of row values that are the result of row subqueries. |
Determines whether any rows are selected by a subquery. If the subquery finds at least one row that satisfies its search condition, the predicate evaluates to true. Otherwise, if the result table of the subquery is empty, the predicate is false. |
|
Determines if a sequence of values is equal to any of the sequences of values in a list of sequences. |
|
Searches for character strings that match a pattern. |
|
Determines whether all the values in a sequence of values are null. |
|
Quantified Comparison Predicates |
Compares the values of sequences of expressions to the values in each row selected by a table subquery. The comparison is quantified by ALL, ANY, or . |
See the individual entry for a predicate or predicate group.
5.15.1. BETWEEN Predicate
The BETWEEN predicate determines whether a sequence of values is within a range of sequences of values.
row-value-constructor [NOT] BETWEEN
row-value-constructor AND row-value-constructor
row-value-constructor is:
(expression [,expression ]...)
| row-subquery
-
row-value-constructor
specifies an operand of the BETWEEN predicate. The three operands can be either of:
-
(expression [,expression ]…)
is a sequence of SQL value expressions, separated by commas and enclosed in parentheses. expression cannot include an aggregate function unless expression is in a HAVING clause. expression can be a scalar subquery (a subquery that returns a single row consisting of a single column). See Expressions.
-
row-subquery
is a subquery that returns a single row (consisting of a sequence of values). See Subquery .
The three row-value-constructors specified in a BETWEEN predicate must contain the same number of elements. That is, the number of value expressions in each list, or the number of values returned by a row subquery, must be the same.
The data types of the respective values of the three row-value-constructors must be comparable. Respective values are values with the same ordinal position in the two lists. See Comparable and Compatible Data Types.
-
Considerations for BETWEEN
Logical Equivalents Using AND and OR
The predicate expr1 BETWEEN expr2 AND expr3 is true if and only if this condition is true:
expr2 <= expr1 AND expr1 <= expr3
The predicate expr1 NOT BETWEEN expr2 AND expr3 is true if and only if this condition is true:
expr2 > expr1 OR expr1 > expr3
Descending Columns in Keys
If a clause specifies a column in a key BETWEEN expr2 and expr3, expr3 must be greater than expr2 even if the column is specified as DESCENDING within its table definition.
Examples of BETWEEN
-
This predicate is true if the total price of the units in inventory is in the range from $1,000 to $10,000:
qty_on_hand * price BETWEEN 1000.00 AND 10000.00
-
This predicate is true if the part cost is less than $5 or more than $800:
partcost NOT BETWEEN 5.00 AND 800.00
-
This BETWEEN predicate selects the part number 6400:
SELECT * FROM partsupp WHERE partnum BETWEEN 6400 AND 6700 AND partcost > 300.00; Part/Num Supp/Num Part/Cost Qty/Rec -------- -------- ------------ ---------- 6400 1 390.00 50 6401 2 500.00 20 6401 3 480.00 38 --- 3 row(s) selected.
-
Find names between Jody Selby and Gene Wright:
(last_name, first_name) BETWEEN ('SELBY', 'JODY') AND ('WRIGHT', 'GENE')
The name Barbara Swift would meet the criteria; the name Mike Wright would not.
SELECT empnum, first_name, last_name FROM persnl.employee WHERE (last_name, first_name) BETWEEN ('SELBY', 'JODY') AND ('WRIGHT', 'GENE'); EMPNUM FIRST_NAME LAST_NAME ------ --------------- -------------------- 43 PAUL WINTER 72 GLENN THOMAS 74 JOHN WALKER ... --- 15 row(s) selected.
5.15.2. Comparison Predicates
A comparison predicate compares the values of sequences of expressions, or the values of sequences of row values that are the result of row subqueries.
row-value-constructor comparison-op row-value-constructor
-
comparison-op
is:= Equal | <> Not equal | < Less than | > Greater than | <= Less than or equal to | >= Greater than or equal to
-
row-value-constructor
is:(expression [,expression]...) | row-subquery
-
row-value-constructor
specifies an operand of a comparison predicate. The two operands can be either of these:
-
(expression [,expression ]…)
is a sequence of SQL value expressions, separated by commas and enclosed in parentheses.
expression cannot include an aggregate function unless expression is in a HAVING clause. expression can be a scalar subquery (a subquery that returns a single row consisting of a single column). See Expressions.
-
row-subquery
is a subquery that returns a single row (consisting of a sequence of values). See Subquery .
-
-
The two row-value-constructors must contain the same number of elements. That is, the number of value expressions in each list, or the number of values returned by a row subquery, must be the same.
The data types of the respective values of the two row-value-constructors must be comparable. (Respective values are values with the same ordinal position in the two lists.) See Comparable and Compatible Data Types.
Considerations for Comparison Predicates
When a Comparison Predicate Is True
Trafodion SQL determines whether a relationship is true or false by comparing values in corresponding positions in sequence, until it finds the first non-equal pair.
You cannot use a comparison predicate in a WHERE or HAVING clause to compare row value constructors when the value expressions in one row value constructor are equal to null. Use the IS NULL predicate instead.
Suppose that two rows with multiple components exist, X and Y:
X=(X1,X2,...,Xn), Y=(Y1,Y2,...,Yn).
Predicate X=Y is true if for all i=1,…,n: Xi=Yi. For this predicate, Trafodion SQL must look through all values. Predicate X = Y is false if for some i Xi<>Yi. When SQL finds non-equal components, it stops and does not look at remaining components.
Predicate X<>Y is true if X=Y is false. If X1<>Y1, Trafodion SQL does not look at all components. It stops and returns a value of false for the X=Y predicate and a value of true for the X<>Y predicate. Predicate X<>Y is false if X=Y is true, or for all i=1,…,n: Xi=Yi. In this situation, Trafodion SQL must look through all components.
Predicate X>Y is true if for some index m Xm>Ym and for all i=1,…,m-1: Xi=Yi. Trafodion SQL does not look through all components. It stops when it finds the first nonequal components, Xm<>Ym. If Xm>Ym, the predicate is true. Otherwise the predicate is false. The predicate is also false if all components are equal, or X=Y.
Predicate X>=Y is true if X>Y is true or X=Y is true. In this scenario, Trafodion SQL might look through all components and return true if they are all equal. It stops at the first nonequal components, Xm<>Ym. If Xm>Ym, the predicate is true. Otherwise, it is false.
Predicate X<Y is true if for some index m Xm<Ym, and for all i=1,…,m-1: Xi=Yi. Trafodion SQL does not look through all components. It stops when it finds the first nonequal components Xm<>Ym. If Xm<Ym, the predicate is true. Otherwise, the predicate is false. The predicate is also false if all components are equal, or X=Y.
Predicate X<=Y is true if X<Y is true or X=Y is true. In this scenario, Trafodion SQL might need to look through all components and return true if they are all equal. It stops at the first non-equal components, Xm<>Ym. If Xm<Ym, the predicate is true. Otherwise, it is false.
Comparing Character Data
For comparisons between character strings of different lengths, the shorter string is padded on the right with spaces (HEX 20) until it is the length of the longer string. Both fixed-length and variable-length strings are padded in this way.
For example, Trafodion SQL considers the string ‘JOE’ equal to a value JOE stored in a column of data type CHAR or VARCHAR of width three or more. Similarly, Trafodion SQL considers a value JOE stored in any column of the CHAR data type equal to the value JOE stored in any column of the VARCHAR data type.
Two strings are equal if all characters in the same ordinal position are equal. Lowercase and uppercase letters are not considered equivalent.
Comparing Numeric Data
Before evaluation, all numeric values in an expression are first converted to the maximum precision needed anywhere in the expression.
Comparing Interval Data
For comparisons of INTERVAL values, Trafodion SQL first converts the intervals to a common unit.
If no common unit exists, Trafodion SQL reports an error. Two INTERVAL values must be both year-month intervals or both day-time intervals.
Comparing Multiple Values
Use multi-value predicates whenever possible; they are generally more efficient than equivalent conditions without multi-value predicates.
Examples of Comparison Predicates
-
This predicate is true if the customer number is equal to 3210:
custnum = 3210
-
This predicate is true if the salary is greater than the average salary of all employees:
salary > (SELECT AVG (salary) FROM persnl.employee);
-
This predicate is true if the customer name is BACIGALUPI:
custname = 'BACIGALUPI'
-
This predicate evaluates to unknown for any rows in either CUSTOMER or ORDERS that contain null in the CUSTNUM column:
customer.custnum > orders.custnum
-
This predicate returns information about anyone whose name follows MOSS, DUNCAN in a list arranged alphabetically by last name and, for the same last name, alphabetically by first name:
(last_name, first_name) > ('MOSS', 'DUNCAN')
REEVES, ANNE meets this criteria, but MOSS, ANNE does not.
This multi-value predicate is equivalent to this condition with three comparison predicates:
(last_name > 'MOSS') OR (last_name = 'MOSS' AND first_name > 'DUNCAN')
-
Compare two datetime values START_DATE and the result of the CURRENT_DATE function:
START_DATE < CURRENT_DATE
-
Compare two datetime values START_DATE and SHIP_TIMESTAMP:
CAST (start_date AS TIMESTAMP) < ship_timestamp
-
Compare two INTERVAL values:
JOB1_TIME < JOB2_TIME
Suppose that JOB1_TIME, defined as INTERVAL DAY TO MINUTE, is 2 days 3 hours, and JOB2_TIME, defined as INTERVAL DAY TO HOUR, is 3 days.
To evaluate the predicate, Trafodion SQL converts the two INTERVAL values to MINUTE. The comparison predicate is true.
-
The next examples contain a subquery in a comparison predicate. Each subquery operates on a separate logical copy of the EMPLOYEE table.
The processing sequence is outer to inner. A row selected by an outer query allows an inner query to be evaluated, and a single value is returned. The next inner query is evaluated when it receives a value from its outer query.
Find all employees whose salary is greater than the maximum salary of employees in department 1500:
SELECT first_name, last_name, deptnum, salary FROM persnl.employee WHERE salary > (SELECT MAX (salary) FROM persnl.employee WHERE deptnum = 1500); FIRST_NAME LAST_NAME DEPTNUM SALARY --------------- -------------------- ------- ----------- ROGER GREEN 9000 175500.00 KATHRYN HALL 4000 96000.00 RACHEL MCKAY 4000 118000.00 THOMAS RUDLOFF 2000 138000.40 JANE RAYMOND 3000 136000.00 JERRY HOWARD 1000 137000.10 --- 6 row(s) selected.
Find all employees from other departments whose salary is less than the minimum salary of employees (not in department 1500) that have a salary greater than the average salary for department 1500:
SELECT first_name, last_name, deptnum, salary FROM persnl.employee WHERE deptnum <> 1500 AND salary < (SELECT MIN (salary) FROM persnl.employee WHERE deptnum <> 1500 AND salary > (SELECT AVG (salary) FROM persnl.employee WHERE deptnum = 1500)); FIRST_NAME LAST_NAME DEPTNUM SALARY --------------- -------------------- ------- ----------- JESSICA CRINER 3500 39500.00 ALAN TERRY 3000 39500.00 DINAH CLARK 9000 37000.00 BILL WINN 2000 32000.00 MIRIAM KING 2500 18000.00 ... --- 35 row(s) selected.
The first subquery of this query determines the minimum salary of employees from other departments whose salary is greater than the average salary for department 1500. The main query then finds the names of employees who are not in department 1500 and whose salary is less than the minimum salary determined by the first subquery.
5.15.3. EXISTS Predicate
The EXISTS predicate determines whether any rows are selected by a subquery. If the subquery finds at least one row that satisfies its search condition, the predicate evaluates to true. Otherwise, if the result table of the subquery is empty, the predicate is false.
[NOT] EXISTS subquery
-
subquery
specifies the operand of the predicate. A subquery is a query expression enclosed in parentheses. An EXISTS subquery is typically correlated with an outer query. See Subquery .
Examples of EXISTS
-
Find locations of employees with job code 300:
SELECT deptnum, location FROM persnl.dept D WHERE EXISTS (SELECT jobcode FROM persnl.employee E WHERE D.deptnum = E.deptnum AND jobcode = 300); DEPTNUM LOCATION ------- ------------- 3000 NEW YORK 3100 TORONTO 3200 FRANKFURT 3300 LONDON 3500 HONG KONG --- 5 row(s) selected.
In the preceding example, the EXISTS predicate contains a subquery that determines which locations have employees with job code 300. The subquery depends on the value of D.DEPTNUM from the outer query and must be evaluated for each row of the result table where D.DEPTNUM equals E.DEPTNUM. The column D.DEPTNUM is an example of an outer reference.
-
Search for departments that have no employees with job code 420:
SELECT deptname FROM persnl.dept D WHERE NOT EXISTS (SELECT jobcode FROM persnl.employee E WHERE D.deptnum = E.deptnum AND jobcode = 420); DEPTNAME ------------ FINANCE PERSONNEL INVENTORY ... --- 11 row(s) selected.
-
Search for parts with less than 20 units in the inventory:
SELECT partnum, suppnum FROM invent.partsupp PS WHERE EXISTS (SELECT partnum FROM invent.partloc PL WHERE PS.partnum = PL.partnum AND qty_on_hand < 20); PARTNUM SUPPNUM ------- ------- 212 1 212 3 2001 1 2003 2 ... --- 18 row(s) selected.
5.15.4. IN Predicate
The IN predicate determines if a sequence of values is equal to any of the sequences of values in a list of sequences. The NOT operator reverses its truth value. For example, if IN is true, NOT IN is false.
row-value-constructor
[NOT] IN {table-subquery | in-value-list}
row-value-constructor is:
(expression [,expression]...)
| row-subquery
-
in-value-list
is:(expression [,expression_]...)
-
row-value-constructor
specifies the first operand of the IN predicate. The first operand can be either of:
(expression [,expression ]...)
is a sequence of SQL value expressions, separated by commas and enclosed in parentheses.
expression cannot include an aggregate function unless expression is in a HAVING clause. expression can be a scalar subquery (a subquery that returns a single row consisting of a single column). See Expressions.
-
row-subquery
is a subquery that returns a single row (consisting of a sequence of values). See Subquery .
-
table-subquery
is a subquery that returns a table (consisting of rows of columns). The table specifies rows of values to be compared with the row of values specified by the row-value-constructor. The number of values of the row-value-constructor must be equal to the number of columns in the result table of the table-subquery, and the data types of the values must be comparable.
-
in-value-list
is a sequence of SQL value expressions, separated by commas and enclosed in parentheses. expression cannot include an aggregate function defined on a column. expression can be a scalar subquery (a subquery that returns a single row consisting of a single column). In this case, the result of the row-value-constructor is a single value. The data types of the values must be comparable. The number of expressions in the in-value-list can have at least 5000 expressions.
Considerations for IN
Logical Equivalent Using ANY (or SOME)
The predicate expr IN (expr1, expr2, … ) is true if and only if the following predicate is true:
expr = ANY (expr1, expr2, ... )
IN Predicate Results
The IN predicate is true if and only if either of these is true:
-
The result of the row-value-constructor (a row or sequence of values) is equal to any row of column values specified by table-subquery.
A table subquery is a query expression and can be specified as a form of a simple table; for example, as the VALUES keyword followed by a list of row values. See SELECT Statement.
-
The result of the row-value-constructor (a single value) is equal to any of the values specified by the list of expressions in-value-list.
In this case, it is helpful to think of the list of expressions as a one-column table—a special case of a table subquery. The degree of the row value constructor and the degree of the list of expressions are both one.
Comparing Character Data
Two strings are equal if all characters in the same ordinal position are equal. Lowercase and uppercase letters are not considered equivalent. For comparisons between character strings of different lengths, the shorter string is padded on the right with spaces (HEX 20) until it is the length of the longer string. Both fixed-length and varying-length strings are padded in this way.
For example, Trafodion SQL considers the string ‘JOE’ equal to a value JOE stored in a column of data type CHAR or VARCHAR of width three or more. Similarly, Trafodion SQL considers a value JOE stored in any column of the CHAR data type equal to the value JOE stored in any column of the VARCHAR data type.
Comparing Numeric Data
Before evaluation, all numeric values in an expression are first converted to the maximum precision needed anywhere in the expression.
Comparing Interval Data
For comparisons of INTERVAL values, Trafodion SQL first converts the intervals to a common unit.
If no common unit exists, Trafodion SQL reports an error. Two INTERVAL values must be both year-month intervals or both day-time intervals.
Examples of IN
-
Find those employees whose EMPNUM is 39, 337, or 452:
SELECT last_name, first_name, empnum FROM persnl.employee WHERE empnum IN (39, 337, 452); LAST_NAME FIRST_NAME EMPNUM -------------------- --------------- ------ CLARK DINAH 337 SAFFERT KLAUS 39 --- 2 row(s) selected.
-
Find those items in PARTS whose part number is not in the PARTLOC table:
SELECT partnum, partdesc FROM sales.parts WHERE partnum NOT IN (SELECT partnum FROM invent.partloc); PARTNUM PARTDESC ------- ------------------ 186 186 MegaByte Disk --- 1 row(s) selected.
-
Find those items (and their suppliers) in PARTS that have a supplier in the PARTSUPP table:
SELECT P.partnum, P.partdesc, S.suppnum, S.suppname FROM sales.parts P, invent.supplier S WHERE P.partnum, S.suppnum IN (SELECT partnum, suppnum FROM invent.partsupp);
-
Find those employees in EMPLOYEE whose last name and job code match the list of last names and job codes:
SELECT empnum, last_name, first_name FROM persnl.employee WHERE (last_name, jobcode) IN (VALUES ('CLARK', 500), ('GREEN', 200));
5.15.5. LIKE Predicate
The LIKE predicate searches for character strings that match a pattern.
Syntax
match-value [NOT] LIKE pattern [ESCAPE esc-char-expression]
-
match-value
is a character value expression that specifies a set of strings to search for that match the pattern.
-
pattern
is a character value expression that specifies the pattern string for the search.
-
esc-char-expression
is a character value expression that must evaluate to a single character. The escape character value is used to turn off the special meaning of percent (%) and underscore (_). See Wild-Card Characters. [escape_characters].
Considerations
Comparing the Value to the Pattern
The values that you compare must be character strings. Lowercase and uppercase letters are not equivalent. To make lowercase letters match uppercase letters, use the UPSHIFT function. A blank is compared in the same way as any other character.
When a LIKE Predicate Is True
When you refer to a column, the LIKE predicate is true if the pattern matches the column value. If the value of the column reference is null, the LIKE predicate evaluates to unknown for that row.
If the values that you compare are both empty strings (that is, strings of zero length), the LIKE predicate is true.
Using NOT
If you specify NOT, the predicate is true if the pattern does not match any string in the match-value or is not the same length as any string in the match-value. For example, NAME NOT LIKE '_Z' is true if the string is not two characters long or the last character is not Z. In a search condition, the predicate NAME NOT LIKE '_Z' is equivalent to NOT (NAME LIKE '_Z').
Wild-Card Characters
You can look for similar values by specifying only part of the characters of pattern combined with these wild-card characters:
-
Percent Sign (%)
Use a percent sign to indicate zero or more characters of any type. For example, '%ART%' matches 'SMART', 'ARTIFICIAL', and 'PARTICULAR', but not 'smart'.
-
Underscore (_)
Use an underscore to indicate any single character. For example, 'BOO_' matches 'BOOK' and 'BOOT' but not 'BOO', 'BOOKLET', or 'book'.
-
Escape Characters
To search for a string containing a percent sign (%) or an underscore (), define an escape character, using ESCAPE _esc-char-expression, to turn off the special meaning of the percent sign and underscore.
To include a percent sign or an underscore in a comparison string, type the escape character immediately preceding the percent sign or underscore. For example, to locate the value 'A_B', type:
NAME LIKE 'A\_B' ESCAPE '\'
To include the escape character itself in the comparison string, type two escape characters. For example, to locate 'A_B\C%', type:
NAME LIKE 'A\_B\\C\%' ESCAPE '\'
The escape character must precede only the percent sign, underscore, or escape character itself. For example, the pattern RA\BS is an invalid LIKE pattern if the escape character is defined to be '\'. Error 8410 will be returned if this kind of pattern is used in an SQL query.
Comparing the Pattern to CHAR Columns
Columns of data type CHAR are fixed length. When a value is inserted into a CHAR column, Trafodion SQL pads the value in the column with blanks if necessary. The value 'JOE' inserted into a CHAR(4) column becomes 'JOE ' (three characters plus one blank). The LIKE predicate is true only if the column value and the comparison value are the same length. The column value 'JOE ' does not match 'JOE' but does match 'JOE%'.
Comparing the Pattern to VARCHAR Columns
Columns of variable-length character data types do not include trailing blanks unless blanks are specified when data is entered. For example, the value 'JOE' inserted in a VARCHAR(4) column is 'JOE' with no trailing blanks. The value matches both 'JOE' and 'JOE%'.
If you cannot locate a value in a variable-length character column, it might be because trailing blanks were specified when the value was inserted into the table. For example, a value of '5MB ' (with one trailing blank) will not be located by LIKE '%MB' but will be located by LIKE '%MB%'.
5.15.6. Examples
-
Find all employee last names beginning with ZE:
last_name LIKE 'ZE%'
-
Find all part descriptions that are not 'FLOPPY_DISK':
partdesc NOT LIKE 'FLOPPY\_DISK' ESCAPE '\'
The escape character indicates that the underscore in 'FLOPPY_DISK' is part of the string to search for, not a wild-card character.
5.15.7. NULL Predicate
The NULL predicate determines whether all the expressions in a sequence are null. See Null .
row-value-constructor IS [NOT] NULL
row-value-constructor is:
(expression [,expression]...)
| row-subquery
-
row-value-constructor
specifies the operand of the NULL predicate. The operand can be either of these:
(expression [,expression ]...)
is a sequence of SQL value expressions, separated by commas and enclosed in parentheses.
expression cannot include an aggregate function unless expression is in a HAVING clause. expression can be a scalar subquery (a subquery that returns a single row consisting of a single column). See Expressions.
-
row-subquery
is a subquery that returns a single row (consisting of a sequence of values). See Subquery .
If all of the expressions in the row-value-constructor are null, the IS NULL predicate is true. Otherwise, it is false. If none of the expressions in the row-value-constructor are null, the IS NOT NULL predicate is true. Otherwise, it is false.
Considerations for NULL
Summary of NULL Results
Let rvc be the value of the row-value-constructor. This table summarizes the results of NULL predicates. The degree of a rvc is the number of values in the rvc.
Expressions | rvc IS NULL | rvc IS NOT NULL | NOT rvc IS NULL | NOT rvc IS NOT NULL |
---|---|---|---|---|
degree 1: null |
TRUE |
FALSE |
FALSE |
TRUE |
degree 1: not null |
FALSE |
TRUE |
TRUE |
FALSE |
degree>1: all null |
TRUE |
FALSE |
FALSE |
TRUE |
degree>1: some null |
FALSE |
FALSE |
TRUE |
TRUE |
degree>1: none null |
FALSE |
TRUE |
TRUE |
FALSE |
The rvc IS NOT NULL predicate is not equivalent to NOT rvc IS NULL.
Examples of NULL
-
Find all rows with null in the SALARY column:
salary IS NULL
-
This predicate evaluates to true if the expression (PRICE + TAX) evaluates to null:
(price + tax) IS NULL
-
Find all rows where both FIRST_NAME and SALARY are null:
(first_name, salary) IS NULL
5.15.8. Quantified Comparison Predicates
A quantified comparison predicate compares the values of sequences of expressions to the values in each row selected by a table subquery. The comparison operation is quantified by the logical quantifiers ALL, ANY, or SOME.
row-value-constructor comparison-op quantifier table-subquery
row-value-constructor is:
(expression [,expression]...)
| row-subquery
comparison-op is:
= Equal
| <> Not equal
| != Not equal
| < Less than
| > Greater than
| <= Less than or equal to
| >= Greater than or equal to
quantifier is:
ALL | ANY | SOME
-
row-value-constructor
specifies the first operand of a quantified comparison predicate. The first operand can be either of:
-
(expression [,expression ]…)
is a sequence of SQL value expressions, separated by commas and enclosed in parentheses. expression cannot include an aggregate function unless expression is in a HAVING clause. expression can be a scalar subquery (a subquery that returns a single row consisting of a single column). See Expressions.
-
row-subquery
is a subquery that returns a single row (consisting of a sequence of values). See Subquery .
-
-
ALL
specifies that the predicate is true if the comparison is true for every row selected by
table-subquery (or if table-subquery selects no rows), and specifies that the predicate is false if the comparison is false for at least one row selected.
-
ANY | SOME
specifies that the predicate is true if the comparison is true for at least one row selected by the table-subquery and specifies that the predicate is false if the comparison is false for every row selected (or if table-subquery selects no rows).
-
table-subquery
provides the values for the comparison. The number of values returned by the row-value-constructor must be equal to the number of values specified by the table-subquery, and the data types of values returned by the row-value-constructor must be comparable to the data types of values returned by the table-subquery. See “Subquery” .
Considerations for ALL, ANY, SOME
Let R be the result of the row-value-constructor, T the result of the table-subquery, and RT a row in T.
Result of Rcomparison-op ALL T
If T is empty or if R comparison-op RT is true for every row RT in T, the comparison-op ALL predicate is true.
If R comparison-op RT is false for at least one row RT in T, the comparison-op ALL predicate is false.
Result of Rcomparison-op ANY T or Rcomparison-op SOME T
If T is empty or if R comparison-op RT is false for every row RT in T, the comparison-op ANY predicate is false.
If R comparison-op RT is true for at least one row RT in T, the comparison-op ANY predicate is true.
Examples of ALL, ANY, SOME
-
This predicate is true if the salary is greater than the salaries of all the employees who have a jobcode of 420:
salary > ALL (SELECT salary FROM persnl.employee WHERE jobcode = 420)
Consider this SELECT statement using the preceding predicate:
SELECT empnum, first_name, last_name, salary FROM persnl.employee WHERE salary > ALL (SELECT salary FROM persnl.employee WHERE jobcode = 420);
The inner query providing the comparison values yields these results:
SELECT salary FROM persnl.employee WHERE jobcode = 420; SALARY ----------- 33000.00 36000.00 18000.10 --- 3 row(s) selected.
The SELECT statement using this inner query yields these results. The salaries listed are greater than the salary of every employees with jobcode equal to 420—that is, greater than $33,000.00, $36,000.00, and $18,000.10:
SELECT empnum, first_name, last_name, salary FROM persnl.employee WHERE salary > ALL (SELECT salary FROM persnl.employee WHERE jobcode = 420); FIRST_NAME LAST_NAME SALARY --------------- -------------------- ----------- ROGER GREEN 175500.00 JERRY HOWARD 137000.10 JANE RAYMOND 136000.00 ... ALAN TERRY 39500.00 BEN HENDERSON 65000.00 JESSICA CRINER 39500.00 --- 23 row(s) selected.
-
This predicate is true if the part number is equal to any part number with more than five units in stock:
partnum = ANY (SELECT partnum FROM sales.odetail WHERE qty_ordered > 5)
Consider this SELECT statement using the preceding predicate:
SELECT ordernum, partnum, qty_ordered FROM sales.odetail WHERE partnum = ANY (SELECT partnum FROM sales.odetail WHERE qty_ordered > 5);
The inner query providing the comparison values yields these results:
SELECT partnum FROM sales.odetail WHERE qty_ordered > 5; Part/Num -------- 2403 5100 5103 6301 6500 .... --- 60 row(s) selected.
The SELECT statement using this inner query yields these results. All of the order numbers listed have part number equal to any part number with more than five total units in stock—that is, equal to 2403, 5100, 5103, 6301, 6500, and so on:
SELECT ordernum, partnum, qty_ordered FROM sales.odetail WHERE partnum = ANY (SELECT partnum FROM sales.odetail WHERE qty_ordered > 5); Order/Num Part/Num Qty/Ord ---------- -------- ---------- 100210 244 3 100210 2001 3 100210 2403 6 100210 5100 10 100250 244 4 100250 5103 10 100250 6301 15 100250 6500 10 ...... .... .. --- 71 row(s) selected.
5.16. Privileges
A privilege provides authorization to perform a specific operation for a specific object. A privilege can be granted to or revoked from a user or role in many ways:
-
Implicit privileges are granted to an owner of an object when the object is created. The owner retains implicit privileges for the lifespan of the object.
-
Explicit privileges can be granted to or revoked from a user or role. Explicit privileges can be granted or revoked by a database user administrator, an object owner, or a user who has been granted the privilege with the WITH GRANT OPTION option.
-
The privileges granted to a user can come from various sources. Privileges can be directly granted to a user or they can be inherited through a role. For example, a user gets the SELECT privilege on table T1 from two different roles. If one of the roles is revoked from the user, the user will still be able to select from T1 via the SELECT privilege granted to the remaining role.
-
A user who is granted a role is thereby conferred all privileges of the role. The only way to revoke any such privilege is to revoke the role from the user. For more information, see Roles .
You can manage privileges by using the GRANT and REVOKE statements.
For more information on GRANT, see:
For more information on REVOKE, see:
5.17. Roles
A role offers the flexibility of implicitly assigning a set of privileges to users, instead of assigning privileges individually. A user can be granted one or more roles. A role can be granted to one or more users. A role can be granted by or revoked by a database user administrator, a role owner, or a member of the role.
Privileges are granted to a role. When a role is granted to a user, the privileges granted to the role become available to the user. If new privileges are granted to the role, those privileges become available to all users who have been granted the role. When a role is revoked from a user, the privileges granted to the role are no longer available to the user. The change in privileges is automatically propagated to and detected by active sessions, so there is no need for users to disconnect from and reconnect to a session to see the updated set of privileges. For more information about privileges, see Privileges.
A role name is an authorization ID. A role name cannot be identical to a registered database user name. For more information, see Authorization IDs.
To manage roles, see these SQL statements:
5.18. Schemas
The ANSI SQL:1999 schema name is an SQL identifier that is unique for a given ANSI catalog name. Trafodion SQL automatically qualifies the schema name with the current default catalog name, TRAFODION.
The logical name of the form schema.object is an ANSI name. The part schema denotes the ANSI-defined schema.
To be compliant with ANSI SQL:1999, Trafodion SQL provides support for ANSI object names.
By using these names, you can develop ANSI-compliant applications that access all SQL objects. You can access Trafodion SQL objects with the name of the actual object. See SET SCHEMA Statement.
5.18.1. Creating and Dropping Schemas
You create a schema using the CREATE SCHEMA command and drop a schema using the DROP SCHEMA statement. For more information, see the CREATE SCHEMA Statement and the DROP SCHEMA Statement.
5.19. Search Condition
A search condition is used to choose rows from tables or views, depending on the result of applying the condition to rows. The condition is a Boolean expression consisting of predicates combined together with OR, AND, and NOT operators.
You can use a search condition in the WHERE clause of a SELECT, DELETE, or UPDATE statement, the HAVING clause of a SELECT statement, the searched form of a CASE expression, the ON clause of a SELECT statement that involves a join, a CHECK constraint, or a ROWS SINCE sequence function.
search-condition is:
boolean-term | search-condition OR boolean-term
boolean-term is:
boolean-factor | boolean-term AND boolean-factor
boolean-factor is:
[NOT] boolean-primary
boolean-primary is:
predicate | (search-condition)
-
OR
specifies the resulting search condition is true if and only if either of the surrounding predicates or search conditions is true.
-
AND
specifies the resulting search condition is true if and only if both the surrounding predicates or search conditions are true.
-
NOT
reverses the truth value of its operand—the following predicate or search condition. predicate is a BETWEEN, comparison, EXISTS, IN, LIKE, NULL, or quantified comparison predicate. A predicate specifies conditions that must be satisfied for a row to be chosen. See Predicates and individual entries.
5.19.1. Considerations for Search Condition
Order of Evaluation
SQL evaluates search conditions in this order:
-
Predicates within parentheses
-
NOT
-
AND
-
OR
Column References
Within a search condition, a reference to a column refers to the value of that column in the row currently being evaluated by the search condition.
Subqueries
If a search condition includes a subquery and the subquery returns no values, the predicate evaluates to null. See Subquery.
5.19.2. Examples of Search Condition
-
Select rows by using a search condition composed of three comparison predicates joined by AND operators:
SELECT O.ordernum, O.deliv_date, OD.qty_ordered FROM sales.orders O, sales.odetail OD WHERE qty_ordered < 9 AND deliv_date <= DATE '2008-11-01' AND O.ordernum = OD.ordernum; ORDERNUM DELIV_DATE QTY_ORDERED ---------- ---------- ----------- 100210 2008-04-10 3 100210 2008-04-10 3 100210 2008-04-10 6 100250 2008-06-15 4 101220 2008-12-15 3 ... --- 28 row(s) selected.
-
Select rows by using a search condition composed of three comparison predicates, two of which are joined by an OR operator (within parentheses), and where the result of the OR and the first comparison predicate are joined by an AND operator:
SELECT partnum, S.suppnum, suppname FROM invent.supplier S, invent.partsupp PS WHERE S.suppnum = PS.suppnum AND (partnum < 3000 OR partnum = 7102); SUPPNAME ------------------ NEW COMPUTERS INC NEW COMPUTERS INC NEW COMPUTERS INC ... LEVERAGE INC --- 18 row(s) selected.
5.20. Subquery
A subquery is a query expression enclosed in parentheses. Its syntactic form is specified in the syntax of a SELECT statement. For further information about query expressions, see SELECT Statement.
A subquery is used to provide values for a BETWEEN, comparison, EXISTS, IN, or quantified comparison predicate in a search condition. It is also used to specify a derived table in the FROM clause of a SELECT statement.
A subquery can be a table, row, or scalar subquery. Therefore, its result table can be a table consisting of multiple rows and columns, a single row of column values, or a single row consisting of only one column value.
5.20.1. SELECT Form of a Subquery
A subquery is typically specified as a special form of a SELECT statement enclosed in parentheses that queries (or selects) to provide values in a search condition or to specify a derived table as a table reference.
The form of a subquery specified as a SELECT statement is query-expr.
Neither the ORDER BY clause nor [FIRST N] / [ANY N] clause is allowed in a subquery.
5.20.2. Using Subqueries to Provide Comparison Values
When a subquery is used to provide comparison values, the SELECT statement that contains the subquery is called an outer query. The subquery within the SELECT is called an inner query.
In this case, the differences between the SELECT statement and the SELECT form of a subquery are:
-
A subquery is always enclosed in parentheses.
-
A subquery cannot contain an ORDER BY clause.
-
If a subquery is not part of an EXISTS, IN, or quantified comparison predicate, and the subquery evaluates to more than one row, a run-time error occurs.
5.20.3. Nested Subqueries When Providing Comparison Values
An outer query (a main SELECT statement) can have nested subqueries. Subqueries within the same WHERE or HAVING clause are at the same level. For example, this query has one level of nesting:
SELECT * FROM table1
WHERE A = (SELECT P FROM table2 WHERE q = 1)
AND b = (SELECT x FROM table3 WHERE y = 2);
A subquery within the WHERE clause of another subquery is at a different level, however, so this query has two levels of nesting:
SELECT * FROM table1
WHERE a = (SELECT p FROM table2
WHERE q = (SELECT x FROM table3
WHERE y = 2))
The maximum level of nested subqueries might depend on:
-
The complexity of the subqueries.
-
Whether the subquery is correlated and if so, whether it can be un-nested.
-
Amount of available memory.
Other factors may affect the maximum level of subqueries.
5.20.4. Correlated Subqueries When Providing Comparison Values
In a subquery, when you refer to columns of any table or view defined in an outer query, the reference is called an outer reference. A subquery containing an outer reference is called a correlated subquery.
If you refer to a column name that occurs in more than one outer query, you must qualify the column name with the correlation name of the table or view to which it belongs. Similarly, if you refer to
a column name that occurs in the subquery and in one or more outer queries, you must qualify the column name with the correlation name of the table or view to which it belongs. The correlation name is known to other subqueries at the same level, or to inner queries but not to outer queries.
If you use the same correlation name at different levels of nesting, an inner query uses the one from the nearest outer level.
5.21. Tables
A table is a logical representation of data in which a set of records is represented as a sequence of rows, and the set of fields common to all rows is represented by columns. A column is a set of values of the same data type with the same definition. The intersection of a row and column represents the data value of a particular field in a particular record.
Every table must have one or more columns, but the number of rows can be zero. No inherent order of rows exists within a table.
You create a Trafodion SQL user table by using the CREATE TABLE statement. See the CREATE TABLE Statement. The definition of a user table within the statement includes this information:
-
Name of the table
-
Name of each column of the table
-
Type of data you can store in each column of the table
-
Other information about the table, including the physical characteristics of the file that stores the table (for example, the storage order of rows within the table)
A Trafodion SQL table is described in an SQL schema and stored as an HBase table. Trafodion SQL tables have regular ANSI names in the catalog TRAFODION. A Trafodion SQL table name can be a fully qualified ANSI name of the form TRAFODION.schema-name.object-name. A Trafodion SQL table’s metadata is stored in the schema TRAFODION."MD".
Because Trafodion defines the encodings for column values in Trafodion SQL tables, those tables support various Trafodion SQL statements. See Supported SQL Statements With HBase Tables.
Internally, Trafodion SQL tables use a single HBase column family and shortened column names to conserve space. Their encoding allows keys consisting of multiple columns and preserves the order of key values as defined by SQL. The underlying HBase column model makes it very easy to add and remove columns from Trafodion SQL tables. HBase columns that are not recorded in the Trafodion metadata are ignored, and missing columns are considered NULL values.
5.21.1. Base Tables and Views
In some descriptions of SQL, tables created with a CREATE TABLE statement are called base tables to distinguish them from views, which are called logical tables.
A view is a named logical table defined by a query specification that uses one or more base tables or other views. See Views.
5.21.2. Example of a Base Table
For example, this EMPLOYEE table is a base table in a sample database:
EMPNUM | FIRST_NAME | LAST_NAME | DEPTNUM | JOBCODE | SALARY |
---|---|---|---|---|---|
1 |
ROGER |
GREEN |
9000 |
100 |
175500.00 |
23 |
JERRY |
HOWARD |
1000 |
100 |
137000.00 |
75 |
TIM |
WALKER |
3000 |
300 |
32000.00 |
. . . |
. . . |
. . . |
. . . |
. . . |
. . . |
In this sample table, the columns are EMPNUM, FIRST_NAME, LAST_NAME, DEPTNUM, JOBCODE, and SALARY. The values in each column have the same data type.
5.22. Views
A view provides an alternate way of looking at data in one or more tables. A view is a named specification of a result table, which is a set of rows selected or generated from one or more base tables or other views. The specification is a SELECT statement that is executed whenever the view is referenced.
A view is a logical table created with the CREATE VIEW statement and derived by projecting a subset of columns, restricting a subset of rows, or both, from one or more base tables or other views.
5.22.1. SQL Views
A view’s name must be unique among table and view names within the schema that contains it. Single table views can be updatable. Multi-table views are not updatable.
For information about SQL views, see CREATE VIEW Statement and DROP VIEW Statement.
5.22.2. Example of a View
You can define a view to show only part of the data in a table. For example, this EMPLIST view is defined as part of the EMPLOYEE table:
EMPNUM | FIRST_NAME | LAST_NAME | DEPTNUM | JOBCODE |
---|---|---|---|---|
1 |
ROGER |
GREEN |
9000 |
100 |
23 |
JERRY |
HOWARD |
1000 |
100 |
75 |
TIM |
WALKER |
3000 |
300 |
. . . |
. . . |
. . . |
. . . |
. . . |
In this sample view, the columns are EMPNUM, FIRST_NAME, LAST_NAME, DEPTNUM, and JOBCODE. The SALARY column in the EMPLOYEE table is not part of the EMPLIST view.
6. SQL Clauses
Clauses are used by Trafodion SQL statements to specify default values, ways to sample or sort data, how to store physical data, and other details.
This section describes:
-
DEFAULT Clause specifies a default value for a column being created.
-
FORMAT Clause specifies the format to use.
-
SAMPLE Clause specifies the sampling method used to select a subset of the intermediate result table of a SELECT statement.
-
SEQUENCE BY Clause specifies the order in which to sort rows of the intermediate result table for calculating sequence functions.
-
TRANSPOSE Clause generates, for each row of the SELECT source table, a row for each item in the transpose item list.
6.1. DEFAULT Clause
The DEFAULT option of the CREATE TABLE or ALTER TABLE table-name ADD COLUMN statement specifies a default value for a column being created.
The default value is used when a row is inserted in the table without a value for the column.
DEFAULT default | NO DEFAULT
default is:
literal
| NULL
| CURRENTDATE
| CURRENTTIME
| CURRENTTIMESTAMP
-
NO DEFAULT
specifies the column has no default value. You cannot specify NO DEFAULT in an ALTER TABLE statement. See ALTER TABLE Statement.
6.1.1. Syntax for Default Clause
-
DEFAULT literal
is a literal of a data type compatible with the data type of the associated column.
For a character column, literal must be a string literal of no more than 240 characters or the length of the column, whichever is less. The maximum length of a default value for a character column is 240 bytes (minus control characters) or the length of the column, whichever is less. Control characters consist of character set prefixes and single quote delimiter found in the text itself.
For a numeric column, literal must be a numeric literal that does not exceed the defined length of the column. The number of digits to the right of the decimal point must not exceed the scale of the column, and the number of digits to the left of the decimal point must not exceed the number in the length (or length minus scale, if you specified scale for the column).
For a datetime column, literal must be a datetime literal with a precision that matches the precision of the column.
For an INTERVAL column, literal must be an INTERVAL literal that has the range of INTERVAL fields defined for the column.
-
DEFAULT NULL
specifies NULL as the default. This default can occur only with a column that allows null.
-
DEFAULT CURRENT_DATE
specifies the default value for the column as the value returned by the CURRENT_DATE function at the time of the operation that assigns a value to the column. This default can occur only with a column whose data type is DATE.
-
DEFAULT CURRENT_TIME
specifies the default value for the column as the value returned by the CURRENT_TIME function at the time of the operation that assigns a value to the column. This default can occur only with a column whose data type is TIME.
-
DEFAULT CURRENT_TIMESTAMP
specifies the default value for the column as the value returned by the CURRENT_TIMESTAMP function at the time of the operation that assigns a value to the column. This default can occur only with a column whose data type is TIMESTAMP.
6.1.2. Examples of DEFAULT
-
This example uses DEFAULT clauses on CREATE TABLE to specify default column values:
CREATE TABLE items ( item_id CHAR(12) NO DEFAULT , description CHAR(50) DEFAULT NULL , num_on_hand INTEGER DEFAULT 0 NOT NULL ) ;
-
This example uses DEFAULT clauses on CREATE TABLE to specify default column values:
CREATE TABLE persnl.project ( projcode NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL , empnum NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL , projdesc VARCHAR (18) DEFAULT NULL , start_date DATE DEFAULT CURRENT_DATE , ship_timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP , est_complete INTERVAL DAY DEFAULT INTERVAL '30' DAY , PRIMARY KEY (projcode) ) ;
6.2. FORMAT Clause
The FORMAT clause specifies the output format for DATE values. It can also be used to specify the length of character output or to specify separating the digits of integer output with colons.
-
Date Formats:
(FORMAT 'format-string') | (DATE, FORMAT 'format-string') format-string for Date Formats is: YYYY-MM-DD MM/DD/YYYY YY/MM/DD YYYY/MM/DD YYYYMMDD DD.MM.YYYY DD-MM-YYYY DD-MMM-YYYY
-
Other Formats:
(FORMAT 'format-string') format-string for other formats is: XXX 99:99:99:99 -99:99:99:99
-
YYYY-MM-DD
specifies that the FORMAT clause output format is year-month-day.
-
MM/DD/YYYY
specifies that the FORMAT clause output format is month/day/year
-
YY/MM/DD
specifies that the FORMAT clause output format is year/month/day.
-
YYYY/MM/DD
specifies that the FORMAT clause output format is year/month/day.
-
YYYYMMDD
specifies that the FORMAT clause output format is yearmonthday.
-
DD.MM.YYYY
specifies that the FORMAT clause output format is day.month.year.
-
DD-MM-YYYY
specifies that the FORMAT clause output format is day-month-year.
-
DD-MMM-YYYY
specifies that the FORMAT clause output format is day-month-year.
-
XXX
specifies that the FORMAT clause output format is a string format. The input must be a numeric or string value.
-
99:99:99:99
specifies that the FORMAT clause output format is a timestamp. The input must be a numeric value.
-
-99:99:99:99
specifies that the FORMAT clause output format is a timestamp. The input must be a numeric value.
6.2.1. Considerations for Date Formats
The expression preceding the (FORMAT ”format-string') clause must be a DATE value.
The expression preceding the (DATE, FORMAT 'format-string') clause must be a quoted string in the USA, EUROPEAN, or DEFAULT date format.
Considerations for Other Formats
For XXX, the expression preceding the (FORMAT 'format-string') clause must be a numeric value or a string value.
For 99:99:99:99 and -99:99:99:99, the expression preceding the (FORMAT 'format-string') clause must be a numeric value.
6.2.2. Examples of FORMAT
-
The format string 'XXX' in this example will yield a sample result of abc:
SELECT 'abcde' (FORMAT 'XXX') FROM (VALUES(1)) t;
-
The format string 'YYYY-MM_DD' in this example will yield a sample result of 2008-07-17.
SELECT CAST('2008-07-17' AS DATE) (FORMAT 'YYYY-MM-DD') FROM (VALUES(1)) t;
-
The format string 'MM/DD/YYYY' in this example will yield a sample result of 07/17/2008.
SELECT '2008-07-17' (DATE, FORMAT 'MM/DD/YYYY') FROM (VALUES(1)) t;
-
The format string 'YY/MM/DD' in this example will yield a sample result of 08/07/17.
SELECT '2008-07-17'(DATE, FORMAT 'YY/MM/DD') FROM (VALUES(1)) t;
-
The format string 'YYYY/MM/DD' in this example will yield a sample result of 2008/07/17.
SELECT '2008-07-17' (DATE, FORMAT 'YYYY/MM/DD') FROM (VALUES(1)) t;
-
The format string 'YYYYMMDD' in this example will yield a sample result`of 20080717.
SELECT '2008-07-17' (DATE, FORMAT 'YYYYMMDD') FROM (VALUES(1)) t;
-
The format string 'DD.MM.YYYY' in this example will yield a sample result of 17.07.2008.
SELECT '2008-07-17' (DATE, FORMAT 'DD.MM.YYYY') FROM (VALUES(1)) t;
-
The format string 'DD-MMM-YYYY' in this example will yield a sample result of 17–JUL-2008.
SELECT '2008-07-17' (DATE, FORMAT 'DD-MMM-YYYY') FROM (VALUES(1)) t;
-
The format string '99:99:99:99' in this example will yield a sample result of 12:34:56:78.
SELECT 12345678 (FORMAT '99:99:99:99') FROM (VALUES(1)) t;
-
The format string '-99:99:99:99' in this example will yield a sample result of -12:34:56:78.
SELECT (-12345678) (FORMAT '-99:99:99:99') FROM (VALUES(1)) t;
6.3. SAMPLE Clause
The SAMPLE clause of the SELECT statement specifies the sampling method used to select a subset of the intermediate result table of a SELECT statement. The intermediate result table consists of the rows returned by a WHERE clause or, if no WHERE clause exists, the FROM clause. See SELECT Statement.
SAMPLE is a Trafodion SQL extension.
SAMPLE sampling-methodis:
RANDOM percent-size
| FIRST rows-size
[SORT BY colname [ASC[ENDING]|DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...]
| PERIODIC rows-size EVERY number-rows ROWS
[SORT BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...]
percent-size is:
percent-result PERCENT [ROWS]
| BALANCE WHEN condition
THEN percent-result PERCENT [ROWS]
[WHEN condition THEN percent-result PERCENT [ROWS]]...
[ELSE percent-result PERCENT [ROWS]] END
rows-size is:
number-rows ROWS
| BALANCE WHEN condition THEN number-rows ROWS
[WHEN condition THEN number-rows ROWS]...
[ELSE number-rows ROWS] END
-
RANDOM percent-size
directs Trafodion SQL to choose rows randomly (each row having an unbiased probability of being chosen) without replacement from the result table. The sampling size is determined by the percent-size, defined as:
-
percent-result PERCENT [ROWS] | BALANCE WHEN condition THEN percent-result PERCENT [ROWS] [WHEN condition THEN percent-result PERCENT [ROWS]]… [ELSE percent-result PERCENT [ROWS]] END
specifies the value of the size for RANDOM sampling by using a percent of the result table. The value percent-result must be a numeric literal.
You can determine the actual size of the sample. Suppose that N rows exist in the intermediate result table. Each row is picked with a probability of r%, where r is the sample size in PERCENT. Therefore, the actual size of the resulting sample is approximately r% of N. The number of rows picked follows a binomial distribution with mean equal to r *c_N_/100.
If you specify a sample size greater than 100 PERCENT, Trafodion SQL returns all the rows in the result table plus duplicate rows. The duplicate rows are picked from the result table according to the specified sampling method. This technique is called oversampling.
-
ROWS
specifies row sampling. Row sampling is the default.
-
BALANCE
If you specify a BALANCE expression, Trafodion SQL performs stratified sampling. The intermediate result table is divided into disjoint strata based on the WHEN conditions.
Each stratum is sampled independently by using the sampling size. For a given row, the stratum to which it belongs is determined by the first WHEN condition that is true for that row—if a true condition exists. If no true condition exists, the row belongs to the ELSE stratum.
-
-
FIRST rows-size [SORT BY colname [ASC[ENDING] | DESC[ENDING]] [,colname [ASC[ENDING] | DESC[ENDING]]]…]
directs Trafodion SQL to choose the first rows from the result table. You can specify the order of the rows to sample. Otherwise, Trafodion SQL chooses an arbitrary order. The sampling size is determined by the rows-size, defined as:
-
number-rows ROWS | BALANCE WHEN condition THEN number-rows ROWS [WHEN condition THEN number-rows ROWS]… [ELSE number-rows ROWS] END
specifies the value of the size for FIRST sampling by using the number of rows intended in the sample. The value number-rows must be an integer literal.
You can determine the actual size of the sample. Suppose that N rows exist in the intermediate result table. If the size s of the sample is specified as a number of rows, the actual size of the resulting sample is the minimum of s and N.
-
PERIODIC rows-size EVERY number-rows ROWS [SORT BY colname [ASC[ENDING] | DESC[ENDING]] [,colname [ASC[ENDING] | DESC[ENDING]]]…]
directs Trafodion SQL to choose the first rows from each block (or period) of contiguous rows. This sampling method is equivalent to a separate FIRST sampling for each period, and the rows-size is defined as in FIRST sampling.
The size of the period is specified as a number of rows. You can specify the order of the rows to sample. Otherwise, Trafodion SQL chooses an arbitrary order.
You can determine the actual size of the sample. Suppose that N rows exist in the intermediate result table. If the size s of the sample is specified as a number of rows and the size p of the period is specified as a number of rows, the actual size of the resulting sample is calculated as:
FLOOR (N/p) * s + _minimum_ (MOD (N, p), s)
minimum in this expression is used simply as the mathematical minimum of two values.
6.3.1. Considerations for SAMPLE
Sample Rows
In general, when you use the SAMPLE clause, the same query returns different sets of rows for each execution. The same set of rows is returned only when you use the FIRST and PERIODIC sampling methods with the SORT BY option, where no duplicates exist in the specified column combination for the sort.
6.3.2. Examples of SAMPLE
-
Suppose that the data-mining tables SALESPER, SALES, and DEPT have been created as:
CREATE TABLE trafodion.mining.salesper ( empid NUMERIC (4) UNSIGNED NOT NULL , dnum NUMERIC (4) UNSIGNED NOT NULL , salary NUMERIC (8,2) UNSIGNED , age INTEGER , sex CHAR (6) , PRIMARY KEY (empid) ); CREATE TABLE trafodion.mining.sales ( empid NUMERIC (4) UNSIGNED NOT NULL , product VARCHAR (20) , region CHAR (4) , amount NUMERIC (9,2) UNSIGNED , PRIMARY KEY (empid) ); CREATE TABLE trafodion.mining.dept ( dnum NUMERIC (4) UNSIGNED NOT NULL , name VARCHAR (20) , PRIMARY KEY (dnum) );
Suppose, too, that sample data is inserted into this database.
-
Return the SALARY of the youngest 50 sales people:
SELECT salary FROM salesperson SAMPLE FIRST 50 ROWS SORT BY age; SALARY ----------- 90000.00 90000.00 28000.00 27000.12 136000.00 37000.40 ... --- 50 row(s) selected.
-
Return the SALARY of 50 sales people. In this case, the table is clustered on EMPID. If the optimizer chooses a plan to access rows using the primary access path, the result consists of salaries of the 50 sales people with the smallest employee identifiers.
SELECT salary FROM salesperson SAMPLE FIRST 50 ROWS; SALARY ----------- 175500.00 137000.10 136000.00 138000.40 75000.00 90000.00 ... --- 50 row(s) selected.
-
Return the SALARY of the youngest five sales people, skip the next 15 rows, and repeat this process until no more rows exist in the intermediate result table. You cannot specify periodic sampling with the sample size larger than the period.
SELECT salary FROM salesperson SAMPLE PERIODIC 5 ROWS EVERY 20 ROWS SORT BY age; SALARY ----------- 90000.00 90000.00 28000.00 27000.12 136000.00 36000.00 ... --- 17 row(s) selected.
In this example, 62 rows exist in the SALESPERSON table. For each set of 20 rows, the first five rows are selected. The last set consists of two rows, both of which are selected.
-
Compute the average salary of a random 10 percent of the sales people. You will get a different result each time you run this query because it is based on a random sample.
SELECT AVG(salary) FROM salesperson SAMPLE RANDOM 10 PERCENT; (EXPR) -------------------- 61928.57 --- 1 row(s) selected.
-
This query illustrates sampling after execution of the WHERE clause has chosen the qualifying rows. The query computes the average salary of a random 10 percent of the sales people over 35 years of age. You will get a different result each time you run this query because it is based on a random sample.
SELECT AVG(salary) FROM salesperson WHERE age > 35 SAMPLE RANDOM 10 PERCENT; (EXPR) -------------------- 58000.00 --- 1 row(s) selected.
-
Compute the average salary of a random 10 percent of sales people belonging to the CORPORATE department. The sample is taken from the join of the SALESPERSON and DEPARTMENT tables. You will get a different result each time you run this query because it is based on a random sample.
SELECT AVG(salary) FROM salesperson S, department D WHERE S.DNUM = D.DNUM AND D.NAME = 'CORPORATE' SAMPLE RANDOM 10 PERCENT; (EXPR) --------------------- 106250.000 --- 1 row(s) selected.
-
In this example, the SALESPERSON table is first sampled and then joined with the DEPARTMENT table. This query computes the average salary of all the sales people belonging to the CORPORATE department in a random sample of 10 percent of the sales employees.
SELECT AVG(salary) FROM ( SELECT salary, dnum FROM salesperson SAMPLE RANDOM 10 PERCENT ) AS S , department D WHERE S.DNUM = D.DNUM AND D.NAME = 'CORPORATE'; (EXPR) -------------------- 37000.000 --- 1 row(s) selected.
The results of this query and some of the results of previous queries might return null:
SELECT AVG(salary) FROM ( SELECT salary, dnum FROM salesperson SAMPLE RANDOM 10 PERCENT ) AS S , department D WHERE S.DNUM = D.DNUM AND D.NAME = 'CORPORATE'; (EXPR) -------------------- ? --- 1 row(s) selected.
For this query execution, the number of rows returned by the embedded query is limited by the total number of rows in the SALESPERSON table. Therefore, it is possible that no rows satisfy the search condition in the WHERE clause.
-
In this example, both the tables are sampled first and then joined. This query computes the average salary and the average sale amount generated from a random 10 percent of all the sales people and 20 percent of all the sales transactions.
SELECT AVG(salary), AVG(amount) FROM ( SELECT salary, empid FROM salesperson SAMPLE RANDOM 10 PERCENT ) AS S, ( SELECT amount, empid FROM sales SAMPLE RANDOM 20 PERCENT ) AS T WHERE S.empid = T.empid; (EXPR) (EXPR) --------- --------- 45000.00 31000.00 --- 1 row(s) selected.
-
This example illustrates oversampling. This query retrieves 150 percent of the sales transactions where the amount exceeds $1000. The result contains every row at least once, and 50 percent of the rows, picked randomly, occur twice.
SELECT * FROM sales WHERE amount > 1000 SAMPLE RANDOM 150 PERCENT; EMPID PRODUCT REGION AMOUNT ----- -------------------- ------ ----------- 1 PCGOLD, 30MB E 30000.00 23 PCDIAMOND, 60MB W 40000.00 23 PCDIAMOND, 60MB W 40000.00 29 GRAPHICPRINTER, M1 N 11000.00 32 GRAPHICPRINTER, M2 S 15000.00 32 GRAPHICPRINTER, M2 S 15000.00 ... ... ... ... --- 88 row(s) selected.
-
The BALANCE option enables stratified sampling. Retrieve the age and salary of 1000 sales people such that 50 percent of the result are male and 50 percent female.
SELECT age, sex, salary FROM salesperson SAMPLE FIRST BALANCE WHEN sex = 'male' THEN 15 ROWS WHEN sex = 'female' THEN 15 ROWS END ORDER BY age; + AGE SEX SALARY ----------- ------ ----------- 22 male 28000.00 22 male 90000.00 22 female 136000.00 22 male 37000.40 ... ... ... --- 30 row(s) selected.
-
Retrieve all sales records with the amount exceeding $10000 and a random sample of 10 percent of the remaining records:
SELECT * FROM sales SAMPLE RANDOM BALANCE WHEN amount > 10000 THEN 100 PERCENT ELSE 10 PERCENT END; PRODUCT REGION AMOUNT -------------------- ------ ----------- PCGOLD, 30MB E 30000.00 PCDIAMOND, 60MB W 40000.00 GRAPHICPRINTER, M1 N 11000.00 GRAPHICPRINTER, M2 S 15000.00 ... ... ... MONITORCOLOR, M2 N 10500.00 ... ... ... --- 32 row(s) selected.
-
This query shows an example of stratified sampling where the conditions are not mutually exclusive:
SELECT * FROM sales SAMPLE RANDOM BALANCE WHEN amount > 10000 THEN 100 PERCENT WHEN product = 'PCGOLD, 30MB' THEN 25 PERCENT WHEN region = 'W' THEN 40 PERCENT ELSE 10 PERCENT END; PRODUCT REGION AMOUNT -------------------- ------ ----------- PCGOLD, 30MB E 30000.00 PCDIAMOND, 60MB W 40000.00 GRAPHICPRINTER, M1 N 11000.00 GRAPHICPRINTER, M2 S 15000.00 GRAPHICPRINTER, M3 S 20000.00 LASERPRINTER, X1 W 42000.00 ... ... ... --- 30 row(s) selected.
6.4. SEQUENCE BY Clause
The SEQUENCE BY clause of the SELECT statement specifies the order in which to sort the rows
of the intermediate result table for calculating sequence functions. This option is used for processing time-sequenced rows in data mining applications. See SELECT Statement.
Sequence by is a Trafodion SQL extension.
SEQUENCE BY colname[ASC[ENDING]|DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...
-
colname
_ names a column in select-list or a column in a table reference in the FROM clause of the SELECT statement. colname is optionally qualified by a table, view, or correlation name; for example, CUSTOMER.CITY. -
ASC | DESC
specifies the sort order. ASC is the default. For ordering an intermediate result table on a column that can contain null, nulls are considered equal to one another but greater than all other non-null values.
You must include a SEQUENCE BY clause if you include a sequence function in the select list of the SELECT statement. Otherwise, Trafodion SQL returns an error. Further, you cannot include a SEQUENCE BY clause if no sequence function exists in the select list. See Sequence Functions .
6.4.1. Considerations for SEQUENCE BY
-
Sequence functions behave differently from set (or aggregate) functions and mathematical (or scalar) functions.
-
If you include both SEQUENCE BY and GROUP BY clauses in the same SELECT statement, the values of the sequence functions must be evaluated first and then become input for aggregate functions in the statement.
-
For a SELECT statement that contains both SEQUENCE BY and GROUP BY clauses, you can nest the sequence function in the aggregate function:
SELECT ordernum , MAX(MOVINGSUM(qty_ordered, 3)) AS maxmovsum_qty , AVG(unit_price) AS avg_price FROM odetail SEQUENCE BY partnum GROUP BY ordernum;
-
-
To use a sequence function as a grouping column, you must use a derived table for the SEQUENCE BY query and use the derived column in the GROUP BY clause:
SELECT ordernum , movsum_qty , AVG(unit_price) FROM ( SELECT ordernum, MOVINGSUM(qty_ordered, 3), unit_price FROM odetail SEQUENCE BY partnum ) AS tab2 (ordernum, movsum_qty, unit_price) GROUP BY ordernum, movsum_qty;
-
To use an aggregate function as the argument to a sequence function, you must also use a derived table:
SELECT MOVINGSUM(avg_price,2) FROM ( SELECT ordernum, AVG(unit_price) FROM odetail GROUP BY ordernum) AS tab2 (ordernum, avg_price) SEQUENCE BY ordernum;
-
Like aggregate functions, sequence functions generate an intermediate result. If the query has a WHERE clause, its search condition is applied during the generation of the intermediate result. Therefore, you cannot use sequence functions in the WHERE clause of a SELECT statement.
-
This query returns an error:
SELECT ordernum, partnum, RUNNINGAVG(unit_price) FROM odetail WHERE ordernum > 800000 AND RUNNINGAVG(unit_price) > 350 SEQUENCE BY qty_ordered;
-
Apply a search condition to the result of a sequence function, use a derived table for the SEQUENCE BY query, and use the derived column in the WHERE clause:
SELECT ordernum, partnum, runavg_price FROM ( SELECT ordernum, partnum, RUNNINGAVG(unit_price) FROM odetail SEQUENCE BY qty_ordered) AS tab2 (ordernum, partnum, runavg_price) WHERE ordernum > 800000 AND runavg_price > 350;
-
6.4.2. Examples of SEQUENCE BY
-
Sequentially number each row for the entire result and also number the rows for each part number:
SELECT RUNNINGCOUNT(*) AS RCOUNT , MOVINGCOUNT(*,ROWS SINCE (d.partnum<>THIS(d.partnum))) AS MCOUNT , d.partnum FROM orders o, odetail d WHERE o.ordernum=d.ordernum SEQUENCE BY d.partnum, o.order_date, o.ordernum ORDER BY d.partnum, o.order_date, o.ordernum; RCOUNT MCOUNT Part/Num -------------------- --------------------- -------- 1 1 212 2 2 212 3 1 244 4 2 244 5 3 244 ... ... ... 67 1 7301 68 2 7301 69 3 7301 70 4 7301 --- 70 row(s) selected.
-
Show the orders for each date, the amount for each order item and the moving total for each order, and the running total of all the orders. The query sequences orders by date, order number, and part number. (The CAST function is used for readability only.)
SELECT o.ordernum , CAST (MOVINGCOUNT(*,ROWS SINCE(THIS(o.ordernum) <> o.ordernum)) AS INT) AS MCOUNT , d.partnum , o.order_date , (d.unit_price * d.qty_ordered) AS AMOUNT , MOVINGSUM (d.unit_price * d.qty_ordered, SEQUENCE BY Clause 269 ROWS SINCE(THIS(o.ordernum)<>o.ordernum) ) AS ORDER_TOTAL , RUNNINGSUM (d.unit_price * d.qty_ordered) AS TOTAL_SALES FROM orders o, odetail d WHERE o.ordernum=d.ordernum SEQUENCE BY o.order_date, o.ordernum, d.partnum ORDER BY o.order_date, o.ordernum, d.partnum; Order/Num MCOUNT Part/Num Order/Date AMOUNT ORDER_TOTAL TOTAL_SALES ---------- ----------- -------- ---------- ---------- -------------- -------------- 100250 1 244 2008-01-23 14000.00 14000.00 14000.00 100250 2 5103 2008-01-23 4000.00 18000.00 18000.00 100250 3 6500 2008-01-23 950.00 18950.00 18950.00 200300 1 244 2008-02-06 28000.00 28000.00 46950.00 200300 2 2001 2008-02-06 10000.00 38000.00 56950.00 200300 3 2002 2008-02-06 14000.00 52000.00 70950.00 ... ... ... ... ... ... ... 800660 18 7102 2008-10-09 1650.00 187360.00 113295.00 800660 19 7301 2008-10-09 5100.00 192460.00 1118395.00 --- 69 row(s) selected.
For example, for order number 200300, the ORDER_TOTAL is a moving sum within the order date 2008-02-06, and the TOTAL_SALES is a running sum for all orders. The current window for the moving sum is defined as ROWS SINCE (THIS(o.ordernum)<>o.ordernum), which restricts the ORDER_TOTAL to the current order number.
-
Show the amount of time between orders by calculating the interval between two dates:
SELECT RUNNINGCOUNT(*),o.order_date,DIFF1(o.order_date) FROM orders o SEQUENCE BY o.order_date, o.ordernum ORDER BY o.order_date, o.ordernum ; (EXPR) Order/Date (EXPR) -------------------- ---------- ------------- 1 2008-01-23 ? 2 2008-02-06 14 3 2008-02-17 11 4 2008-03-03 14 5 2008-03-19 16 6 2008-03-19 0 7 2008-03-27 8 8 2008-04-10 14 9 2008-04-20 10 10 2008-05-12 22 11 2008-06-01 20 12 2008-07-21 50 13 2008-10-09 80 --- 13 row(s) selected.
6.5. TRANSPOSE Clause
The TRANSPOSE clause of the SELECT statement generates for each row of the SELECT source table a row for each item in the transpose item list. The result table of the TRANSPOSE clause has all the columns of the source table plus, for each transpose item list, a value column or columns and an optional key column.
TRANSPOSE is a Trafodion SQL extension.
TRANSPOSE transpose-set [transpose-set]...
[KEY BY key-colname]
transpose-set is:
transpose-item-list AS transpose-col-list
transpose-item-list is:
expression-list
| (expression-list) [,(expression-list)]...
expression-list is:
expression [,expression]...
transpose-col-list is:
colname | (colname-list)
colname-list is:
colname [,colname]...
-
transpose-item-list AS transpose-col-list
specifies a transpose-set, which correlates a transpose-item-list with a transpose-col-list. The transpose-item-list can be a list of expressions or a list of expression lists enclosed in parentheses. The transpose-col-list can be a single column name or a list of column names enclosed in parentheses.
For example, in the transpose-set TRANSPOSE (A,X),(B,Y),(C,Z) AS (V1,V2), the items in the transpose-item-list are (A,X),(B,Y), and (C,Z), and the transpose-col-list is (V1,V2). The number of expressions in each item must be the same as the number of value columns in the column list.
In the example TRANSPOSE A,B,C AS V, the items are A,B, and C, and the value column is V. This form can be thought of as a shorter way of writing TRANSPOSE (A),(B),© AS (V).
-
transpose-item-list
specifies a list of items. An item is a value expression or a list of value expressions enclosed in parentheses.
-
expression-list
specifies a list of SQL value expressions, separated by commas. The expressions must have compatible data types.
For example, in the transpose set TRANSPOSE A,B,C AS V, the expressions A,B, and C have compatible data types.
-
(expression-list) [,(expression-list)]&8230;
specifies a list of expressions enclosed in parentheses, followed by another list of expressions enclosed in parentheses, and so on. The number of expressions within parentheses must be equal for each list. The expressions in the same ordinal position within the parentheses must have compatible data types.
For example, in the transpose set TRANSPOSE (A,X),(B,Y),(C,Z) AS (V1,V2), the expressions A,B, and C have compatible data types, and the expressions X,Y, and Z have compatible data types.
-
-
transpose-col-list
specifies the columns that consist of the evaluation of expressions in the item list as the expressions are applied to rows of the source table.
-
colname
is an SQL identifier that specifies a column name. It identifies the column consisting of the values in expression-list.
For example, in the transpose set TRANSPOSE A,B,C AS V, the column V corresponds to the values of the expressions A,B, and C.
-
(colname-list)
specifies a list of column names enclosed in parentheses. Each column consists of the values of the expressions in the same ordinal position within the parentheses in the transpose item list.
For example, in the transpose set TRANSPOSE (A,X),(B,Y),(C,Z) AS (V1,V2), the column V1 corresponds to the expressions A,B, and C, and the column V2 corresponds to the expressions X,Y, and Z.
-
-
KEY BY key-colname
optionally specifies which expression (the value in the transpose column list corresponds to) by its position in the item list. key-colname is an SQL identifier. The data type of the key column is exact numeric, and the value is NOT NULL.
6.5.1. Considerations for TRANSPOSE
Multiple TRANSPOSE Clauses and Sets
-
Multiple TRANSPOSE clauses can be used in the same query. For example:
SELECT keycol1, valcol1, keycol2, valcol2 FROM mytable TRANSPOSE a, b, c AS valcol1 KEY BY keycol1 TRANSPOSE d, e, f AS valcol2 KEY BY keycol2
-
A TRANSPOSE clause can contain multiple transpose sets. For example:
SELECT keycol, valcol1, valcol2 FROM mytable TRANSPOSE a, b, c AS valcol1 d, e, f AS valcol2 KEY BY keycol
Degree and Column Order of the TRANSPOSE Result
The degree of the TRANSPOSE result is the degree of the source table (the result table derived from the table reference or references in the FROM clause and a WHERE clause if specified), plus one if the key column is specified, plus the cardinalities of all the transpose column lists.
The columns of the TRANSPOSE result are ordered beginning with the columns of the source table, followed by the key column if specified, and then followed by the list of column names in the order in which they are specified.
Data Type of the TRANSPOSE Result
The data type of each of the value columns is the union compatible data type of the corresponding expressions in the transpose-item-list. You cannot have expressions with data types that are not compatible in a transpose-item-list.
For example, in TRANSPOSE (A,X),(B,Y),(C,Z) AS (V1,V2), the data type of V1 is the union compatible type for A, B, and C, and the data type of V2 is the union compatible type for X, Y, and Z.
Cardinality of the TRANSPOSE Result
The items in each transpose-item-list are enumerated from 1 to N, where N is the total number of items in all the item lists in the transpose sets.
In this example with a single transpose set, the value of N is 3:
TRANSPOSE (a,x),(b,y),(c,z) AS (v1,v2)
In this example with two transpose sets, the value of N is 5:
TRANSPOSE (a,x),(b,y),(c,z) AS (v1,v2) l,m AS v3
The values 1 to N are the key values k_i. The items in each _transpose-item-list are the expression values _v_i.
The cardinality of the result of the TRANSPOSE clause is the cardinality of the source table times N, the total number of items in all the transpose item lists.
For each row of the source table and for each value in the key values _k_i, the TRANSPOSE result contains a row with all the attributes of the source table, the key value _k_i in the key column, the expression values vi in the value columns of the corresponding transpose set, and NULL in the value columns of other transpose sets.
For example, consider this TRANSPOSE clause:
TRANSPOSE (a,x),(b,y),(c,z) AS (v1,v2)
l,m AS v3
KEY BY k
The value of N is 5. One row of the SELECT source table produces this TRANSPOSE result:
columns-of-source | K | V1 | V2 | V3 |
---|---|---|---|---|
source-row |
1 |
value-of-A |
value-of-X |
NULL |
source-row |
2 |
value-of-B |
value-of-Y |
NULL |
source-row |
3 |
value-of-C |
value-of-Z |
NULL |
source-row |
4 |
NULL |
NULL |
value-of-L |
source-row |
5 |
NULL |
NULL |
value-of-M |
6.5.2. Examples of TRANSPOSE
-
Suppose that MYTABLE has been created as:
CREATE TABLE mining.mytable ( A INTEGER, B INTEGER, C INTEGER, D CHAR(2), E CHAR(2), F CHAR(2) );
The table MYTABLE has columns A, B, C, D, E, and F with related data. The columns A, B, and C are type INTEGER, and columns D, E, and F are type CHAR.
A B C D E F 1
10
100
d1
e1
f1
2
20
200
d2
e2
f2
-
Suppose that MYTABLE has only the first three columns: A, B, and C. The result of the TRANSPOSE clause has three times as many rows (because three items exist in the transpose item list) as rows exist in MYTABLE:
SELECT * FROM mytable TRANSPOSE a, b, c AS valcol KEY BY keycol;
The result table of the TRANSPOSE query is:
A B C D E F KEYCOL VALCOL 1
10
100
d1
e1
f1
1
1
1
10
100
d1
e1
f1
2
10
1
10
100
d1
e1
f1
3
100
2
20
200
d2
e2
f2
1
2
2
20
200
d2
e2
f2
2
20
2
20
200
d2
e2
f2
3
200
-
This query shows that the items in the transpose item list can be any valid scalar expressions:
SELECT keycol, valcol, a, b, c FROM mytable TRANSPOSE a + b, c + 3, 6 AS valcol KEY BY keycol;
The result table of the TRANSPOSE query is:
KEYCOL VALCOL A B C 1
1
1
10
100
2
103
1
10
100
3
6
1
10
100
1
22
2
20
200
2
203
2
20
200
3
6
2
20
200
-
This query shows how the TRANSPOSE clause can be used with a GROUP BY clause. This query is typical of queries used to obtain cross-table information, where A, B, and C are the independent variables, and D is the dependent variable.
SELECT keycol, valcol, d, COUNT(*) FROM mytable TRANSPOSE a, b, c AS valcol KEY BY keycol GROUP BY keycol, valcol, d;
The result table of the TRANSPOSE query is:
KEYCOL VALCOL D COUNT(*) 1
1
d1
1
2
10
d1
1
3
100
d1
1
1
2
d2
1
2
20
d2
1
3
200
d2
1
-
This query shows how to use COUNT applied to VALCOL. The result table of the TRANSPOSE query shows the number of distinct values in VALCOL.
SELECT COUNT(DISTINCT valcol) FROM mytable TRANSPOSE a, b, c AS valcol KEY BY keycol GROUP BY keycol; (EXPR) -------------------- 2 2 2 --- 3 row(s) selected.
-
This query shows how multiple TRANSPOSE clauses can be used in the same query. The result table from this query has nine times as many rows as rows exist in MYTABLE:
SELECT keycol1, valcol1, keycol2, valcol2 FROM mytable TRANSPOSE a, b, c AS valcol1 KEY BY keycol1 TRANSPOSE d, e, f AS valcol2 KEY BY keycol2;
The result table of the TRANSPOSE query is:
KEYCOL1 VALCOL1 KEYCOL2 VALCOL2 1
1
1
d1
1
1
2
e1
1
1
3
f1
2
10
1
d1
2
10
2
e1
2
10
3
f1
3
100
1
d1
3
100
2
e1
3
100
3
f1
1
2
1
d2
1
2
2
e2
1
2
3
f2
2
20
1
d2
2
20
2
e2
2
20
3
f2
3
200
1
d2
3
200
2
e2
3
200
3
f2
-
This query shows how a TRANSPOSE clause can contain multiple transpose sets—that is, multiple transpose-item-list AS transpose-col-list. The expressions A, B, and C are of type integer, and expressions D, E, and F are of type character.
SELECT keycol, valcol1, valcol2 FROM mytable TRANSPOSE a, b, c AS valcol1 d, e, f AS valcol2 KEY BY keycol;
The result table of the TRANSPOSE query is:
KEYCOL VALCOL1 VALCOL2 1
1
?
2
10
?
3
100
?
4
?
d1
5
?
e1
6
?
f1
1
2
?
2
20
?
3
200
?
4
?
d2
5
?
e2
6
?
f2
A question mark (?) in a value column indicates no value for the given KEYCOL.
-
This query shows how the preceding query can include a GROUP BY clause:
SELECT keycol, valcol1, valcol2, COUNT(*) FROM mytable TRANSPOSE a, b, c AS valcol1 d, e, f AS valcol2 KEY BY keycol GROUP BY keycol, valcol1, valcol2;
The result table of the TRANSPOSE query is:
KEYCOL VALCOL1 VALCOL2 (EXPR) 1
1
?
1
2
10
?
1
3
100
?
1
1
2
?
1
2
20
?
1
3
200
?
1
4
?
d2
1
5
?
e2
1
6
?
f2
1
4
?
d1
1
5
?
e1
1
6
?
f1
1
-
This query shows how an item in the transpose item list can contain a list of expressions and that the KEY BY clause is optional:
SELECT * FROM mytable TRANSPOSE (1, A, 'abc'), (2, B, 'xyz') AS (VALCOL1, VALCOL2, VALCOL3);
The result table of the TRANSPOSE query is:
A B C D E F VALCOL1 VALCOL2 VALCOL3 1
10
100
d1
e1
f1
1
1
abc
1
10
100
d1
e1
f1
2
10
xyz
2
20
200
d2
e2
f2
1
2
abc
2
20
200
d2
e2
f2
2
20
xyz
7. SQL Functions and Expressions
This section describes the syntax and semantics of specific functions and expressions that you can use in Trafodion SQL statements. The functions and expressions are categorized according to their functionality.
7.1. Standard Normalization
For datetime functions, the definition of standard normalization is: If the ending day of the resulting date is invalid, the day will be rounded DOWN to the last day of the result month.
7.2. Aggregate (Set) Functions
An aggregate (or set) function operates on a group or groups of rows retrieved by the SELECT statement or the subquery in which the aggregate function appears.
Computes the average of a group of numbers derived from the evaluation of the expression argument of the function. |
|
Counts the number of rows that result from a query (by using *) or the number of rows that contain a distinct value in the one-column table derived from the expression argument of the function (optionally distinct values). |
|
Determines a maximum value from the group of values derived from the evaluation of the expression argument. |
|
Determines a minimum value from the group of values derived from the evaluation of the expression argument. |
|
Computes the statistical standard deviation of a group of numbers derived from the evaluation of the expression argument of the function. The numbers can be weighted. |
|
Computes the sum of a group of numbers derived from the evaluation of the expression argument of the function. "VARIANCE Function" Computes the statistical variance of a group of numbers derived from the evaluation of the expression argument of the function. The numbers can be weighted. |
Columns and expressions can be arguments of an aggregate function. The expressions cannot contain aggregate functions or subqueries.
An aggregate function can accept an argument specified as DISTINCT, which eliminates duplicate values before the aggregate function is applied. See DISTINCT Aggregate Functions.
If you include a GROUP BY clause in the SELECT statement, the columns you refer to in the select list must be either grouping columns or arguments of an aggregate function. If you do not include a GROUP BY clause but you specify an aggregate function in the select list, all rows of the SELECT result table form the one and only group.
See the individual entry for the function.
7.3. Character String Functions
These functions manipulate character strings and use a character value expression as an argument or return a result of a character data type. Character string functions treat each single-byte or multi-byte character in an input string as one character, regardless of the byte length of the character.
Returns the ASCII code value of the first character of a character value expression. |
|
Returns the specified code value in a character set. |
|
Returns the number of characters in a string. You can also use CHARACTER_LENGTH. |
|
Returns an unsigned integer that is the code point of the first character in a character value expression that can be associated with one of the supported character sets. |
|
Returns the concatenation of two character value expressions as a string value. You can also use the concatenation operator (||). |
|
Returns a character string where a specified number of characters within the character string have been deleted and then a second character string has been inserted at a specified start position. |
|
Down-shifts alphanumeric characters. You can also use LOWER. |
|
Returns the leftmost specified number of characters from a character expression. |
|
Returns the position of a specified substring within a character string. You can also use POSITION. |
|
Down-shifts alphanumeric characters. You can also use LCASE. |
|
Replaces the leftmost specified number of characters in a character expression with a padding character. |
|
Removes leading spaces from a character string. |
|
Returns the length of a character string in bytes. |
|
Returns the position of a specified substring within a character string. You can also use LOCATE. |
|
Returns a character string composed of the evaluation of a character expression repeated a specified number of times. |
|
Returns a character string where all occurrences of a specified character string in the original string are replaced with another character string. |
|
Returns the rightmost specified number of characters from a character expression. |
|
Replaces the rightmost specified number of characters in a character expression with a padding character. |
|
Removes trailing spaces from a character string. |
|
Returns a character string consisting of a specified number of spaces. |
|
Extracts a substring from a character string. |
|
Translates a character string from a source character set to a target character set. |
|
Removes leading or trailing characters from a character string. |
|
Up-shifts alphanumeric characters. You can also use UPSHIFT or UPPER. |
|
Up-shifts alphanumeric characters. You can also use UPSHIFT or UCASE. |
|
Up-shift alphanumeric characters. You can also use UPPER or UCASE. |
See the individual entry for the function.
7.4. Datetime Functions
These functions use either a datetime value expression as an argument or return a result of datetime data type:
Adds the integer number of months specified by intr_expr to datetime_expr and normalizes the result. |
|
Converts a Julian timestamp to a TIMESTAMP value. |
|
Returns the current timestamp. You can also use the CURRENT_TIMESTAMP Function. |
|
Returns the current date. |
|
Returns the current time. |
|
Returns the current timestamp. You can also use the CURRENT Function. |
|
Adds the interval specified by interval_expression to datetime_expr. |
|
Extracts the datetime field specified by text from the interval value specified by interval and returns the result as an exact numeric value. |
|
Extracts the datetime field specified by text from the datetime value specified by timestamp and returns the result as an exact numeric value. |
|
Subtracts the specified interval_expression from datetime_expr. |
|
Returns the date with the time portion of the day truncated. |
|
Adds the interval specified by datepart and num_expr to datetime_expr. |
|
Returns the integer value for the number of datepart units of time between startdate and enddate. |
|
Formats a datetime value for display purposes. |
|
Returns an integer value in the range 1 through 31 that represents the corresponding day of the month. You can also use DAYOFMONTH. |
|
Returns the name of the day of the week from a date or timestamp expression. |
|
Returns an integer value in the range 1 through 31 that represents the corresponding day of the month. You can also use DAY. |
|
Returns an integer value in the range 1 through 7 that represents the corresponding day of the week. |
|
Returns an integer value in the range 1 through 366 that represents the corresponding day of the year. |
|
Returns a specified datetime field from a datetime value expression or an interval value expression. |
|
Returns an integer value in the range 0 through 23 that represents the corresponding hour of the day. |
|
Converts a datetime value to a Julian timestamp. |
|
Returns an integer value in the range 0 through 59 that represents the corresponding minute of the hour. |
|
Returns an integer value in the range 1 through 12 that represents the corresponding month of the year. |
|
Returns a character literal that is the name of the month of the year (January, February, and so on). |
|
Returns an integer value in the range 1 through 4 that represents the corresponding quarter of the year. |
|
Returns an integer value in the range 0 through 59 that represents the corresponding second of the minute. |
|
Adds the interval of time specified by interval-ind and num_expr to datetime_expr. |
|
Returns the integer value for the number of interval-ind units of time between startdate and enddate. |
|
Returns an integer value in the range 1 through 54 that represents the corresponding week of the year. |
|
Returns an integer value that represents the year. |
See the individual entry for the function.
7.5. Mathematical Functions
Use these mathematical functions within an SQL numeric value expression:
Returns the absolute value of a numeric value expression. |
|
Returns the arccosine of a numeric value expression as an angle expressed in radians. |
|
Returns the arcsine of a numeric value expression as an angle expressed in radians. |
|
Returns the arctangent of a numeric value expression as an angle expressed in radians. |
|
Returns the arctangent of the x and y coordinates, specified by two numeric value expressions, as an angle expressed in radians. |
|
Returns the smallest integer greater than or equal to a numeric value expression. |
|
Returns the cosine of a numeric value expression, where the expression is an angle expressed in radians. |
|
Returns the hyperbolic cosine of a numeric value expression, where the expression is an angle expressed in radians. |
|
Converts a numeric value expression expressed in radians to the number of degrees. |
|
Returns the exponential value (to the base e) of a numeric value expression. |
|
Returns the largest integer less than or equal to a numeric value expression. |
|
Returns the natural logarithm of a numeric value expression. |
|
Returns the base 10 logarithm of a numeric value expression. |
|
Returns the remainder (modulus) of an integer value expression divided by an integer value expression. |
|
Returns the value of the operand unless it is zero, in which case it returns NULL. |
|
Returns the constant value of pi as a floating-point value. |
|
Returns the value of a numeric value expression raised to the power of an integer value expression. You can also use the exponential operator *\*. |
|
Converts a numeric value expression expressed in degrees to the number of radians. |
|
Returns the value of numeric_expr round to num places to the right of the decimal point. |
|
Returns an indicator of the sign of a numeric value expression. If value is less than zero, returns -1 as the indicator. If value is zero, returns 0. If value is greater than zero, returns 1. |
|
Returns the sine of a numeric value expression, where the expression is a |