SQL Server connector#
The SQL Server connector lets you query and create tables in an external Microsoft SQL Server database. This can be used to join data between different systems like SQL Server and Hive, or between two different SQL Server instances.
SEP includes additional enterprise features that are built on top of the existing Trino connector functionality. For more information on key feature differences between Trino and SEP, see the connectors feature matrix.
Requirements#
To connect to SQL Server, you need:
SQL Server 2012 or higher, or Azure SQL Database.
Network access from the SEP coordinator and workers to SQL Server. Port 1433 is the default port.
A valid Starburst Enterprise license.
Configuration#
To configure the SQL Server connector, create a catalog properties file that
specifies the SQL Server connector by setting the connector.name
to
sqlserver
.
For example, to access a database as example
, create the file
etc/catalog/example.properties
. Replace the connection properties as
appropriate for your setup:
connector.name=sqlserver
connection-url=jdbc:sqlserver://<host>:<port>;databaseName=<databaseName>;encrypt=false
connection-user=root
connection-password=secret
The connection-url
defines the connection information and parameters to pass
to the SQL Server JDBC driver. The supported parameters for the URL are
available in the SQL Server JDBC driver
documentation.
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 exposing actual values in the
catalog properties files.
Connection security#
The JDBC driver and the connector automatically use Transport Layer Security (TLS) encryption and certificate validation. This requires a suitable TLS certificate configured on your SQL Server database host.
If you do not have the necessary configuration established, you can disable
encryption in the connection string with the encrypt
property:
connection-url=jdbc:sqlserver://<host>:<port>;databaseName=<databaseName>;encrypt=false
Additional parameters like trustServerCertificate
, hostNameInCertificate
,
trustStore
, and trustStorePassword
are detailed in the TLS section of SQL
Server 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 |
---|---|
|
Type of the credential provider. Must be one of |
|
Connection user name. |
|
Connection password. |
|
Name of the extra credentials property, whose value to use as the user
name. See |
|
Name of the extra credentials property, whose value to use as the password. |
|
Location of the properties file where credentials are present. It must
contain the |
|
The location of the Java Keystore file, from which to read credentials. |
|
File format of the keystore file, for example |
|
Password for the key store. |
|
Name of the key store entity to use as the user name. |
|
Password for the user name key store entity. |
|
Name of the key store entity to use as the password. |
|
Password for the password key store entity. |
Multiple SQL Server databases or servers#
The SQL Server connector can only access a single SQL Server database within a single catalog. If you have multiple SQL Server databases, or want to connect to multiple SQL Server instances, you must configure multiple instances of the SQL Server connector. See also, Dynamic catalog selection
To add another catalog, add a new properties file to etc/catalog
. For example,
if you name the property file sales.properties
, SEP creates a catalog
named sales
.
Another option to access multiple databases on a SQL Server cluster is to enable
the sqlserver.database-prefix-for-schema.enabled
catalog configuration
property, as described in the following table:
Property name |
Description |
Default |
---|---|---|
|
Allow access to other databases in SQL Server by including the database name in double quotes with the schema name: SELECT *
FROM catalog."database.schema".table
When enabled, |
false |
Dynamic catalog selection#
The default configuration, similar to the etc/example.properties
file,
enables the connection to one database running on a SQL Server instance.
connector.name=sqlserver
connection-url=jdbc:sqlserver://dbserver.example.com:1443/exampledb;encrypt=false
The connector supports connecting to multiple SQL Server databases using a
single catalog by setting an override_catalog
session property. This support
has to be enabled in the catalog properties file with the
sqlserver.override-catalog.enabled
property:
connector.name=sqlserver
connection-url=jdbc:sqlserver://dbserver.example.com:1443/exampledb;encrypt=false
sqlserver.override-catalog.enabled=true
The previously mentioned example lets you query any table in any schema in the
database exampledb
on the SQL Server dbserver
. The user that was specified
in connection-user
must have sufficient access rights.
SELECT * FROM example.exampleschema.exampletable;
In order to query another database, such as testdb
, you must override the
database configured in the catalog. Then you can query that database in
the current user session:
SET SESSION example.override_catalog=testdb;
SELECT * FROM example.testdbschema.testdbtable;
Note
The access rights to the databases, schemas, tables, and actual rows are determined by the configured user for the connection. This also applies to other security setups like impersonation or Apache Ranger integration. Make sure these access rights are as restrictive as required.
General configuration properties#
The following table describes general catalog configuration properties for the connector:
Property name |
Description |
---|---|
|
Support case insensitive schema and table names. Defaults to |
|
Duration for which case insensitive schema and table
names are cached. Defaults to |
|
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 |
|
Frequency with which Trino checks the name matching configuration file
for changes. The duration value defaults to |
|
Duration for which metadata, including table and
column statistics, is cached. Defaults to |
|
Cache the fact that metadata, including table and column statistics, is
not available. Defaults to |
|
Duration for which schema metadata is cached.
Defaults to the value of |
|
Duration for which table metadata is cached.
Defaults to the value of |
|
Duration for which tables statistics are cached.
Defaults to the value of |
|
Maximum number of objects stored in the metadata cache. Defaults to |
|
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 |
|
Push down dynamic filters into JDBC queries. Defaults to |
|
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 |
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 exampletrino-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
256
for this threshold.
Specific configuration properties#
The SQL Server connector supports additional catalog properties to configure the behavior of the connector.
Property name |
Description |
---|---|
|
Control the automatic use of snapshot isolation for transactions issued by
Trino in SQL Server. Defaults to |
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.
Fault-tolerant execution support#
The connector supports Fault-tolerant execution of query processing. Read and write operations are both supported with any retry policy.
Querying SQL Server#
The SQL Server connector provides access to all schemas visible to the specified user in the configured database.
Run SHOW SCHEMAS
to see all the abvailable schemas in your SQL server
database:
SHOW SCHEMAS FROM example;
If you used a different name for your catalog properties file, use that catalog
name instead of example
.
Example:
If you have a schema named web
, you can run SHOW TABLES
to view the tables
in the schema:
SHOW TABLES FROM example.web;
To see a list of the columns in the clicks
table in the web
database, run
either of the following:
DESCRIBE example.web.clicks;
SHOW COLUMNS FROM example.web.clicks;
To access the clicks
table in the web
database, run the following:
SELECT * FROM example.web.clicks;
Type mapping#
Because Trino and SQL Server 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.
SQL Server type to Trino type mapping#
The connector maps SQL Server types to the corresponding Trino types following this table:
SQL Server database type |
Trino type |
Notes |
---|---|---|
|
|
|
|
|
SQL Server |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
Trino type to SQL Server type mapping#
The connector maps Trino types to the corresponding SQL Server types following this table:
Trino type |
SQL Server type |
Notes |
---|---|---|
|
|
|
|
|
Trino only supports writing values belonging to |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
See the Microsoft documentation for the complete list of SQL Server data types.
Numeric type mapping#
For SQL Server FLOAT[(n)]
:
If
n
is not specified maps to TrinoDouble
If
1 <= n <= 24
maps to TrinoREAL
If
24 < n <= 53
maps to TrinoDOUBLE
Character type mapping#
For Trino CHAR(n)
:
If
1 <= n <= 4000
maps SQL ServerNCHAR(n)
If
n > 4000
maps SQL ServerNVARCHAR(max)
For Trino VARCHAR(n)
:
If
1 <= n <= 4000
maps SQL ServerNVARCHAR(n)
If
n > 4000
maps SQL ServerNVARCHAR(max)
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 |
---|---|---|
|
Configure how unsupported column data types are handled:
The respective catalog session property is |
|
|
Allow forced mapping of comma separated lists of data types to convert to
unbounded |
SQL support#
The connector provides read access and write access to data and metadata in SQL Server. In addition to the globally available and read operation statements, the connector supports the following statements:
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
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
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 catalog property sqlserver.non-transactional-insert.enabled
or the
corresponding catalog session property non_transactional_insert
to true
.
In rare cases when exceptions occur during the insert operation, data in the target table can be corrupted. Since transactions have been disabled, no rollback can be performed.
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();
system.execute('query')
#
The execute
procedure allows you to execute a query in the underlying data
source directly. The query must use supported syntax of the connected data
source. Use the procedure to access features which are not available in Trino
or to execute queries that return no result set and therefore can not be used
with the query
or raw_query
pass-through table function. Typical use cases
are statements that create or alter objects, and require native feature such
as constraints, default values, automatic identifier creation, or indexes.
Queries can also invoke statements that insert, update, or delete data, and do
not return any data as a result.
The query text is not parsed by Trino, only passed through, and therefore only subject to any security or access control of the underlying data source.
The following example sets the current database to the example_schema
of the
example
catalog. Then it calls the procedure in that schema to drop the
default value from your_column
on your_table
table using the standard SQL
syntax in the parameter value assigned for query
:
USE example.example_schema;
CALL system.execute(query => 'ALTER TABLE your_table ALTER COLUMN your_column DROP DEFAULT');
Verify that the specific database supports this syntax, and adapt as necessary based on the documentation for the specific connected database and database version.
Table functions#
The connector provides specific table functions to access SQL Server.
query(varchar) -> table
#
The query
function lets you to query the underlying database directly. It
requires syntax native to SQL Server, because the full query is pushed down and
processed in SQL Server. This can be useful for accessing native features which
are not implemented 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.
For example, query the example
catalog and select the top 10 percent of
nations by population:
SELECT
*
FROM
TABLE(
example.system.query(
query => 'SELECT
TOP(10) PERCENT *
FROM
tpch.nation
ORDER BY
population DESC'
)
);
procedure(varchar) -> table
#
The procedure
function lets you run stored procedures on the underlying
database directly. It requires syntax native to SQL Server, because the full
query is pushed down and processed in SQL Server. In order to use this table
function set sqlserver.experimental.stored-procedure-table-function-enabled
to
true
.
Note
The procedure
function does not support running StoredProcedures that return
multiple statements, use a non-select statement, use output parameters, or use
conditional statements.
Warning
This feature is experimental only. The function has security implication and syntax might change and be backward incompatible.
The following example runs the stored procedure employee_sp
in the example
catalog and the example_schema
schema in the underlying SQL Server database:
SELECT
*
FROM
TABLE(
example.system.procedure(
query => 'EXECUTE example_schema.employee_sp'
)
);
If the stored procedure employee_sp
requires any input append the parameter
value to the procedure statement:
SELECT
*
FROM
TABLE(
example.system.procedure(
query => 'EXECUTE example_schema.employee_sp 0'
)
);
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.
Parallelism#
The connector is able to read data from SQL Server using multiple parallel connections for tables partitioned as described in the SQL Server partitioning documentation.
Property name |
Description |
Default |
---|---|---|
|
Defines the maximum number of parallel splits during query execution. Use
this property to limit the number of splits for tables with a large number
of partitions to avoid opening a large number of connections. The default
value of |
1 |
In the event that multiple parallel connections result in a deadlocked state, the connector attempts to retry the operation up to 3 times.
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.
Table statistics#
The SQL Server 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 SQL Server and retrieved by the connector.
The connector can use information stored in single-column statistics. SQL Server Database can automatically create column statistics for certain columns. To manually create statistics for a certain column, run the following statement:
CREATE STATISTICS example_statistics_name ON table_schema.table_name (column_name);
SQL Server Database routinely updates the statistics. In some cases, you may want to manually update statistics. To manually update statistics, run the following statement in SQL Server Database.
UPDATE STATISTICS table_schema.table_name;
Refer to SQL Server documentation for information about options, limitations, and additional considerations.
Managed statistics#
The connector supports Managed statistics which lets SEP 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 ALTER TABLE EXECUTE for details and
examples.
Pushdown#
The connector supports pushdown for a number of operations:
In addition, the connector supportsAggregate 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 |
---|---|---|
|
Enable join pushdown. Equivalent catalog
session property is
|
|
|
Strategy used to evaluate whether join operations are pushed down. Set to
|
|
Predicate pushdown support#
The connector supports pushdown of predicates on VARCHAR
and NVARCHAR
columns if the underlying columns in SQL Server use a case-sensitive
collation.
The following operators are pushed down:
=
<>
IN
NOT IN
To ensure correct results, operators are not pushed down for columns using a case-insensitive collation.
Bulk insert#
Use the bulk copy API to drastically speed up write operations.
Enable bulk copying and a lock on the destination table to meet minimal logging requirements.
The following table shows the relevant catalog configuration properties and their default values:
Property name |
Description |
Default |
---|---|---|
|
Use the SQL Server bulk copy API for writes. The corresponding catalog
session property is |
|
|
Obtain a bulk update lock on the destination table for write operations. The
corresponding catalog session property is
|
|
Limitations:
Column names with leading and trailing spaces are not supported.
Starburst Cached Views#
The connector supports table scan redirection to improve performance and reduce load on the data source.
Data compression#
You can specify the data compression policy for SQL Server
tables
with the data_compression
table property. Valid policies are NONE
, ROW
or
PAGE
.
Example:
CREATE TABLE example_schema.scientists (
recordkey VARCHAR,
name VARCHAR,
age BIGINT,
birthday DATE
)
WITH (
data_compression = 'ROW'
);
Security#
The connector includes a number of security-related features, detailed in the following sections.
User impersonation#
The connector supports user impersonation.
To enable user impersonation in the catalog file, add the following property:
sqlserver.impersonation.enabled=true
User impersonation in SQL Server connector is based on EXECUTE AS USER
. For
more information, see the SQL Server
documentation.
Kerberos authentication#
The connector supports Kerberos authentication using a keytab. To configure Kerberos authentication, add the following properties to the catalog properties file:
sqlserver.authentication.type=KERBEROS
kerberos.client.principal=example@example.com
kerberos.client.keytab=etc/kerberos/example.keytab
kerberos.config=etc/kerberos/krb5.conf
In this configuration, the user example@example.com
connects to the database.
The related Kerberos service ticket is located in the
etc/kerberos/example.keytab
file defined in the kerberos.client.keytab
property.
Kerberos credential pass-through#
You can configure SQL Server to pass through Kerberos credentials, received by SEP, to the SQL server database. To configure credential pass-through in Kerberos and SEP, see Kerberos credential pass-through.
After you configure Kerberos and SEP, edit the catalog properties file to enable the connector to pass the credentials to the SQL Server database.
Confirm the correct Kerberos client configuration properties in the catalog properties file. For example:
sqlserver.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 SQL server database accessed using SEP is subject to the Kerberos-defined data access restrictions and permissions.
Constrained delegation#
The connector supports constrained delegation, where the user ticket is not attached as part of a service ticket and instead uses the Service for User to Proxy (S4U2proxy) extension to access the underlying data source based on the service ticket generated by the user.
To enable constrained delegation, the following configuration properties must
be set both in the catalog configuration and the config.properties
for the
coordinator and all workers:
http-server.authentication.krb5.constrained-delegation.enabled=true
http-server.authentication.krb5.delegation.service-name=${delegated_service_name}
Constrained delegation requires the server to have a ticket-granting ticket
(TGT). To specify a name type, use the
http-server.authentication.krb5.delegation.name-type
configuration property.
All services involved must have permission to delegate to each other, including
the SEP coordinator and worker nodes’
http-server.authentication.krb5.service-name
having permission to delegate to
itself, all workers, and the underlying data source.
Password credential pass-through#
The connector supports password credential pass-through. To enable it, edit the catalog properties file to include the authentication type:
sqlserver.authentication.type=PASSWORD_PASS_THROUGH
NTLM authentication#
The connector supports NTLM authentication as an alternative to Kerberos authentication for environments where Kerberos auth is not feasible.
To enable NTLM authentication, configure the following properties in the catalog properties file:
connection-user=ad_username
connection-password=ad_password
sqlserver.authentication.type=NTLM_PASSWORD
In this configuration, the user ad_username
and password ad_password
are
Active Directory credentials for a single user who has underlying access to the
data source.
TLS/HTTPS settings#
Microsoft strongly suggests encrypting traffic using TLS when using NTLM authentication.
If you have globally-trusted certificates installed on both SEP and the data
source, enable TLS by appending the encrypt=true
parameter to the
connection-url
catalog configuration property:
connection-url=jdbc:sqlserver://<host>:<port>;databaseName=<databaseName>;encrypt=true
If you do not have globally-trusted certificates installed, you can instead use certificates trusted by a custom truststore.
The following catalog configuration properties manage custom truststore configuration for the SQL Server connector:
Property name |
Description |
---|---|
|
Path to the truststore file in SEP. |
|
Password used to generate the truststore file |
|
The type of truststore. Supports either |
The following catalog properties configuration specifies a custom JKS truststore to enable TLS for NTLM authentication:
sqlserver.tls.truststore-path=path/to/truststore.jks
sqlserver.tls.truststore-password=insecurepassword
sqlserver.tls.truststore-type=JKS
NTLM credential pass-through#
The connector supports NTLM credential pass-through. To enable this, edit the catalog properties file to include the authentication type:
sqlserver.authentication.type=NTLM_PASSWORD_PASS_THROUGH