PostgreSQL connector#

The PostgreSQL connector allows querying and creating tables in an external PostgreSQL database. This can be used to join data between different systems like PostgreSQL and Hive, or between different PostgreSQL instances.

SEP includes additional enterprise features that are built on top of the existing Trino connector functionality. For more information on connector key feature differences between Trino and SEP, see the connectors feature matrix.

Requirements#

To connect to PostgreSQL, you need:

  • PostgreSQL 11.x or higher.

  • Network access from the SEP coordinator and workers to PostgreSQL. Port 5432 is the default port.

  • A valid Starburst Enterprise license.

Configuration#

The connector can query a database on a PostgreSQL server. Create a catalog properties file that specifies the PostgreSQL connector by setting the connector.name to postgresql.

For example, to access a database as the example catalog, create the file etc/catalog/example.properties. Replace the connection properties as appropriate for your setup:

connector.name=postgresql
connection-url=jdbc:postgresql://example.net:5432/database
connection-user=root
connection-password=secret

The connection-url defines the connection information and parameters to pass to the PostgreSQL JDBC driver. The parameters for the URL are available in the PostgreSQL JDBC driver documentation. Some parameters can have adverse effects on the connector behavior or not work with the connector.

The connection-user and connection-password are typically required and determine the user credentials for the connection, often a service user. You can use secrets to avoid actual values in the catalog properties files.

Access to system tables#

The PostgreSQL connector supports reading PostgreSQL catalog tables, such as pg_namespace. The functionality is turned off by default, and can be enabled using the postgresql.include-system-tables configuration property.

You can see more details in the pg_catalog schema in the example catalog, for example about the pg_namespace system table:

SHOW TABLES FROM example.pg_catalog;
SELECT * FROM example.pg_catalog.pg_namespace;

Connection security#

If you have TLS configured with a globally-trusted certificate installed on your data source, you can enable TLS between your cluster and the data source by appending a parameter to the JDBC connection string set in the connection-url catalog configuration property.

For example, with version 42 of the PostgreSQL JDBC driver, enable TLS by appending the ssl=true parameter to the connection-url configuration property:

connection-url=jdbc:postgresql://example.net:5432/database?ssl=true

For more information on TLS configuration options, see the PostgreSQL JDBC driver documentation.

Data source authentication#

The connector can provide credentials for the data source connection in multiple ways:

  • inline, in the connector configuration file

  • in a separate properties file

  • in a key store file

  • as extra credentials set when connecting to Trino

You can use secrets to avoid storing sensitive values in the catalog properties files.

The following table describes configuration properties for connection credentials:

Property name

Description

credential-provider.type

Type of the credential provider. Must be one of INLINE, FILE, or KEYSTORE; defaults to INLINE.

connection-user

Connection user name.

connection-password

Connection password.

user-credential-name

Name of the extra credentials property, whose value to use as the user name. See extraCredentials in Parameter reference.

password-credential-name

Name of the extra credentials property, whose value to use as the password.

connection-credential-file

Location of the properties file where credentials are present. It must contain the connection-user and connection-password properties.

keystore-file-path

The location of the Java Keystore file, from which to read credentials.

keystore-type

File format of the keystore file, for example JKS or PEM.

keystore-password

Password for the key store.

keystore-user-credential-name

Name of the key store entity to use as the user name.

keystore-user-credential-password

Password for the user name key store entity.

keystore-password-credential-name

Name of the key store entity to use as the password.

keystore-password-credential-password

Password for the password key store entity.

Multiple PostgreSQL databases or servers#

The PostgreSQL connector can only access a single database within a PostgreSQL server. Thus, if you have multiple PostgreSQL databases, or want to connect to multiple PostgreSQL servers, you must configure multiple instances of the PostgreSQL connector.

To add another catalog, add another properties file to etc/catalog with a different name, making sure it ends in .properties. For example, if you name the property file sales.properties, SEP creates a catalog named sales using the configured connector.

General configuration properties#

The following table describes general catalog configuration properties for the connector:

Property name

Description

case-insensitive-name-matching

Support case insensitive schema and table names. Defaults to false.

case-insensitive-name-matching.cache-ttl

Duration for which case insensitive schema and table names are cached. Defaults to 1m.

case-insensitive-name-matching.config-file

Path to a name mapping configuration file in JSON format that allows Trino to disambiguate between schemas and tables with similar names in different cases. Defaults to null.

case-insensitive-name-matching.config-file.refresh-period

Frequency with which Trino checks the name matching configuration file for changes. The duration value defaults to 0s (refresh disabled).

metadata.cache-ttl

Duration for which metadata, including table and column statistics, is cached. Defaults to 0s (caching disabled).

metadata.cache-missing

Cache the fact that metadata, including table and column statistics, is not available. Defaults to false.

metadata.schemas.cache-ttl

Duration for which schema metadata is cached. Defaults to the value of metadata.cache-ttl.

metadata.tables.cache-ttl

Duration for which table metadata is cached. Defaults to the value of metadata.cache-ttl.

metadata.statistics.cache-ttl

Duration for which tables statistics are cached. Defaults to the value of metadata.cache-ttl.

metadata.cache-maximum-size

Maximum number of objects stored in the metadata cache. Defaults to 10000.

write.batch-size

Maximum number of statements in a batched execution. Do not change this setting from the default. Non-default values may negatively impact performance. Defaults to 1000.

dynamic-filtering.enabled

Push down dynamic filters into JDBC queries. Defaults to true.

dynamic-filtering.wait-timeout

Maximum duration for which Trino waits for dynamic filters to be collected from the build side of joins before starting a JDBC query. Using a large timeout can potentially result in more detailed dynamic filters. However, it can also increase latency for some queries. Defaults to 20s.

Appending query metadata#

The optional parameter query.comment-format allows you to configure a SQL comment that is sent to the datasource with each query. The format of this comment can contain any characters and the following metadata:

  • $QUERY_ID: The identifier of the query.

  • $USER: The name of the user who submits the query to Trino.

  • $SOURCE: The identifier of the client tool used to submit the query, for example trino-cli.

  • $TRACE_TOKEN: The trace token configured with the client tool.

The comment can provide more context about the query. This additional information is available in the logs of the datasource. To include environment variables from the Trino cluster with the comment , use the ${ENV:VARIABLE-NAME} syntax.

The following example sets a simple comment that identifies each query sent by Trino:

query.comment-format=Query sent by Trino.

With this configuration, a query such as SELECT * FROM example_table; is sent to the datasource with the comment appended:

SELECT * FROM example_table; /*Query sent by Trino.*/

The following example improves on the preceding example by using metadata:

query.comment-format=Query $QUERY_ID sent by user $USER from Trino.

If Jane sent the query with the query identifier 20230622_180528_00000_bkizg, the following comment string is sent to the datasource:

SELECT * FROM example_table; /*Query 20230622_180528_00000_bkizg sent by user Jane from Trino.*/

Note

Certain JDBC driver settings and logging configurations might cause the comment to be removed.

Domain compaction threshold#

Pushing down a large list of predicates to the data source can compromise performance. Trino compacts large predicates into a simpler range predicate by default to ensure a balance between performance and predicate pushdown. If necessary, the threshold for this compaction can be increased to improve performance when the data source is capable of taking advantage of large predicates. Increasing this threshold may improve pushdown of large dynamic filters. The domain-compaction-threshold catalog configuration property or the domain_compaction_threshold catalog session property can be used to adjust the default value of 32 for this threshold.

Procedures#

  • system.flush_metadata_cache()

    Flush JDBC metadata caches. For example, the following system call flushes the metadata caches for all schemas in the example catalog

    USE example.example_schema;
    CALL system.flush_metadata_cache();
    

Case insensitive matching#

When case-insensitive-name-matching is set to true, Trino is able to query non-lowercase schemas and tables by maintaining a mapping of the lowercase name to the actual name in the remote system. However, if two schemas and/or tables have names that differ only in case (such as “customers” and “Customers”) then Trino fails to query them due to ambiguity.

In these cases, use the case-insensitive-name-matching.config-file catalog configuration property to specify a configuration file that maps these remote schemas/tables to their respective Trino schemas/tables:

{
  "schemas": [
    {
      "remoteSchema": "CaseSensitiveName",
      "mapping": "case_insensitive_1"
    },
    {
      "remoteSchema": "cASEsENSITIVEnAME",
      "mapping": "case_insensitive_2"
    }],
  "tables": [
    {
      "remoteSchema": "CaseSensitiveName",
      "remoteTable": "tablex",
      "mapping": "table_1"
    },
    {
      "remoteSchema": "CaseSensitiveName",
      "remoteTable": "TABLEX",
      "mapping": "table_2"
    }]
}

Queries against one of the tables or schemes defined in the mapping attributes are run against the corresponding remote entity. For example, a query against tables in the case_insensitive_1 schema is forwarded to the CaseSensitiveName schema and a query against case_insensitive_2 is forwarded to the cASEsENSITIVEnAME schema.

At the table mapping level, a query on case_insensitive_1.table_1 as configured above is forwarded to CaseSensitiveName.tablex, and a query on case_insensitive_1.table_2 is forwarded to CaseSensitiveName.TABLEX.

By default, when a change is made to the mapping configuration file, Trino must be restarted to load the changes. Optionally, you can set the case-insensitive-name-mapping.refresh-period to have Trino refresh the properties without requiring a restart:

case-insensitive-name-mapping.refresh-period=30s

Non-transactional INSERT#

The connector supports adding rows using INSERT statements. By default, data insertion is performed by writing data to a temporary table. You can skip this step to improve performance and write directly to the target table. Set the insert.non-transactional-insert.enabled catalog property or the corresponding non_transactional_insert catalog session property to true.

Note that with this property enabled, data can be corrupted in rare cases where exceptions occur during the insert operation. With transactions disabled, no rollback can be performed.

Type mapping#

Because Trino and PostgreSQL each support types that the other does not, this connector modifies some types when reading or writing data. Data types may not map the same way in both directions between Trino and the data source. Refer to the following sections for type mapping in each direction.

PostgreSQL type to Trino type mapping#

The connector maps PostgreSQL types to the corresponding Trino types following this table:

PostgreSQL type to Trino type mapping#

PostgreSQL type

Trino type

Notes

BIT

BOOLEAN

BOOLEAN

BOOLEAN

SMALLINT

SMALLINT

INTEGER

INTEGER

BIGINT

BIGINT

REAL

REAL

DOUBLE

DOUBLE

NUMERIC(p, s)

DECIMAL(p, s)

DECIMAL(p, s) is an alias of NUMERIC(p, s). See Decimal type handling for more information.

CHAR(n)

CHAR(n)

VARCHAR(n)

VARCHAR(n)

ENUM

VARCHAR

BYTEA

VARBINARY

DATE

DATE

TIME(n)

TIME(n)

TIMESTAMP(n)

TIMESTAMP(n)

TIMESTAMPTZ(n)

TIMESTAMP(n) WITH TIME ZONE

MONEY

VARCHAR

UUID

UUID

JSON

JSON

JSONB

JSON

HSTORE

MAP(VARCHAR, VARCHAR)

ARRAY

Disabled, ARRAY, or JSON

See Array type handling for more information.

No other types are supported.

Trino type to PostgreSQL type mapping#

The connector maps Trino types to the corresponding PostgreSQL types following this table:

Trino type to PostgreSQL type mapping#

Trino type

PostgreSQL type

Notes

BOOLEAN

BOOLEAN

SMALLINT

SMALLINT

TINYINT

SMALLINT

INTEGER

INTEGER

BIGINT

BIGINT

DOUBLE

DOUBLE

DECIMAL(p, s)

NUMERIC(p, s)

DECIMAL(p, s) is an alias of NUMERIC(p, s). See Decimal type handling for more information.

CHAR(n)

CHAR(n)

VARCHAR(n)

VARCHAR(n)

VARBINARY

BYTEA

DATE

DATE

TIME(n)

TIME(n)

TIMESTAMP(n)

TIMESTAMP(n)

TIMESTAMP(n) WITH TIME ZONE

TIMESTAMPTZ(n)

UUID

UUID

JSON

JSONB

ARRAY

ARRAY

See Array type handling for more information.

No other types are supported.

Decimal type handling#

DECIMAL types with unspecified precision or scale are ignored unless the decimal-mapping configuration property or the decimal_mapping session property is set to allow_overflow. Then such types are mapped to a Trino DECIMAL with a default precision of 38 and default scale of 0. To change the scale of the resulting type, use the decimal-default-scale configuration property or the decimal_default_scale session property. The precision is always 38.

By default, values that require rounding or truncation to fit will cause a failure at runtime. This behavior is controlled via the decimal-rounding-mode configuration property or the decimal_rounding_mode session property, which can be set to UNNECESSARY (the default), UP, DOWN, CEILING, FLOOR, HALF_UP, HALF_DOWN, or HALF_EVEN (see RoundingMode).

Array type handling#

The PostgreSQL array implementation does not support fixed dimensions whereas SEP support only arrays with fixed dimensions. You can configure how the PostgreSQL connector handles arrays with the postgresql.array-mapping configuration property in your catalog file or the array_mapping session property. The following values are accepted for this property:

  • DISABLED (default): array columns are skipped.

  • AS_ARRAY: array columns are interpreted as Trino ARRAY type, for array columns with fixed dimensions.

  • AS_JSON: array columns are interpreted as Trino JSON type, with no constraint on dimensions.

Type mapping configuration properties#

The following properties can be used to configure how data types from the connected data source are mapped to Trino data types and how the metadata is cached in Trino.

Property name

Description

Default value

unsupported-type-handling

Configure how unsupported column data types are handled:

  • IGNORE, column is not accessible.

  • CONVERT_TO_VARCHAR, column is converted to unbounded VARCHAR.

The respective catalog session property is unsupported_type_handling.

IGNORE

jdbc-types-mapped-to-varchar

Allow forced mapping of comma separated lists of data types to convert to unbounded VARCHAR

Querying PostgreSQL#

The PostgreSQL connector provides a schema for every PostgreSQL schema. You can see the available PostgreSQL schemas by running SHOW SCHEMAS:

SHOW SCHEMAS FROM example;

If you have a PostgreSQL schema named web, you can view the tables in this schema by running SHOW TABLES:

SHOW TABLES FROM example.web;

You can see a list of the columns in the clicks table in the web database using either of the following:

DESCRIBE example.web.clicks;
SHOW COLUMNS FROM example.web.clicks;

Finally, you can access the clicks table in the web schema:

SELECT * FROM example.web.clicks;

If you use a different name for your catalog properties file, use that catalog name instead of example in the above examples.

SQL support#

The connector provides read access and write access to data and metadata in PostgreSQL. In addition to the globally available and read operation statements, the connector supports the following features:

UPDATE#

Only UPDATE statements with constant assignments and predicates are supported. For example, the following statement is supported because the values assigned are constants:

UPDATE table SET col1 = 1 WHERE col3 = 1

Arithmetic expressions, function calls, and other non-constant UPDATE statements are not supported. For example, the following statement is not supported because arithmetic expressions cannot be used with the SET command:

UPDATE table SET col1 = col2 + 2 WHERE col3 = 1

The =, !=, >, <, >=, <=, IN, NOT IN operators are supported in predicates. The following statement is not supported because the AND operator cannot be used in predicates:

UPDATE table SET col1 = 1 WHERE col3 = 1 AND col2 = 3

All column values of a table row cannot be updated simultaneously. For a three column table, the following statement is not supported:

UPDATE table SET col1 = 1, col2 = 2, col3 = 3 WHERE col3 = 1

SQL DELETE#

If a WHERE clause is specified, the DELETE operation only works if the predicate in the clause can be fully pushed down to the data source.

ALTER TABLE EXECUTE#

This connector supports the following commands for use with ALTER TABLE EXECUTE:

collect_statistics#

The collect_statistics command is used with Managed statistics to collect statistics for a table and its columns.

The following statement collects statistics for the example_table table and all of its columns:

ALTER TABLE example_table EXECUTE collect_statistics;

Collecting statistics for all columns in a table may be unnecessarily performance-intensive, especially for wide tables. To only collect statistics for a subset of columns, you can include the columns parameter with an array of column names. For example:

ALTER TABLE example_table
    EXECUTE collect_statistics(columns => ARRAY['customer','line_item']);

ALTER TABLE RENAME TO#

The connector does not support renaming tables across multiple schemas. For example, the following statement is supported:

ALTER TABLE example.schema_one.table_one RENAME TO example.schema_one.table_two

The following statement attempts to rename a table across schemas, and therefore is not supported:

ALTER TABLE example.schema_one.table_one RENAME TO example.schema_two.table_two

ALTER SCHEMA#

The connector supports renaming a schema with the ALTER SCHEMA RENAME statement. ALTER SCHEMA SET AUTHORIZATION is not supported.

Fault-tolerant execution support#

The connector supports Fault-tolerant execution of query processing. Read and write operations are both supported with any retry policy.

Table functions#

The connector provides specific table functions to access PostgreSQL.

query(varchar) -> table#

The query function allows you to query the underlying database directly. It requires syntax native to PostgreSQL, because the full query is pushed down and processed in PostgreSQL. This can be useful for accessing native features which are not available in SEP or for improving query performance in situations where running a query natively may be faster.

The native query passed to the underlying data source is required to return a table as a result set. Only the data source performs validation or security checks for these queries using its own configuration. Trino does not perform these tasks. Only use passthrough queries to read data.

As a simple example, query the example catalog and select an entire table:

SELECT
  *
FROM
  TABLE(
    example.system.query(
      query => 'SELECT
        *
      FROM
        tpch.nation'
    )
  );

As a practical example, you can leverage frame exclusion from PostgresSQL when using window functions:

SELECT
  *
FROM
  TABLE(
    example.system.query(
      query => 'SELECT
        *,
        array_agg(week) OVER (
          ORDER BY
            week
          ROWS
            BETWEEN 2 PRECEDING
            AND 2 FOLLOWING
            EXCLUDE GROUP
        ) AS week,
        array_agg(week) OVER (
          ORDER BY
            day
          ROWS
            BETWEEN 2 PRECEDING
            AND 2 FOLLOWING
            EXCLUDE GROUP
        ) AS all
      FROM
        test.time_data'
    )
  );

Note

The query engine does not preserve the order of the results of this function. If the passed query contains an ORDER BY clause, the function result may not be ordered as expected.

Performance#

The connector includes a number of performance features detailed in the following sections.

Table statistics#

The PostgreSQL connector can use table and column statistics for cost based optimizations, to improve query processing performance based on the actual data in the data source.

The statistics are collected by PostgreSQL and retrieved by the connector.

To collect statistics for a table, execute the following statement in PostgreSQL.

ANALYZE table_schema.table_name;

Refer to PostgreSQL documentation for additional ANALYZE options.

Managed statistics#

The connector supports Managed statistics allowing SEP to collect and store table and column statistics that can then be used for performance optimizations in query planning.

Statistics must be collected manually using the built-in collect_statistics command, see collect_statistics for details and examples.

Pushdown#

The connector supports pushdown for a number of operations:

Aggregate pushdown for the following functions:

Note

The connector performs pushdown where performance may be improved, but in order to preserve correctness an operation may not be pushed down. When pushdown of an operation may result in better performance but risks correctness, the connector prioritizes correctness.

Cost-based join pushdown#

The connector supports cost-based Join pushdown to make intelligent decisions about whether to push down a join operation to the data source.

When cost-based join pushdown is enabled, the connector only pushes down join operations if the available Table statistics suggest that doing so improves performance. Note that if no table statistics are available, join operation pushdown does not occur to avoid a potential decrease in query performance.

The following table describes catalog configuration properties for join pushdown:

Property name

Description

Default value

join-pushdown.enabled

Enable join pushdown. Equivalent catalog session property is join_pushdown_enabled.

true

join-pushdown.strategy

Strategy used to evaluate whether join operations are pushed down. Set to AUTOMATIC to enable cost-based join pushdown, or EAGER to push down joins whenever possible. Note that EAGER can push down joins even when table statistics are unavailable, which may result in degraded query performance. Because of this, EAGER is only recommended for testing and troubleshooting purposes.

AUTOMATIC

Dynamic filtering#

Dynamic filtering is enabled by default. It causes the connector to wait for dynamic filtering to complete before starting a JDBC query.

You can disable dynamic filtering by setting the dynamic-filtering.enabled property in your catalog configuration file to false.

Wait timeout#

By default, table scans on the connector are delayed up to 20 seconds until dynamic filters are collected from the build side of joins. Using a large timeout can potentially result in more detailed dynamic filters. However, it can also increase latency for some queries.

You can configure the dynamic-filtering.wait-timeout property in your catalog properties file:

dynamic-filtering.wait-timeout=1m

You can use the dynamic_filtering_wait_timeout catalog session property in a specific session:

SET SESSION example.dynamic_filtering_wait_timeout = 1s;

Compaction#

The maximum size of dynamic filter predicate, that is pushed down to the connector during table scan for a column, is configured using the domain-compaction-threshold property in the catalog properties file:

domain-compaction-threshold=100

You can use the domain_compaction_threshold catalog session property:

SET SESSION domain_compaction_threshold = 10;

By default, domain-compaction-threshold is set to 32. When the dynamic predicate for a column exceeds this threshold, it is compacted into a single range predicate.

For example, if the dynamic filter collected for a date column dt on the fact table selects more than 32 days, the filtering condition is simplified from dt IN ('2020-01-10', '2020-01-12',..., '2020-05-30') to dt BETWEEN '2020-01-10' AND '2020-05-30'. Using a large threshold can result in increased table scan overhead due to a large IN list getting pushed down to the data source.

Metrics#

Metrics about dynamic filtering are reported in a JMX table for each catalog:

jmx.current."io.trino.plugin.jdbc:name=example,type=dynamicfilteringstats"

Metrics include information about the total number of dynamic filters, the number of completed dynamic filters, the number of available dynamic filters and the time spent waiting for dynamic filters.

Predicate pushdown support#

Predicates are pushed down for most types, including UUID and temporal types, such as DATE.

The connector does not support pushdown of range predicates, such as >, <, or BETWEEN, on columns with character string types like CHAR or VARCHAR. Equality predicates, such as IN or =, and inequality predicates, such as != on columns with textual types are pushed down. This ensures correctness of results since the remote data source may sort strings differently than SEP.

In the following example, the predicate of the first query is not pushed down since name is a column of type VARCHAR and > is a range predicate. The other queries are pushed down.

-- Not pushed down
SELECT * FROM nation WHERE name > 'CANADA';
-- Pushed down
SELECT * FROM nation WHERE name != 'CANADA';
SELECT * FROM nation WHERE name = 'CANADA';

There is experimental support to enable pushdown of range predicates on columns with character string types which can be enabled by setting the postgresql.experimental.enable-string-pushdown-with-collate catalog configuration property or the corresponding enable_string_pushdown_with_collate session property to true. Enabling this configuration will make the predicate of all the queries in the above example get pushed down.

Starburst Cached Views#

The connector supports table scan redirection to improve performance and reduce load on the data source.

JDBC connection pooling#

When JDBC connection pooling is enabled, each node creates and maintains a connection pool instead of opening and closing separate connections to the data source. Each connection is available to connect to the data source and retrieve data. After completion of an operation, the connection is returned to the pool and can be reused. This improves performance by a small amount, reduces the load on any required authentication system used for establishing the connection, and helps avoid running into connection limits on data sources.

JDBC connection pooling is disabled by default. You can enable JDBC connection pooling by setting the connection-pool.enabled property to true in your catalog configuration file:

connection-pool.enabled=true

The following catalog configuration properties can be used to tune connection pooling:

JDBC connection pooling catalog configuration properties#

Property name

Description

Default value

connection-pool.enabled

Enable connection pooling for the catalog.

false

connection-pool.max-size

The maximum number of idle and active connections in the pool.

10

connection-pool.max-connection-lifetime

The maximum lifetime of a connection. When a connection reaches this lifetime it is removed, regardless of how recently it has been active.

30m

connection-pool.pool-cache-max-size

The maximum size of the JDBC data source cache.

1000

connection-pool.pool-cache-ttl

The expiration time of a cached data source when it is no longer accessed.

30m

Security#

The connector includes a number of security-related features, detailed in the following sections.

User impersonation#

The PostgreSQL connector supports user impersonation.

User impersonation can be enabled in the catalog file:

postgresql.impersonation.enabled=true

User impersonation in PostgreSQL connector is based on SET ROLE. For more details visit the PostgreSQL documentation.

Kerberos authentication#

The connector supports Kerberos authentication using either a keytab or credential cache.

To configure Kerberos authentication with a keytab, add the following catalog configuration properties to the catalog properties file:

postgresql.authentication.type=KERBEROS
kerberos.client.principal=example@example.com
kerberos.client.keytab=etc/kerberos/example.keytab
kerberos.config=etc/kerberos/krb5.conf

With this configuration the user example@example.com, defined in the principal property, is used to connect to the database, and the related Kerberos service ticket is located in the example.keytab file.

To configure Kerberos authentication with a credential cache, add the following catalog configuration properties to the catalog properties file:

postgresql.authentication.type=KERBEROS
kerberos.client.principal=example@example.com
kerberos.client.credential-cache.location=etc/kerberos/example.cache
kerberos.config=etc/kerberos/krb5.conf

In these configurations the user example@example.com, as defined in the principal property, connects to the database. The related Kerberos service ticket is located in the etc/kerberos/example.keytab file, or cache credentials in the etc/kerberos/example.cache file.

Kerberos credential pass-through#

The PostgreSQL connector can be configured to pass through Kerberos credentials, received by SEP, to the PostgreSQL database.

Configure Kerberos and SEP, following the instructions in Kerberos credential pass-through.

Then configure the connector to pass through the credentials from the server to the database in your catalog properties file and ensure the Kerberos client configuration properties are in place on all nodes.

postgresql.authentication.type=KERBEROS_PASS_THROUGH
http.authentication.krb5.config=/etc/krb5.conf
http-server.authentication.krb5.service-name=exampleServiceName
http-server.authentication.krb5.keytab=/path/to/Keytab/File

Note

When delegated Kerberos authentication is configured for the Starburst Enterprise web UI, make sure the http-server.authentication.krb5.service-name value is set to HTTP to match the configured Kerberos service name.

Now any database access via SEP is subject to the data access restrictions and permissions of the user supplied via Kerberos.

Password credential pass-through#

The connector supports password credential pass-through. To enable it, edit the catalog properties file to include the authentication type:

postgresql.authentication.type=PASSWORD_PASS_THROUGH

For more information about configurations and limitations, see Password credential pass-through.

AWS IAM authentication#

When the PostgreSQL database is deployed as an AWS RDS instance, the connector can use IAM authentication. This enhancement allows you to manage access control from SEP with IAM policies.

Configuration#

To enable IAM authentication, add the following configuration properties to the catalog configuration file:

postgresql.authentication.type=AWS
connection-user=<RDS username>
aws.region-name=<AWS region>
aws.token-expiration-timeout=10m

You can also configure the connector to assume a specific IAM role for authentication before creating the access token, in order to apply policies specific to SEP. Alongside this role, you must include an (informal) external identifier of a user to assume this role.

To apply an IAM role to the connector, add the following configuration properties:

aws.iam-role=<role_arn>
aws.external-id=<external_id>

This table describes the configuration properties for IAM authentication:

IAM configuration properties#

Property name

Description

connection-user

The database account used to access the RDS database instance.

aws.region-name

The name of the AWS region in which the RDS instance is deployed.

aws.iam-role

(Optional) Set an IAM role to assume for authentication before creating the access token. If set, aws.external-id must be configured as well.

aws.external-id

(Optional) The informal identifier of the user who assumes the IAM role set in aws.iam-role.

aws.token-expiration-timeout

The amount of time to keep the generated RDS access tokens for each user before they are regenerated. The maximum value is 15 minutes. Defaults to 10m.

aws.access-key

The access key of the principal to authenticate with for the token generator service. Used for fixed authentication, setting this property disables automatic authentication.

aws.secret-key

The secret key of the principal to authenticate with for the token generator service. Used for fixed authentication, setting this property disables automatic authentication.

aws.session-token

(Optional) A session token for temporary credentials, such as credentials obtained from SSO. Used for fixed authentication, setting this property disables automatic authentication.

Authentication#

By default the connector attempts to automatically obtain its authentication credentials from the environment. The default credential provider chain attempts to obtain credentials from the following sources, in order:

  1. Environment variables: AWS_ACCESS_KEY_ID and AWS_SECRET_ACCESS_KEY, or AWS_ACCESS_KEY and AWS_SECRET_KEY.

  2. Java system properties: aws.accessKeyId and aws.secretKey.

  3. Web identity token: credentials from the environment or container.

  4. Credential profiles file: a profiles file at the default location (~/.aws/credentials) shared by all AWS SDKs and the AWS CLI.

  5. EC2 service credentials: credentials delivered through the Amazon EC2 container service, assuming the security manager has permission to access the value of the AWS_CONTAINER_CREDENTIALS_RELATIVE_URI environment variable.

  6. Instance profile credentials: credentials delievered through the Amazon EC2 metadata service.

If the SEP cluster is running on an EC2 instance, these credentials most likely come from the metadata service.

Alternatively, you can set fixed credentials for authentication. This option disables the container’s automatic attempt to locate credentials. To use fixed credentials for authentication, set the following configuration properties:

aws.access-key=<access_key>
aws.secret-key=<secret_key>

# (Optional) You can use temporary credentials. For example, you can use temporary credentials from SSO
aws.session-token=<session_token>