Skip to content

Summary of WarehousePG Features

This section provides a high-level overview of the system requirements and feature set of WarehousePG. It contains the following topics:

WarehousePG SQL Standard Conformance

The SQL language was first formally standardized in 1986 by the American National Standards Institute (ANSI) as SQL 1986. Subsequent versions of the SQL standard have been released by ANSI and as International Organization for Standardization (ISO) standards: SQL 1989, SQL 1992, SQL 1999, SQL 2003, SQL 2006, and finally SQL 2008, which is the current SQL standard. The official name of the standard is ISO/IEC 9075-14:2008. In general, each new version adds more features, although occasionally features are deprecated or removed.

It is important to note that there are no commercial database systems that are fully compliant with the SQL standard. WarehousePG is almost fully compliant with the SQL 1992 standard, with most of the features from SQL 1999. Several features from SQL 2003 have also been implemented (most notably the SQL OLAP features).

This section addresses the important conformance issues of WarehousePG as they relate to the SQL standards. For a feature-by-feature list of WarehousePG's support of the latest SQL standard, see SQL 2008 Optional Feature Compliance.

Core SQL Conformance

In the process of building a parallel, shared-nothing database system and query optimizer, certain common SQL constructs are not currently implemented in WarehousePG. The following SQL constructs are not supported:

  1. Some set returning subqueries in EXISTS or NOT EXISTS clauses that WarehousePG's parallel optimizer cannot rewrite into joins.

  2. Backwards scrolling cursors, including the use of FETCH PRIOR, FETCH FIRST, FETCH ABSOLUTE, and FETCH RELATIVE.

  3. In CREATE TABLE statements (on hash-distributed tables): a UNIQUE or PRIMARY KEY clause must include all of (or a superset of) the distribution key columns. Because of this restriction, only one UNIQUE clause or PRIMARY KEY clause is allowed in a CREATE TABLE statement. UNIQUE or PRIMARY KEY clauses are not allowed on randomly-distributed tables.

  4. CREATE UNIQUE INDEX statements that do not contain all of (or a superset of) the distribution key columns. CREATE UNIQUE INDEX is not allowed on randomly-distributed tables.

    Note that UNIQUE INDEXES (but not UNIQUE CONSTRAINTS) are enforced on a part basis within a partitioned table. They guarantee the uniqueness of the key within each part or sub-part.

  5. VOLATILE or STABLE functions cannot run on the segments, and so are generally limited to being passed literal values as the arguments to their parameters.

  6. Triggers are not generally supported because they typically rely on the use of VOLATILE functions. PostgreSQL Event Triggers are supported because they capture only DDL events.

  7. Referential integrity constraints (foreign keys) are not enforced in WarehousePG. Users can declare foreign keys and this information is kept in the system catalog, however.

  8. Sequence manipulation functions CURRVAL and LASTVAL.

SQL 1992 Conformance

The following features of SQL 1992 are not supported in WarehousePG:

  1. NATIONAL CHARACTER (NCHAR) and NATIONAL CHARACTER VARYING (NVARCHAR). Users can declare the NCHAR and NVARCHAR types, however they are just synonyms for CHAR and VARCHAR in WarehousePG.
  2. CREATE ASSERTION statement.
  3. INTERVAL literals are supported in WarehousePG, but do not conform to the standard.
  4. GET DIAGNOSTICS statement.
  5. GLOBAL TEMPORARY TABLEs and LOCAL TEMPORARY TABLEs. WarehousePG TEMPORARY TABLEs do not conform to the SQL standard, but many commercial database systems have implemented temporary tables in the same way. WarehousePG temporary tables are the same as VOLATILE TABLEs in Teradata.
  6. UNIQUE predicate.
  7. MATCH PARTIAL for referential integrity checks (most likely will not be implemented in WarehousePG).

SQL 1999 Conformance

The following features of SQL 1999 are not supported in WarehousePG:

  1. Large Object data types: BLOB, CLOB, NCLOB. However, the BYTEA and TEXT columns can store very large amounts of data in WarehousePG (hundreds of megabytes).

  2. MODULE (SQL client modules).

  3. CREATE PROCEDURE (SQL/PSM). This can be worked around in WarehousePG by creating a FUNCTION that returns void, and invoking the function as follows:

    SELECT *myfunc*(*args*);
  4. The PostgreSQL/WarehousePG function definition language (PL/PGSQL) is a subset of Oracle's PL/SQL, rather than being compatible with the SQL/PSM function definition language. WarehousePG also supports function definitions written in Python, Perl, Java, and R.

  5. BIT and BIT VARYING data types (intentionally omitted). These were deprecated in SQL 2003, and replaced in SQL 2008.

  6. WarehousePG supports identifiers up to 63 characters long. The SQL standard requires support for identifiers up to 128 characters long.

  7. Prepared transactions (PREPARE TRANSACTION, COMMIT PREPARED, ROLLBACK PREPARED). This also means WarehousePG does not support XA Transactions (2 phase commit coordination of database transactions with external transactions).

  8. CHARACTER SET option on the definition of CHAR() or VARCHAR() columns.

  9. Specification of CHARACTERS or OCTETS (BYTES) on the length of a CHAR() or VARCHAR() column. For example, VARCHAR(15 CHARACTERS) or VARCHAR(15 OCTETS) or VARCHAR(15 BYTES).

  10. CREATE DISTINCT TYPE statement. CREATE DOMAIN can be used as a work-around in WarehousePG.

  11. The explicit table construct.

SQL 2003 Conformance

The following features of SQL 2003 are not supported in WarehousePG:

  1. MERGE statements.
  2. IDENTITY columns and the associated GENERATED ALWAYS/GENERATED BY DEFAULT clause. The SERIAL or BIGSERIAL data types are very similar to INT or BIGINT GENERATED BY DEFAULT AS IDENTITY.
  3. MULTISET modifiers on data types.
  4. ROW data type.
  5. WarehousePG syntax for using sequences is non-standard. For example, nextval('seq') is used in WarehousePG instead of the standard NEXT VALUE FOR seq.
  6. GENERATED ALWAYS AS columns. Views can be used as a work-around.
  7. The sample clause (TABLESAMPLE) on SELECT statements. The random() function can be used as a work-around to get random samples from tables.
  8. The partitioned join tables construct (PARTITION BY in a join).
  9. WarehousePG cluster data types are almost SQL standard compliant with some exceptions. Generally customers should not encounter any problems using them.

SQL 2008 Conformance

The following features of SQL 2008 are not supported in WarehousePG:

  1. BINARY and VARBINARY data types. BYTEA can be used in place of VARBINARY in WarehousePG.

  2. The ORDER BY clause is ignored in views and subqueries unless a LIMIT clause is also used. This is intentional, as the WarehousePG optimizer cannot determine when it is safe to avoid the sort, causing an unexpected performance impact for such ORDER BY clauses. To work around, you can specify a really large LIMIT. For example:

    SELECT * FROM mytable ORDER BY 1 LIMIT 9999999999
  3. The row subquery construct is not supported.

  4. TRUNCATE TABLE does not accept the CONTINUE IDENTITY and RESTART IDENTITY clauses.

WarehousePG and PostgreSQL Compatibility

WarehousePG is based on PostgreSQL 9.4. To support the distributed nature and typical workload of a WarehousePG cluster, some SQL commands have been added or modified, and there are a few PostgreSQL features that are not supported. WarehousePG has also added features not found in PostgreSQL, such as physical data distribution, parallel query optimization, external tables, resource queues, and enhanced table partitioning. For full SQL syntax and references, see the SQL Commands.

Note WarehousePG does not support the PostgreSQL large object facility for streaming user data that is stored in large-object structures.

Note Unsupported: using WITH OIDS or oids=TRUE to assign an OID system column when creating or altering a table. This syntax is deprecated and will be removed in a future WarehousePG release.

WarehousePG and PostgreSQL Compatibility SQL Support

SQL CommandSupported in WarehousePGModifications, Limitations, Exceptions
ALTER AGGREGATEYES
ALTER CONVERSIONYES
ALTER DATABASEYES
ALTER DOMAINYES
ALTER EVENT TRIGGERYES
ALTER EXTENSIONYESChanges the definition of a WarehousePG extension - based on PostgreSQL 9.6.
ALTER FUNCTIONYES
ALTER GROUPYESAn alias for ALTER ROLE
ALTER INDEXYES
ALTER LANGUAGEYES
ALTER OPERATORYES
ALTER OPERATOR CLASSYES
ALTER OPERATOR FAMILYYES
ALTER PROTOCOLYES
ALTER PUBLICATIONNO
ALTER RESOURCE QUEUEYESWarehousePG resource management feature - not in PostgreSQL.
ALTER ROLEYESWarehousePG Clauses:

RESOURCE QUEUE queue_name | none

ALTER SCHEMAYES
ALTER SEQUENCEYES
ALTER SUBSCRIPTIONNO
ALTER SYSTEMNO
ALTER TABLEYESUnsupported Clauses / Options:

ENABLE/DISABLE TRIGGER

WarehousePG Database Clauses:

ADD | DROP | RENAME | SPLIT | EXCHANGE PARTITION | SET SUBPARTITION TEMPLATE | SET WITH (REORGANIZE=true | false) | SET DISTRIBUTED BY

ALTER TABLESPACEYES
ALTER TRIGGERNO
ALTER TYPEYESWarehousePG Clauses:

SET DEFAULT ENCODING

ALTER USERYESAn alias for ALTER ROLE
ALTER VIEWYES
ANALYZEYES
BEGINYES
CHECKPOINTYES
CLOSEYES
CLUSTERYES
COMMENTYES
COMMITYES
COMMIT PREPAREDNO
COPYYESModified Clauses:

ESCAPE [ AS ] 'escape' | 'OFF'

WarehousePG Clauses:

[LOG ERRORS] SEGMENT REJECT LIMIT count [ROWS|PERCENT]

CREATE AGGREGATEYESUnsupported Clauses / Options:

[ , SORTOP = sort_operator ]

WarehousePG Clauses:

[ , COMBINEFUNC = combinefunc ]

Limitations:

The functions used to implement the aggregate must be IMMUTABLE functions.

CREATE CASTYES
CREATE CONSTRAINT TRIGGERNO
CREATE CONVERSIONYES
CREATE DATABASEYES
CREATE DOMAINYES
CREATE EVENT TRIGGERYES
CREATE EXTENSIONYESLoads a new extension into WarehousePG - based on PostgreSQL 9.6.
CREATE EXTERNAL TABLEYESWarehousePG parallel ETL feature - not in PostgreSQL 9.4.
CREATE FUNCTIONYESLimitations:

Functions defined as STABLE or VOLATILE can be run in WarehousePG provided that they are run on the coordinator only. STABLE and VOLATILE functions cannot be used in statements that run at the segment level.

CREATE GROUPYESAn alias for CREATE ROLE
CREATE INDEXYESWarehousePG Clauses:

USING bitmap (bitmap indexes)

Limitations:

UNIQUE indexes are allowed only if they contain all of (or a superset of) the WarehousePG distribution key columns. On partitioned tables, a unique index is only supported within an individual partition - not across all partitions.

CONCURRENTLY keyword not supported in WarehousePG.

CREATE LANGUAGEYES
CREATE MATERIALIZED VIEWYESBased on PostgreSQL 9.4.
CREATE OPERATORYESLimitations:

The function used to implement the operator must be an IMMUTABLE function.

CREATE OPERATOR CLASSYES
CREATE OPERATOR FAMILYYES
CREATE PROTOCOLYES
CREATE PUBLICATIONNO
CREATE RESOURCE QUEUEYESWarehousePG resource management feature - not in PostgreSQL 9.4.
CREATE ROLEYESWarehousePG Clauses:

RESOURCE QUEUEqueue_name | none

CREATE RULEYES
CREATE SCHEMAYES
CREATE SEQUENCEYESLimitations:

The lastval() and currval() functions are not supported.

The setval() function is only allowed in queries that do not operate on distributed data.

CREATE SUBSCRIPTIONNO
CREATE TABLEYESUnsupported Clauses / Options:

[GLOBAL | LOCAL]

REFERENCES

FOREIGN KEY

[DEFERRABLE | NOT DEFERRABLE]

Limited Clauses:

UNIQUE or PRIMARY KEY constraints are only allowed on hash-distributed tables (DISTRIBUTED BY), and the constraint columns must be the same as or a superset of the distribution key columns of the table and must include all the distribution key columns of the partitioning key.

WarehousePG Clauses:

DISTRIBUTED BY (column, [ ... ] ) |

DISTRIBUTED RANDOMLY

PARTITION BY type (column [, ...]) ( partition_specification, [...] )

WITH (appendoptimized=true [,compresslevel=value,blocksize=value] )

CREATE TABLE ASYESSee CREATE TABLE
CREATE TABLESPACEYESWarehousePG Clauses:

Specify host file system locations for specific segment instances.

WITH (contentID_1='/path/to/dir1...)

CREATE TRIGGERNO
CREATE TYPEYESWarehousePG Clauses:

COMPRESSTYPE | COMPRESSLEVEL | BLOCKSIZE

Limitations:

The functions used to implement a new base type must be IMMUTABLE functions.

CREATE USERYESAn alias for CREATE ROLE
CREATE VIEWYES
DEALLOCATEYES
DECLAREYESUnsupported Clauses / Options:

SCROLL

FOR UPDATE [ OF column [, ...] ]

Limitations:

Cursors cannot be backward-scrolled. Forward scrolling is supported.

PL/pgSQL does not have support for updatable cursors.

DELETEYES
DISCARDYES

Limitation:DISCARD ALL is not supported.

DOYESPostgreSQL 9.0 feature
DROP AGGREGATEYES
DROP CASTYES
DROP CONVERSIONYES
DROP DATABASEYES
DROP DOMAINYES
DROP EVENT TRIGGERYES
DROP EXTENSIONYESRemoves an extension from WarehousePG – based on PostgreSQL 9.6.
DROP EXTERNAL TABLEYESWarehousePG parallel ETL feature - not in PostgreSQL 9.4.
DROP FUNCTIONYES
DROP GROUPYESAn alias for DROP ROLE
DROP INDEXYES
DROP LANGUAGEYES
DROP OPERATORYES
DROP OPERATOR CLASSYES
DROP OPERATOR FAMILYYES
DROP OWNEDNO
DROP PROTOCOLYES
DROP PUBLICATIONNO
DROP RESOURCE QUEUEYESWarehousePG resource management feature - not in PostgreSQL 9.4.
DROP ROLEYES
DROP RULEYES
DROP SCHEMAYES
DROP SEQUENCEYES
DROP SUBSCRIPTIONNO
DROP TABLEYES
DROP TABLESPACEYES
DROP TRIGGERNO
DROP TYPEYES
DROP USERYESAn alias for DROP ROLE
DROP VIEWYES
ENDYES
EXECUTEYES
EXPLAINYES
FETCHYESUnsupported Clauses / Options:

LAST

PRIOR

BACKWARD

BACKWARD ALL

Limitations:

Cannot fetch rows in a nonsequential fashion; backward scan is not supported.

GRANTYES
INSERTYES
LATERAL Join TypeNO
LISTENYES
LOADYES
LOCKYES
MOVEYESSee FETCH
NOTIFYYES
PREPAREYES
PREPARE TRANSACTIONNO
REASSIGN OWNEDYES
REFRESH MATERIALIZED VIEWYESBased on PostgreSQL 9.4.
REINDEXYES
RELEASE SAVEPOINTYES
RESETYES
RETRIEVEYESWarehousePG parallel retrieve cursor - not in PostgreSQL 9.4.
REVOKEYES
ROLLBACKYES
ROLLBACK PREPAREDNO
ROLLBACK TO SAVEPOINTYES
SAVEPOINTYES
SELECTYESLimitations:

Limited use of VOLATILE and STABLE functions in FROM or WHERE clauses

Text search (Tsearch2) is not supported

WarehousePG Clauses (OLAP):

[GROUP BY grouping_element [, ...]]

[WINDOW window_name AS (window_specification)]

[FILTER (WHERE condition)] applied to an aggregate function in the SELECT list

SELECT INTOYESSee SELECT
SETYES
SET CONSTRAINTSNOIn PostgreSQL, this only applies to foreign key constraints, which are currently not enforced in WarehousePG.
SET ROLEYES
SET SESSION AUTHORIZATIONYESDeprecated as of PostgreSQL 8.1 - see SET ROLE
SET TRANSACTIONYESLimitations:

DEFERRABLE clause has no effect.

SHOWYES
START TRANSACTIONYES
TRUNCATEYES
UNLISTENYES
UPDATEYESLimitations:

SET not allowed for WarehousePG distribution key columns.

VACUUMYESLimitations:

VACUUM FULL is not recommended in WarehousePG.

VALUESYES