SingleStore connector#
The SingleStore (formerly known as MemSQL) connector lets you query and create tables in an external SingleStore database.
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 SingleStore, you need:
SingleStore version 7.1.4 or higher.
Network access from the SEP coordinator and workers to SingleStore. Port 3306 is the default port.
A valid Starburst Enterprise license.
Configuration#
To configure the Singlestore connector, create a catalog properties file that
specifies the Singlestore connector by setting the connector.name
to
Singlestore
.
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=singlestore
connection-url=jdbc:singlestore://example.net:3306
connection-user=root
connection-password=secret
The connection-url
defines the connection information and parameters to pass
to the SingleStore JDBC driver. The supported parameters for the URL are
available in the SingleStore 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#
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.
To enable TLS append useSsl=true
to the connection-url
configuration
property:
connection-url=jdbc:singlestore://example.net:3306/?useSsl=true
For more information on TLS configuration options, see the JDBC driver documentation.
Multiple SingleStore servers#
You can have as many catalogs as you need. If you have additional SingleStore servers, configure another catalog.
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
.
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.
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 SingleStore#
The SingleStore connector provides a schema for every SingleStore database.
Run SHOW SCHEMAS
to see the available SingleStore databases:
SHOW SCHEMAS FROM example;
Examples#
If you used a different name for your catalog properties file, use that catalog
name instead of example
.
If you have a SingleStore database named web
, run SHOW TABLES
to see the
tables it contains:
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 Singlestore 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.
Singlestore to Trino type mapping#
The connector maps Singlestore types to the corresponding Trino types following this table:
Singlestore type |
Trino type |
Notes |
---|---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
No other types are supported.
Trino to Singlestore type mapping#
The connector maps Trino types to the corresponding Singlestore types following this table:
Trino type |
Singlestore type |
Notes |
---|---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
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).
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 a SingleStore database. 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
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
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.
Performance#
The connector includes a number of performance features, detailed in the following sections.
Parallelism#
The connector is able to read data from SingleStore using multiple parallel connections for tables partitioned as described in the SingleStore documentation.
Parallelism is disabled by default. Set the following catalog configuration property to enable parallelism:
singlestore.parallelism-type=RESULT_TABLE_PARALLELISM
When this feature is enabled, SEP reads each partition of a SingleStore table in parallel and uses materialized result tables.
Table statistics#
The SingleStore 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 SingleStore and retrieved by the connector.
Table-level statistics are based on SingleStore’s
INFORMATION_SCHEMA.TABLE_STATISTICS
table.
SingleStore can automatically update its table and column statistics. In some cases, you may want to force a statistics update. For example, after creating new columns or after changing data in the table.
To force an update, run the following statement in the SingleStore database:
ANALYZE TABLE table_name;
Note
SingleStore statistics are estimates, and SEP and SingleStore may use statistics information in different ways. For this reason, the accuracy of table and column statistics returned by the SingleStore connector might be lower than that of others connectors.
Improving statistics accuracy
You can improve statistics accuracy and access column-level statistics with
histogram statistics. Column-level statistics are based on SingleStore’s column
statistics INFORMATION_SCHEMA.ADVANCED_HISTOGRAMS
table. If that table is not
available, the information is based on the
INFORMATION_SCHEMA.OPTIMIZER_STATISTICS
table.
The ADVANCED_HISTOGRAMS
table includes additional stats such as the MIN
and
MAX
values for a column. These statistics are not available in the
LEGACY_HISTOGRAMS
table. SingleStore’s ADVANCED_HISTOGRAMS
feature requires
a cardinality_estimation_level
greater than or equal to 6.5.
To check and determine whether ADVANCED_HISTOGRAMS
are available to you,
execute the following statement in SingleStore:
SELECT
COLUMN_NAME,
IF(RANGE_STATS=1, true, false) as histograms_available,
IF(ADVANCED_HISTOGRAMS=1, 'Advanced', 'Legacy') as histogram_type
FROM INFORMATION_SCHEMA.OPTIMIZER_STATISTICS
WHERE DATABASE_NAME = 'db' AND TABLE_NAME = 'table';
If available in your SingleStore version, use the following statement
to populate the ADVANCED_HISTOGRAMS
table:
ANALYZE TABLE table_name COLUMNS ALL ENABLE;
Refer to the SingleStore 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 supports pushdown for the following aggregate functions:
count()
, alsocount(distinct x)
variance()
andvar_samp()
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.
Join pushdown#
The join-pushdown.enabled
catalog configuration property or
join_pushdown_enabled
catalog session property control whether the connector pushes
down join operations. The property defaults to false
, and enabling join
pushdowns may negatively impact performance for some queries.
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 does not support pushdown of any predicates on columns with
textual types like CHAR
or VARCHAR
.
This ensures correctness of results since the data source may compare strings
case-insensitively.
In the following example, the predicate is not pushed down for either query
since name
is a column of type VARCHAR
:
SELECT * FROM nation WHERE name > 'CANADA';
SELECT * FROM nation WHERE name = 'CANADA';
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.
Starburst Cached Views#
The connectors supports table scan redirection to improve performance and reduce load on the data source.
Security#
The connector includes a number of security-related features, detailed in the following sections.
Kerberos authentication#
The connector supports Kerberos authentication. To configure Kerberos authentication, add the following catalog configuration properties to the catalog properties file:
singlestore.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.
The SingleStore connector authenticates to Kerberos using the Java
Authentication and Authorization Service (JAAS). The file is set with the
java.security.auth.login.config
JVM system property.
If this system property is not set, the connector automatically generates a file. The file contents include values from the catalog configuration, and sets the system property to the path of the generated file.
Krb5ConnectorContext {
com.sun.security.auth.module.Krb5LoginModule required
useKeyTab=true
storeKey=true
doNotPrompt=true
isInitiator=true
principal="${kerberos.client.principal}"
keyTab="${kerberos.client.keytab}";
};
A single JAAS configuration file is shared for the entire JVM. This means
multiple SingleStore catalogs must use the same principal and keytab. Users can
create their own JAAS configuration and set the system property in the
jvm.config
configuration. There must be a Krb5ConnectorContext
for the
connector to work correctly.