Retrieves information from the database.
SELECT [ ALL | DISTINCT ] [ row-limitation-option1 ] select-list … [ INTO { host-variable-list | variable-list | table-name } ] … [ INTO LOCAL TEMPORARY TABLE { table-name } ] … [ FROM table-list ] … [ WHERE search-condition ] … [ GROUP BY [ expression [, ...] | ROLLUP ( expression [, ...] ) | CUBE ( expression [, ...] ) ] ] … [ HAVING search-condition ] … [ ORDER BY { expression | integer } [ ASC | DESC ] [, ...] ] | [ FOR JSON json-mode ] … [ row-limitation-option ] select-list - (back to Syntax) { column-name | expression [ [ AS ] alias-name ] | * } row-limitation-option1 - (back to Syntax) FIRST | TOP {ALL | limit-expression} [START AT startat-expression ] limit-expression - (back to row-limitation-option1) or (back to row-limitation-option2) simple-expression startat-expression - (back to row-limitation-option1) simple-expression row-limitation-option2 - (back to Syntax) LIMIT { [ offset-expression, ] limit-expression | limit-expression OFFSET offset-expression } offset-expression - (back to row-limitation-option2) simple-expression simple-expression - (back to startat-expression) or (back to offset-expression) or (back to limit-expression) integer | variable | ( simple-expression ) | ( simple-expression { + | - | * } simple-expression )
If DISTINCT is used, the statement cannot contain an aggregate function with a DISTINCT parameter.
FIRST and TOP are used primarily with the ORDER BY clause. If you use these keywords without an ORDER BY clause, the result might vary from run to run of the same query, as the optimizer might choose a different query plan.
FIRST and TOP are permitted only in the top-level SELECT of a query, so they cannot be used in derived tables or view definitions. Using FIRST or TOP in a view definition might result in the keyword being ignored when a query is run on the view.
Using FIRST is the same as setting the ROW_COUNT database option to 1. Using TOP is the same as setting the ROW_COUNT option to the same number of rows. If both TOP and ROW_COUNT are set, then the value of TOP takes precedence.
The ROW_COUNT option could produce inconsistent results when used in a query involving global variables, system functions or proxy tables. See ROW_COUNT Option for details.
Subqueries can also be used in a WHERE or HAVING clause predicate (one of the supported predicate types). However, inside the WHERE or HAVING clause, subqueries cannot be used inside a value expression or inside a CONTAINS or LIKE predicate. Subqueries are not allowed in the ON clause of outer joins or in the GROUP BY clause.
If the table name starts with #, the table is created as a temporary table. Otherwise, the table is created as a permanent base table. For permanent tables to be created, the query must satisfy these conditions:
To create a permanent table with one column, the table name must be specified as owner.table. Omit the owner specification for a temporary table.
This statement causes a COMMIT before execution as a side effect of creating the table. Requires the CREATE TABLE system privilege to execute this statement. No permissions are granted on the new table: the statement is a short form for CREATE TABLE followed by INSERT... SELECT.
A SELECT INTO from a stored procedure or function is not permitted, as SELECT INTO is an atomic statement and you cannot do COMMIT, ROLLBACK, or some ROLLBACK TO SAVEPOINT statements in an atomic statement.
Tables created using this statement do not have a primary key defined. You can add a primary key using ALTER TABLE. A primary key should be added before applying any updates or deletes to the table; otherwise, these operations result in all column values being logged in the transaction log for the affected rows.
Use of this clause is restricted to valid SQL Anywhere queries. SAP Sybase IQ extensions are not supported.
SELECT @@version
displays the value of the global variable @@version. This is equivalent to:
SELECT @@version FROM DUMMY
If you have a query that does not require a FROM clause, you can force the query to be processed by SAP Sybase IQ by adding the clause “FROM iq_dummy,” where iq_dummy is a one-row, one-column table that you create in your database.
The use of the same CASE statement is not allowed in both the SELECT and the WHERE clause of a grouped query.
SAP Sybase IQ also supports the disjunction of subquery predicates. Each subquery can appear within the WHERE or HAVING clause with other predicates and can be combined using the AND or OR operators.
GROUP BY must contain more than a single constant. You do not need to add constants to the GROUP BY clause to select the constants in grouped queries. If the GROUP BY expression contains only a single constant, an error is returned and the query is rejected.
When GROUP BY is used, the select list, HAVING clause, and ORDER BY clause cannot reference any identifiers except those named in the GROUP BY clause. This exception applies: The select-list and HAVING clause may contain aggregate functions.
The ROLLUP operator requires an ordered list of grouping expressions to be supplied as arguments. ROLLUP first calculates the standard aggregate values specified in the GROUP BY. Then ROLLUP moves from right to left through the list of grouping columns and creates progressively higher-level subtotals. A grand total is created at the end. If n is the number of grouping columns, ROLLUP creates n+1 levels of subtotals.
SELECT … [ GROUPING ( column-name ) …] … GROUP BY [ expression [, …] | ROLLUP ( expression [, …] ) ]
GROUPING takes a column name as a parameter and returns a Boolean value:
If the Value of the Result Is | GROUPING Returns |
---|---|
NULL created by a ROLLUP operation | 1 (TRUE) |
NULL indicating the row is a subtotal | 1 (TRUE) |
not created by a ROLLUP operation | 0 (FALSE) |
a stored NULL | 0 (FALSE) |
GROUPING is used with the CUBE operator to distinguish between stored NULL values and NULL values in query results created by CUBE.
CUBE syntax:
SELECT … [ GROUPING ( column-name ) …] … GROUP BY [ expression [, …] | CUBE ( expression [, …] ) ]
GROUPING takes a column name as a parameter and returns a Boolean value:
If the Value of the Result Is | GROUPING Returns |
---|---|
NULL created by a CUBE operation | 1 (TRUE) |
NULL indicating the row is a subtotal | 1 (TRUE) |
not created by a CUBE operation | 0 (FALSE) |
a stored NULL | 0 (FALSE) |
When generating a query plan, the SAP Sybase IQ optimizer estimates the total number of groups generated by the GROUP BY CUBE hash operation. The MAX_CUBE_RESULTS database option sets an upper boundary for the number of estimated rows the optimizer considers for a hash algorithm that can be run. If the actual number of rows exceeds the MAX_CUBE_RESULT option value, the optimizer stops processing the query and returns the error message “Estimate number: nnn exceed the DEFAULT_MAX_CUBE_RESULT of GROUP BY CUBE or ROLLUP”, where nnn is the number estimated by the optimizer. See MAX_CUBE_RESULT Option for information on setting the MAX_CUBE_RESULT option.
In Embedded SQL, the SELECT statement is used for retrieving results from the database and placing the values into host variables with the INTO clause. The SELECT statement must return only one row. For multiple row queries, you must use cursors.
You cannot include a Java class in the SELECT list, but you can, for example, create a function or variable that acts as a wrapper for the Java class and then select it.
FOR JSON clause specifies that the result set is to be returned in JSON format. The JSON format depends on the mode you specify. This clause cannot be used with the FOR UPDATE or FOR READ ONLY clause. Cursors declared with FOR JSON are implicitly READ ONLY.
When you specify RAW mode, each row in the result set is returned as a flattened JSON representation.
AUTO mode returns the query results as nested JSON objects based on query joins.
EXPLICIT mode allows you to control the form of the generated JSON objects. Using EXPLICIT mode offers more flexibility in specifying columns and nested hierarchical objects to produce uniform or heterogeneous arrays.
The LIMIT argument must be an integer or integer variable The OFFSET argument must evaluate to a value greater than or equal to 0. If offset-expression is not specified, the default is 0.
The row limitation clause LIMIT offset-expression, limit-expression is equivalent to LIMIT limit-expression OFFSET offset-expression.
SELECT tname FROM SYS.SYSCATALOG WHERE tname LIKE 'SYS%' ;
SELECT CompanyName, CAST( sum(SalesOrderItems.Quantity * Products.UnitPrice) AS INTEGER) VALUE FROM Customers LEFT OUTER JOIN SalesOrders LEFT OUTER JOIN SalesOrderItems LEFT OUTER JOIN Products GROUP BY CompanyName ORDER BY VALUE DESC
SELECT count(*) FROM Employees;
SELECT count(*) INTO :size FROM Employees;
SELECT year, model, color, sum(sales) FROM sales_tab GROUP BY ROLLUP (year, model, color);
SELECT * INTO #TableTemp FROM lineitem WHERE l_discount < 0.5
SELECT FIRST * FROM Employees ORDER BY Surname;
SELECT TOP 5 * FROM Employees ORDER BY Surname;
SELECT * FROM Employees ORDER BY Surname LIMIT 5;
SELECT * FROM Employees ORDER BY Surname DESC LIMIT 4,2;
You can use a SELECT statement in Interactive SQL to browse data in the database or to export data from the database to an external file.
You can also use a SELECT statement in procedures or in Embedded SQL. The SELECT statement with an INTO clause is used for retrieving results from the database when the SELECT statement returns only one row. (Tables created with SELECT INTO do not inherit IDENTITY/AUTOINCREMENT tables.) For multiple-row queries, you must use cursors. When you select more than one column and do not use #table, SELECT INTO creates a permanent base table. SELECT INTO #table always creates a temporary table regardless of the number of columns. SELECT INTO table with a single column selects into a host variable.
Tables with the same name but different owners require aliases. A query without aliases returns incorrect results:
SELECT * FROM user1.t1 WHERE NOT EXISTS (SELECT * FROM user2.t1 WHERE user2.t1.col1 = user1.t.col1);
For correct results, use an alias for each table:
SELECT * FROM user1.t1 U1 WHERE NOT EXISTS (SELECT * FROM user2.t1 U2 WHERE U2.col1 = U1.col1);
The INTO clause with a variable-list is used only in procedures.
In SELECT statements, a stored procedure call can appear anywhere a base table or view is allowed. Note that CIS functional compensation performance considerations apply. For example, a SELECT statement can also return a result set from a procedure.