PostgreSQL wire protocol¶
CrateDB supports the PostgreSQL wire protocol v3.
If a node is started with PostgreSQL wire protocol support enabled it will bind
to port 5432
by default. To use a custom port, set the corresponding
Ports in the Configuration.
However, even though connecting PostgreSQL tools and client libraries is
supported, the actual SQL statements have to be supported by CrateDB’s SQL
dialect. A notable difference is that CrateDB doesn’t support transactions,
which is why clients should generally enable autocommit
.
Note
In order to use setFetchSize
in JDBC it is possible to set auto commit
to false.
The client will utilize the fetchSize on SELECT statements and only load up to fetchSize rows into memory.
See the PostgreSQL JDBC Query docs for more information.
Write operations will still behave as if auto commit was enabled and commit or rollback calls are ignored.
Table of contents
Server compatibility¶
CrateDB emulates PostgreSQL server version 14
.
Start-up¶
SSL Support¶
SSL can be configured using Secured communications (SSL/TLS).
Authentication¶
Authentication methods can be configured using Host-Based Authentication (HBA).
ParameterStatus¶
After the authentication succeeded, the server has the possibility to send
multiple ParameterStatus
messages to the client. These are used to
communicate information like server_version
(emulates PostgreSQL 9.5) or
server_encoding
.
CrateDB
also sends a message containing the crate_version
parameter.
This contains the current CrateDB
version number.
This information is useful for clients to detect that they’re connecting to
CrateDB
instead of a PostgreSQL instance.
Database selection¶
Since CrateDB uses schemas instead of databases, the database
parameter
sets the default schema name for future queries. If no schema is specified, the
schema doc
will be used as default. Additionally, the only supported
charset is UTF8
.
Query modes¶
Simple query¶
The PostgreSQL simple query protocol mode is fully implemented.
Extended query¶
The PostgreSQL extended query protocol mode is implemented with the following limitations:
The
ParameterDescription
message works for the most common use cases except for DDL statements.To optimize the execution of bulk operations the execution of statements is delayed until the
Sync
message is received
Copy operations¶
CrateDB does not support the COPY
sub-protocol, see also
Copy operations.
Function call¶
The function call sub-protocol is not supported since it’s a legacy feature.
Canceling requests¶
PostgreSQL cancelling requests is fully implemented.
pg_catalog
¶
For improved compatibility, the pg_catalog
schema is implemented containing
following tables:
pg_type
¶
Some clients require the pg_catalog.pg_type
in order to be able to stream
arrays or other non-primitive types.
For compatibility reasons, there is a trimmed down pg_type table available in CrateDB:
cr> SELECT oid, typname, typarray, typelem, typlen, typtype, typcategory
... FROM pg_catalog.pg_type
... ORDER BY oid;
+------+--------------+----------+---------+--------+---------+-------------+
| oid | typname | typarray | typelem | typlen | typtype | typcategory |
+------+--------------+----------+---------+--------+---------+-------------+
| 16 | bool | 1000 | 0 | 1 | b | N |
| 18 | char | 1002 | 0 | 1 | b | S |
| 19 | name | -1 | 0 | 64 | b | S |
| 20 | int8 | 1016 | 0 | 8 | b | N |
| 21 | int2 | 1005 | 0 | 2 | b | N |
| 23 | int4 | 1007 | 0 | 4 | b | N |
| 24 | regproc | 1008 | 0 | 4 | b | N |
| 25 | text | 1009 | 0 | -1 | b | S |
| 26 | oid | 1028 | 0 | 4 | b | N |
| 30 | oidvector | 1013 | 26 | -1 | b | A |
| 114 | json | 199 | 0 | -1 | b | U |
| 199 | _json | 0 | 114 | -1 | b | A |
| 600 | point | 1017 | 0 | 16 | b | G |
| 700 | float4 | 1021 | 0 | 4 | b | N |
| 701 | float8 | 1022 | 0 | 8 | b | N |
| 705 | unknown | 0 | 0 | -2 | p | X |
| 1000 | _bool | 0 | 16 | -1 | b | A |
| 1002 | _char | 0 | 18 | -1 | b | A |
| 1005 | _int2 | 0 | 21 | -1 | b | A |
| 1007 | _int4 | 0 | 23 | -1 | b | A |
| 1008 | _regproc | 0 | 24 | -1 | b | A |
| 1009 | _text | 0 | 25 | -1 | b | A |
| 1014 | _bpchar | 0 | 1042 | -1 | b | A |
| 1015 | _varchar | 0 | 1043 | -1 | b | A |
| 1016 | _int8 | 0 | 20 | -1 | b | A |
| 1017 | _point | 0 | 600 | -1 | b | A |
| 1021 | _float4 | 0 | 700 | -1 | b | A |
| 1022 | _float8 | 0 | 701 | -1 | b | A |
| 1042 | bpchar | 1014 | 0 | -1 | b | S |
| 1043 | varchar | 1015 | 0 | -1 | b | S |
| 1082 | date | 1182 | 0 | 8 | b | D |
| 1114 | timestamp | 1115 | 0 | 8 | b | D |
| 1115 | _timestamp | 0 | 1114 | -1 | b | A |
| 1182 | _date | 0 | 1082 | -1 | b | A |
| 1184 | timestamptz | 1185 | 0 | 8 | b | D |
| 1185 | _timestamptz | 0 | 1184 | -1 | b | A |
| 1186 | interval | 1187 | 0 | 16 | b | T |
| 1187 | _interval | 0 | 1186 | -1 | b | A |
| 1231 | _numeric | 0 | 1700 | -1 | b | A |
| 1266 | timetz | 1270 | 0 | 12 | b | D |
| 1270 | _timetz | 0 | 1266 | -1 | b | A |
| 1560 | bit | 1561 | 0 | -1 | b | V |
| 1561 | _bit | 0 | 1560 | -1 | b | A |
| 1700 | numeric | 1231 | 0 | -1 | b | N |
| 2205 | regclass | 2210 | 0 | 4 | b | N |
| 2210 | _regclass | 0 | 2205 | -1 | b | A |
| 2249 | record | 2287 | 0 | -1 | p | P |
| 2276 | any | 0 | 0 | 4 | p | P |
| 2277 | anyarray | 0 | 2276 | -1 | p | P |
| 2287 | _record | 0 | 2249 | -1 | p | A |
+------+--------------+----------+---------+--------+---------+-------------+
SELECT 50 rows in set (... sec)
Note
This is just a snapshot of the table.
Check table information_schema.columns to get information for all supported columns.
OID types¶
Object Identifiers (OIDs) are used internally by PostgreSQL as primary keys for various system tables.
CrateDB supports the oid type and the following aliases:
Name |
Reference |
Description |
Example |
---|---|---|---|
A function name |
|
||
A relation name |
|
CrateDB also supports the oidvector type.
Note
Casting a string or an integer to the regproc
type does not result in a function
lookup (as it does with PostgreSQL).
Instead:
Casting a string to the
regproc
type results in an object of theregproc
type with a name equal to the string value and anoid
equal to an integer hash of the string.Casting an integer to the
regproc
type results in an object of theregproc
type with a name equal to the string representation of the integer and anoid
equal to the integer value.
Consult the CrateDB data types reference for more information about each OID type (including additional type casting behaviour).
Show transaction isolation¶
For compatibility with JDBC the SHOW TRANSACTION ISOLATION LEVEL
statement
is implemented:
cr> show transaction isolation level;
+-----------------------+
| transaction_isolation |
+-----------------------+
| read uncommitted |
+-----------------------+
SHOW 1 row in set (... sec)
BEGIN
, START
, and COMMIT
statements¶
For compatibility with clients that use the PostgresSQL wire protocol (e.g., the Golang lib/pq and pgx drivers), CrateDB will accept the BEGIN, COMMIT, and START TRANSACTION statements. For example:
cr> BEGIN TRANSACTION ISOLATION LEVEL READ UNCOMMITTED,
... READ ONLY,
... NOT DEFERRABLE;
BEGIN OK, 0 rows affected (... sec)
cr> COMMIT
COMMIT OK, 0 rows affected (... sec)
CrateDB will silently ignore the COMMIT
, BEGIN
, and START
TRANSACTION
statements and all respective parameters.
Client compatibility¶
JDBC¶
pgjdbc JDBC drivers version 9.4.1209
and above are compatible.
Limitations¶
Reflection methods like
conn.getMetaData().getTables(...)
won’t work since the required tables are unavailable in CrateDB.As a workaround it’s possible to use
SHOW TABLES
or query theinformation_schema
tables manually usingSELECT
statements.OBJECT
andGEO_SHAPE
columns can be streamed asJSON
but require pgjdbc version9.4.1210
or newer.Multidimensional arrays will be streamed as
JSON
encoded string to avoid a protocol limitation where all sub-arrays are required to have the same length.The behavior of
PreparedStatement.executeBatch
in error cases depends on in which stage an error occurs: ABatchUpdateException
is thrown if no processing has been done yet, whereas single operations failing after the processing started are indicated by anEXECUTE_FAILED
(-3) return value.Transaction limitations as described above.
Having
escape processing
enabled could prevent the usage of Object Literals in case an object key’s starting character clashes with a JDBC escape keyword (see also JDBC escape syntax). Disablingescape processing
will remedy this appropriately for pgjdbc version >=9.4.1212
.
Connection failover and load balancing¶
Connection failover and load balancing is supported as described here: PostgreSQL JDBC connection failover.
Note
It is not recommended to use the targetServerType parameter since CrateDB has no concept of master-replica nodes.
Implementation differences¶
The PostgreSQL Wire Protocol makes it easy to use many PostgreSQL compatible tools and libraries directly with CrateDB. However, many of these tools assume that they are talking to PostgreSQL specifically, and thus rely on SQL extensions and idioms that are unique to PostgreSQL. Because of this, some tools or libraries may not work with other SQL databases such as CrateDB.
CrateDB’s SQL query engine enables real-time search & aggregations for online analytic processing (OLAP) and business intelligence (BI) with the benefit of the ability to scale horizontally. The use-cases of CrateDB are different than those of PostgreSQL, as CrateDB’s specialized storage schema and query execution engine addresses different needs (see Clustering).
The features listed below cover the main differences in implementation and dialect between CrateDB and PostgreSQL. A detailed comparison between CrateDB’s SQL dialect and standard SQL is outlined in SQL compatibility.
Copy operations¶
CrateDB does not support the distinct sub-protocol that is used to serve
COPY
operations and provides another implementation for transferring bulk
data using the COPY FROM and COPY TO statements.
Data types¶
Dates and times¶
At the moment, CrateDB does not support TIME
without a time zone.
Additionally, CrateDB does not support the INTERVAL
input units
MILLENNIUM
, CENTURY
, DECADE
, or MICROSECOND
.
Objects¶
The definition of structured values by using JSON
types, composite types
or HSTORE
are not supported. CrateDB alternatively allows the definition of
nested documents (of type OBJECT) that store fields containing any
CrateDB supported data type, including nested object types.
Arrays¶
Declaration of arrays¶
While multidimensional arrays in PostgreSQL must have matching extends for each dimension, CrateDB allows different length nested arrays as this example shows:
cr> select [[1,2,3],[1,2]] from sys.cluster;
+---------------------+
| [[1, 2, 3], [1, 2]] |
+---------------------+
| [[1, 2, 3], [1, 2]] |
+---------------------+
SELECT 1 row in set (... sec)
Type casts¶
CrateDB accepts the Type casting syntax for conversion of one data type to another.
Text search functions and operators¶
The functions and operators provided by PostgreSQL for full-text search (see PostgreSQL fulltext Search) are not compatible with those provided by CrateDB.
If you are missing features, functions or dialect improvements and have a great use case for it, let us know on GitHub. We’re always improving and extending CrateDB and we love to hear feedback.