SQL Capabilities
DML allows you to update and query data stored in OmniSci.
See Using Geospatial Objects: Geospatial Functions for details on geospatial functions.
INSERT
INSERT
Use for single-row ad hoc inserts. (When inserting many rows, use the more efficient COPY
command.)
Examples
You can also insert into a table as SELECT, as shown in the following examples:
You can insert array literals into array columns. The inserts in the following example each have three array values, and demonstrate how you can:
Create a table with variable-length and fixed-length array columns.
Insert
NULL
arrays into these colums.Specify and inserty array literals using
{...}
orARRAY[...]
syntax.Insert empty variable-length arrays using
{}
andARRAY[]
syntax.Insert array values that contain
NULL
elements.
SELECT
SELECT
Usage Notes - ORDER BY
ORDER BY
Sort order defaults to ascending (ASC).
Sorts null values after non-null values by default in an ascending sort, before non-null values in a descending sort. For any query, you can use
NULLS FIRST
to sort null values to the top of the results orNULLS LAST
to sort null values to the bottom of the results.Allows you to use a positional reference to choose the sort column. For example, the command
SELECT colA,colB FROM table1 ORDER BY 2
sorts the results oncolB
because it is in position 2.
For more information, see SELECT.
UPDATE
UPDATE
Changes the values of the specified columns based on the assign
argument (identifier=expression
) in all rows that satisfy the condition in the WHERE
clause.
Example
Currently, OmniSci does not support updating a geo column type (POINT, LINESTRING, POLYGON, or MULTIPOLYGON) in a table.
Update Via Subquery
You can update a table via subquery, which allows you to update based on calculations performed on another table.
Examples
DELETE
DELETE
Deletes rows that satisfy the WHERE
clause from the specified table. If the WHERE clause is absent, all rows in the table are deleted, resulting in a valid but empty table.
EXPLAIN
EXPLAIN
Shows generated Intermediate Representation (IR) code, identifying whether it is executed on GPU or CPU. This is primarily used internally by OmniSci to monitor behavior.
For example, when you use the EXPLAIN
command on a basic statement, the utility returns 90 lines of IR code that is not meant to be human readable. However, at the top of the listing, a heading indicates whether it is IR for the CPU
or IR for the GPU
, which can be useful to know in some situations.
EXPLAIN CALCITE
EXPLAIN CALCITE
Returns a relational algebra tree describing the high-level plan to execute the statement.
The table below lists the relational algebra classes used to describe the execution plan for a SQL statement.
Method | Description |
| Operator that eliminates duplicates and computes totals. |
| Expression that computes project expressions and also filters. |
| Operator that converts a stream to a relation. |
| Operator that performs nested-loop joins. |
| Operator that converts a relation to a stream. |
| Expression that imposes a particular distribution on its input without otherwise changing its content. |
| Expression that iterates over its input and returns elements for which a condition evaluates to true. |
| Expression that returns the intersection of the rows of its inputs. |
| Expression that combines two relational expressions according to some condition. |
| Expression that represents a MATCH_RECOGNIZE node. |
| Expression that returns the rows of its first input minus any matching rows from its other inputs. Corresponds to the SQL EXCEPT operator. |
| Expression that computes a set of ‘select expressions’ from its input relational expression. |
| Expression that imposes a particular sort order on its input without otherwise changing its content. |
| Expression that calls a table-valued function. |
| Expression that modifies a table. Similar to TableScan, but represents a request to modify a table instead of read from it. |
| Reads all the rows from a RelOptTable. |
| Expression that returns the union of the rows of its inputs, optionally eliminating duplicates. |
| Expression for which the value is a sequence of zero or more literal row values. |
| Expression representing a set of window aggregates. See Window Functions |
For example, a SELECT
statement is described as a table scan and projection.
If you add a sort order, the table projection is folded under a LogicalSort
procedure.
When the SQL statement is simple, the EXPLAIN CALCITE version is actually less “human readable.” EXPLAIN CALCITE is more useful when you work with more complex SQL statements, like the one that follows. This query performs a scan on the BOOK table before scanning the BOOK_ORDER table.
Revising the original SQL command results in a more natural selection order and a more performant query.
SHOW
SHOW
Use SHOW
commands to get information about databases, tables, and user sessions.
Command | Description |
| Shows the CREATE TABLE statement that could have been used to create the table.
|
| Retrieve the databases accessible for the current user, showing the database name and owner.
|
| Retrieve the tables accessible for the current user.
|
| Retrieve all persisted user sessions, showing the session ID, user login name, client address, and database name. Admin or superuser privileges required.
|
Window Functions
Window functions allow you to work with a subset of rows related to the currently selected row. For a given dimension, you can find the most associated dimension by some other measure (for example, number of records or sum of revenue).
Window functions must always contain an OVER clause. The OVER clause splits up the rows of the query for processing by the window function.
The PARTITION BY list divides the rows into groups that share the same values of the PARTITION BY expression(s). For each row, the window function is computed using all rows in the same partition as the current row.
Rows that have the same value in the ORDER BY clause are considered peers. The ranking functions give the same answer for any two peer rows.
Function | Description |
| Number of the current row within the partition, counting from 1. |
| Rank of the current row with gaps. Equal to the |
| Rank of the current row without gaps. This function counts peer groups. |
| Relative rank of the current row: (rank-1)/(total rows-1). |
| Cumulative distribution value of the current row: (number of rows preceding or peers of the current row)/(total rows) |
| Subdivide the partition into buckets. If the total number of rows is divisible by num_buckets, each bucket has a equal number of rows. If the total is not divisible by num_buckets, the function returns groups of two sizes with a difference of 1. |
| Returns the value at the row that is offset rows before the current row within the partition |
| Returns the value at the row that is offset rows after the current row within the partition |
| Returns the value from the first row of the window frame (the rows from the start of the partition to the last peer of the current row). |
| Returns the value from the last row of the window frame. |
Usage Notes
OmniSciDB supports the aggregate functions
AVG
,MIN
,MAX
,SUM
, andCOUNT
in window functions.OmniSciDB does not support empty partitions. For example, the following query triggers an exception because the OVER clause requires a PARTITION BY list:
Window functions only work on single fragment datasets. If you want to run window functions over base data in your table, you must ensure there is only one fragment (by increasing the fragment size to be greater than the number of rows expected in the table before import). If you are running the window function on top of an intermediate result (for example, a GROUP BY), the intermediate result is contained in a single fragment, even if the underlying table contains multiple fragments. This happens automatically if a GROUP BY clause is part of the window function query.
Window functions are not supported in distributed mode.
Example
This query shows the top airline carrier for each state, based on the number of departures.
Table Expression and Join Support
If a join column name or alias is not unique, it must be prefixed by its table name.
You can use BIGINT, INTEGER, SMALLINT, TINYINT, DATE, TIME, TIMESTAMP, or TEXT ENCODING DICT data types. TEXT ENCODING DICT is the most efficient because corresponding dictionary IDs are sequential and span a smaller range than, for example, the 65,535 values supported in a SMALLINT field. Depending on the number of values in your field, you can use TEXT ENCODING DICT(32) (up to approximately 2,150,000,000 distinct values), TEXT ENCODING DICT(16) (up to 64,000 distinct values), or TEXT ENCODING DICT(8) (up to 255 distinct values). For more information, see Data Types and Fixed Encoding.
Geospatial Joins
By default, a join involving a geospatial operator (such as ST_Contains
) utilizes the loop join framework.
To allow all loop joins, set the allow-loop-joins
flag to true
at either the command line when starting OmniSci, or in omnisci.conf. Running geo join queries without allow-loop-joins
set to true
results in the following error:
If you set trivial-loop-join-threshold
, loop joins are allowed if the inner table has fewer rows than the trivial join loop threshold you specify. The default value is 1,000 rows.
For geospatial joins, the inner table should always be the more complicated primitive. For example, for ST_Contains(polygon, point)
, the point
table should be the outer table and the polygon
table should be the inner table.
Geo join best practice is to increase the trivial join loop threshold for the size of the inner table.
When you increase the trivial loop join threshold by 1, you increase the run time by the number of rows in your outer table. For example, if your outer table has 100,000,000 rows, and your trivial loop join threshold is 10, you potentially run 1,000,000,000 operations in the loop. If you increase the loop join to 100, you increase the number of operations run to 10,000,000,000.
Using Joins in a Distributed Environment
You can create joins in a distributed environment in two ways:
Replicate small dimension tables that are used in the join.
Create a shard key on the column used in the join (note that there is a limit of one shard key per table). If the column involved in the join is a TEXT ENCODED field, you must create a SHARED DICTIONARY that references the FACT table key you are using to make the join.
The join order for one small table and one large table matters. If you swap the sales and customer tables on the join, it throws an exception stating that table "sales" must be replicated.
Logical Operator Support
Operator | Description |
| Logical AND |
| Negates value |
| Logical OR |
Conditional Expression Support
Expression | Description |
| Case operator |
| Returns the first non-null value in the list |
Subquery Expression Support
Expression | Description |
| Evaluates whether expr equals any value of the IN list. |
| Evaluates whether expr does not equal any value of the IN list. |
Usage Notes
You can use a subquery anywhere an expression can be used, subject to any runtime constraints of that expression. For example, a subquery in a CASE statement must return exactly one row, but a subquery can return multiple values to an IN expression.
You can use a subquery anywhere a table is allowed (for example,
FROM
subquery), using aliases to name any reference to the table and columns returned by the subquery.
Type Cast Support
Expression | Example | Description |
|
| Converts an expression to another data type |
The following table shows cast type conversion support.
FROM/TO: |
|
|
|
|
|
|
|
|
|
|
|
|
| - | Yes | Yes | Yes | Yes | Yes | Yes | No | No | No | No | n/a |
| Yes | - | Yes | Yes | Yes | Yes | Yes | No | No | No | No | n/a |
| Yes | Yes | - | Yes | Yes | Yes | Yes | No | Yes | No | No | No |
| Yes | Yes | Yes | - | Yes | Yes | Yes | No | No | No | No | No |
| Yes | Yes | Yes | Yes | - | Yes | No | No | No | No | No | No |
| Yes | Yes | Yes | Yes | Yes | - | No | No | No | No | No | n/a |
| Yes | Yes | Yes | Yes | Yes | Yes | - | No | No | No | No | n/a |
| No | No | No | No | No | No | No | - | No | No | No | No |
| No | No | Yes | No | No | No | No | No | - | n/a | n/a | n/a |
| No | No | No | No | No | No | No | No | n/a | - | No | Yes |
| No | No | No | No | No | No | No | No | n/a | No | - | n/a |
| No | No | No | No | No | No | No | No | n/a | Yes | No | - |
Array Support
OmniSci supports arrays in dictionary-encoded text and number fields (TINYINT, SMALLINT, INTEGER, BIGINT, FLOAT, and DOUBLE). Data stored in arrays are not normalized. For example, {green,yellow} is not the same as {yellow,green}. As with many SQL-based services, OmniSci array indexes are 1-based.
OmniSci supports NULL variable-length arrays for all integer and floating-point data types, including dictionary-encoded string arrays. For example, you can insert NULL
into BIGINT[ ], DOUBLE[ ], or TEXT[ ] columns. OmniSci supports NULL fixed-length arrays for all integer and floating-point data types, but not for dictionary-encoded string arrays. For example, you can insert NULL
into BIGINT[2] DOUBLE[3], but not into TEXT[2] columns.
Expression | Description | |||||||
| Returns value(s) from specific location | |||||||
| Extract the values in the array to a set of rows. Requires | |||||||
|
| |||||||
|
| |||||||
| Returns the number of elements in an array. For example: `omnisql> \d arr CREATE TABLE arr ( sia SMALLINT[]) omnisql> select sia, CARDINALITY(sia) from arr; sia | EXPR$0 NULL | NULL {} | 0 {NULL} | 1 {1} | 1 {2,2} | 2 {3,3,3} | 3` |
Examples
The following examples show query results based on the table test_array
created with the following statement:
The following queries use arrays in an INTEGER field:
LIKELY/UNLIKELY
LIKELY/UNLIKELY
Expression | Description |
| Provides a hint to the query planner that argument |
| Provides a hint to the query planner that argument |
Usage Notes
SQL normally assumes that terms in the WHERE
clause that cannot be used by indices are usually true. If this assumption is incorrect, it could lead to a suboptimal query plan. Use the LIKELY(X)
and UNLIKELY(X)
SQL functions to provide hints to the query planner about clause terms that are probably not true, which helps the query planner to select the best possible plan.
Use LIKELY
/UNLIKELY
to optimize evaluation of OR
/AND
logical expressions. LIKELY
/UNLIKELY
causes the left side of an expression to be evaluated first. This allows the right side of the query to be skipped when possible. For example, in the clause UNLIKELY(A) AND B
, if A
evaluates to FALSE
, B
does not need to be evaluated.
Consider the following:
If x
is one of the values 7
, 8
, 9
, or 10
, the filter y > 42
is applied. If x
is not one of those values, the filter y > 42
is not applied.
Last updated