|
| 1 | +--- |
| 2 | +myst: |
| 3 | + substitutions: |
| 4 | + default_domain_compaction_threshold: '`32`' |
| 5 | +--- |
| 6 | + |
| 7 | +# HsqlDB connector |
| 8 | + |
| 9 | +```{raw} html |
| 10 | +<img src="../_static/img/hsqldb.png" class="connector-logo"> |
| 11 | +``` |
| 12 | + |
| 13 | +The HsqlDB connector allows querying and creating tables in an external HsqlDB |
| 14 | +database (ie: HyperSQL database). |
| 15 | + |
| 16 | +## Requirements |
| 17 | + |
| 18 | +To connect to HsqlDB, you need: |
| 19 | + |
| 20 | +- HsqlDB version 2.7.3. |
| 21 | +- Network access from the Trino coordinator and workers to HsqlDB. |
| 22 | + Port 9001 is the default port. |
| 23 | + |
| 24 | +## Configuration |
| 25 | + |
| 26 | +To configure the HsqlDB connector, create a catalog properties file in |
| 27 | +`etc/catalog` named, for example, `example.properties`, to mount the HsqlDB |
| 28 | +connector as the `example` catalog. Create the file with the following |
| 29 | +contents, replacing the connection properties as appropriate for your setup: |
| 30 | + |
| 31 | +```properties |
| 32 | +connector.name=hsqldb |
| 33 | +connection-url=jdbc:hsqldb:hsql://<host>:<port>/<dbname> |
| 34 | +connection-user=SA |
| 35 | +connection-password= |
| 36 | +``` |
| 37 | + |
| 38 | +The `connection-url` defines the connection information and parameters to pass |
| 39 | +to the HsqlDB JDBC driver. The supported parameters for the URL are |
| 40 | +available in the [HyperSQL User Guide](https://hsqldb.org/doc/2.0/guide/guide.html#dpc_connection_url). |
| 41 | + |
| 42 | +The `connection-user` and `connection-password` are typically required and |
| 43 | +determine the user credentials for the connection, often a service user. You can |
| 44 | +use {doc}`secrets </security/secrets>` to avoid actual values in the catalog |
| 45 | +properties files. |
| 46 | + |
| 47 | +```{include} jdbc-authentication.fragment |
| 48 | +``` |
| 49 | + |
| 50 | +```{include} jdbc-common-configurations.fragment |
| 51 | +``` |
| 52 | + |
| 53 | +```{include} jdbc-domain-compaction-threshold.fragment |
| 54 | +``` |
| 55 | + |
| 56 | +```{include} jdbc-case-insensitive-matching.fragment |
| 57 | +``` |
| 58 | + |
| 59 | +```{include} non-transactional-insert.fragment |
| 60 | +``` |
| 61 | + |
| 62 | +(hsqldb-fte-support)= |
| 63 | +### Fault-tolerant execution support |
| 64 | + |
| 65 | +The connector supports {doc}`/admin/fault-tolerant-execution` of query |
| 66 | +processing. Read and write operations are both supported with any retry policy. |
| 67 | + |
| 68 | +## Querying HsqlDB |
| 69 | + |
| 70 | +The HsqlDB connector provides access to all schemas visible to the specified |
| 71 | +user in the configured database. For the following examples, assume the HsqlDB |
| 72 | +catalog is `example`. |
| 73 | + |
| 74 | +You can see the available schemas by running `SHOW SCHEMAS`: |
| 75 | + |
| 76 | +``` |
| 77 | +SHOW SCHEMAS FROM example; |
| 78 | +``` |
| 79 | + |
| 80 | +If you have a schema named `web`, you can view the tables |
| 81 | +in this schema by running `SHOW TABLES`: |
| 82 | + |
| 83 | +``` |
| 84 | +SHOW TABLES FROM example.web; |
| 85 | +``` |
| 86 | + |
| 87 | +You can see a list of the columns in the `clicks` table in the `web` database |
| 88 | +using either of the following: |
| 89 | + |
| 90 | +``` |
| 91 | +DESCRIBE example.web.clicks; |
| 92 | +SHOW COLUMNS FROM example.web.clicks; |
| 93 | +``` |
| 94 | + |
| 95 | +Finally, you can query the `clicks` table in the `web` schema: |
| 96 | + |
| 97 | +``` |
| 98 | +SELECT * FROM example.web.clicks; |
| 99 | +``` |
| 100 | + |
| 101 | +If you used a different name for your catalog properties file, use |
| 102 | +that catalog name instead of `example` in the above examples. |
| 103 | + |
| 104 | +% hsqldb-type-mapping: |
| 105 | + |
| 106 | +## Type mapping |
| 107 | + |
| 108 | +Because Trino and HsqlDB each support types that the other does not, this |
| 109 | +connector {ref}`modifies some types <type-mapping-overview>` when reading or |
| 110 | +writing data. Data types may not map the same way in both directions between |
| 111 | +Trino and the data source. Refer to the following sections for type mapping in |
| 112 | +each direction. |
| 113 | + |
| 114 | +### HsqlDB type to Trino type mapping |
| 115 | + |
| 116 | +The connector maps HsqlDB types to the corresponding Trino types according |
| 117 | +to the following table: |
| 118 | + |
| 119 | +:::{list-table} HsqlDB type to Trino type mapping |
| 120 | +:widths: 30, 30, 50 |
| 121 | +:header-rows: 1 |
| 122 | + |
| 123 | +* - HsqlDB type |
| 124 | + - Trino type |
| 125 | + - Notes |
| 126 | +* - `BOOLEAN` |
| 127 | + - `BOOLEAN` |
| 128 | + - |
| 129 | +* - `TINYINT` |
| 130 | + - `TINYINT` |
| 131 | + - |
| 132 | +* - `SMALLINT` |
| 133 | + - `SMALLINT` |
| 134 | + - |
| 135 | +* - `INT`, `INTEGER` |
| 136 | + - `INTEGER` |
| 137 | + - |
| 138 | +* - `BIGINT` |
| 139 | + - `BIGINT` |
| 140 | + - |
| 141 | +* - `DOUBLE`, `FLOAT` |
| 142 | + - `DOUBLE` |
| 143 | + - |
| 144 | +* - `DECIMAL(p,s)`, `DEC(p,s)`, `NUMERIC(p,s)` |
| 145 | + - `DECIMAL(p,s)` |
| 146 | + - |
| 147 | +* - `CHAR(n)`, `CHARACTER(n)` |
| 148 | + - `CHAR(n)` |
| 149 | + - |
| 150 | +* - `VARCHAR(n)`, `CHARACTER VARYING(n)`, `CLOB(n)` |
| 151 | + - `VARCHAR(n)` |
| 152 | + - |
| 153 | +* - `BLOB` |
| 154 | + - `VARBINARY` |
| 155 | + - |
| 156 | +* - `VARBINARY(n)` |
| 157 | + - `VARBINARY` |
| 158 | + - |
| 159 | +* - `DATE` |
| 160 | + - `DATE` |
| 161 | + - |
| 162 | +* - `TIME(n)` |
| 163 | + - `TIME(n)` |
| 164 | + - |
| 165 | +* - `TIME(n) WITH TIME ZONE` |
| 166 | + - `TIME(n) WITH TIME ZONE` |
| 167 | + - |
| 168 | +::: |
| 169 | + |
| 170 | +No other types are supported. |
| 171 | + |
| 172 | +### Trino type mapping to HsqlDB type mapping |
| 173 | + |
| 174 | +The connector maps Trino types to the corresponding HsqlDB types according |
| 175 | +to the following table: |
| 176 | + |
| 177 | +:::{list-table} Trino type mapping to HsqlDB type mapping |
| 178 | +:widths: 30, 25, 50 |
| 179 | +:header-rows: 1 |
| 180 | + |
| 181 | +* - Trino type |
| 182 | + - HsqlDB type |
| 183 | + - Notes |
| 184 | +* - `BOOLEAN` |
| 185 | + - `BOOLEAN` |
| 186 | + - |
| 187 | +* - `TINYINT` |
| 188 | + - `TINYINT` |
| 189 | + - |
| 190 | +* - `SMALLINT` |
| 191 | + - `SMALLINT` |
| 192 | + - |
| 193 | +* - `INTEGER` |
| 194 | + - `INT`, `INTEGER` |
| 195 | + - |
| 196 | +* - `BIGINT` |
| 197 | + - `BIGINT` |
| 198 | + - |
| 199 | +* - `DOUBLE` |
| 200 | + - `DOUBLE` |
| 201 | + - |
| 202 | +* - `DECIMAL(p,s)` |
| 203 | + - `DECIMAL(p,s)` |
| 204 | + - |
| 205 | +* - `CHAR(n)` |
| 206 | + - `CHAR(n)` |
| 207 | + - |
| 208 | +* - `VARCHAR(n)` |
| 209 | + - `VARCHAR(n)` |
| 210 | + - |
| 211 | +* - `VARBINARY(n)` |
| 212 | + - `VARBINARY(n)` |
| 213 | + - |
| 214 | +* - `DATE` |
| 215 | + - `DATE` |
| 216 | + - |
| 217 | +* - `TIME(n)` |
| 218 | + - `TIME(n)` |
| 219 | + - |
| 220 | +* - `TIME(n) WITH TIME ZONE` |
| 221 | + - `TIME(n) WITH TIME ZONE` |
| 222 | + - |
| 223 | +::: |
| 224 | + |
| 225 | +No other types are supported. |
| 226 | + |
| 227 | +Complete list of [HsqlDB data types](https://hsqldb.org/doc/2.0/guide/guide.html#sgc_data_type_guide). |
| 228 | + |
| 229 | +```{include} jdbc-type-mapping.fragment |
| 230 | +``` |
| 231 | + |
| 232 | +(hsqldb-sql-support)= |
| 233 | +## SQL support |
| 234 | + |
| 235 | +The connector provides read access and write access to data and metadata in |
| 236 | +a HsqlDB database. In addition to the {ref}`globally available |
| 237 | +<sql-globally-available>` and {ref}`read operation <sql-read-operations>` |
| 238 | +statements, the connector supports the following features: |
| 239 | + |
| 240 | +- {doc}`/sql/insert` |
| 241 | +- {doc}`/sql/update` |
| 242 | +- {doc}`/sql/delete` |
| 243 | +- {doc}`/sql/truncate` |
| 244 | +- {doc}`/sql/create-table` |
| 245 | +- {doc}`/sql/create-table-as` |
| 246 | +- {doc}`/sql/drop-table` |
| 247 | +- {doc}`/sql/alter-table` |
| 248 | +- {doc}`/sql/create-schema` |
| 249 | +- {doc}`/sql/drop-schema` |
| 250 | + |
| 251 | +```{include} sql-update-limitation.fragment |
| 252 | +``` |
| 253 | + |
| 254 | +```{include} sql-delete-limitation.fragment |
| 255 | +``` |
| 256 | + |
| 257 | +### Procedures |
| 258 | + |
| 259 | +```{include} jdbc-procedures-flush.fragment |
| 260 | +``` |
| 261 | +```{include} procedures-execute.fragment |
| 262 | +``` |
| 263 | + |
| 264 | +### Table functions |
| 265 | + |
| 266 | +The connector provides specific {doc}`table functions </functions/table>` to |
| 267 | +access HsqlDB. |
| 268 | + |
| 269 | +(hsqldb-query-function)= |
| 270 | +#### `query(varchar) -> table` |
| 271 | + |
| 272 | +The `query` function allows you to query the underlying database directly. It |
| 273 | +requires syntax native to HsqlDB, because the full query is pushed down and |
| 274 | +processed in HsqlDB. This can be useful for accessing native features which are |
| 275 | +not available in Trino or for improving query performance in situations where |
| 276 | +running a query natively may be faster. |
| 277 | + |
| 278 | +```{include} query-passthrough-warning.fragment |
| 279 | +``` |
| 280 | + |
| 281 | +As an example, query the `example` catalog and select the age of employees by |
| 282 | +using `TIMESTAMPDIFF` and `CURRENT_DATE`: |
| 283 | + |
| 284 | +``` |
| 285 | +SELECT |
| 286 | + age |
| 287 | +FROM |
| 288 | + TABLE( |
| 289 | + example.system.query( |
| 290 | + query => 'SELECT |
| 291 | + TIMESTAMPDIFF( |
| 292 | + YEAR, |
| 293 | + date_of_birth, |
| 294 | + CURRENT_DATE() |
| 295 | + ) AS age |
| 296 | + FROM |
| 297 | + tiny.employees' |
| 298 | + ) |
| 299 | + ); |
| 300 | +``` |
| 301 | + |
| 302 | +```{include} query-table-function-ordering.fragment |
| 303 | +``` |
| 304 | + |
| 305 | +## Performance |
| 306 | + |
| 307 | +The connector includes a number of performance improvements, detailed in the |
| 308 | +following sections. |
| 309 | + |
| 310 | +(hsqldb-pushdown)= |
| 311 | +### Pushdown |
| 312 | + |
| 313 | +The connector supports pushdown for a number of operations: |
| 314 | + |
| 315 | +- {ref}`join-pushdown` |
| 316 | +- {ref}`limit-pushdown` |
| 317 | +- {ref}`topn-pushdown` |
| 318 | + |
| 319 | +{ref}`Aggregate pushdown <aggregation-pushdown>` for the following functions: |
| 320 | + |
| 321 | +- {func}`avg` |
| 322 | +- {func}`count` |
| 323 | +- {func}`max` |
| 324 | +- {func}`min` |
| 325 | +- {func}`sum` |
| 326 | + |
| 327 | +```{include} pushdown-correctness-behavior.fragment |
| 328 | +``` |
| 329 | + |
| 330 | +```{include} no-pushdown-text-type.fragment |
| 331 | +``` |
0 commit comments