[jdbc] Add Oracle DB support (#17317)

* Allow Oracle extensions to url definition

Signed-off-by: Mark Herwege <mark.herwege@telenet.be>
This commit is contained in:
Mark Herwege 2024-09-08 22:09:51 +02:00 committed by GitHub
parent 1e007cd305
commit 6f6787b794
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
9 changed files with 427 additions and 52 deletions

View File

@ -4,11 +4,13 @@ This service writes and reads item states to and from a number of relational dat
This service allows you to persist state updates using one of several different underlying database services.
It is designed for a maximum of scalability, to store very large amounts of data and still over the years not lose its speed.
You can install JDBC persistence for many supported databases, but **only one JDBC persistence service for a single database type** should be installed and can be configured at any point in time.
The generic design makes it relatively easy for developers to integrate other databases that have JDBC drivers.
The following databases are currently supported and tested:
| Database | Tested Driver / Version |
| -------------------------------------------- |----------------------------------------------------------------------------------------------------------|
| -------------------------------------------- |---------------------------------------------------------------------------------------------------------------------------------------------|
| [Apache Derby](https://db.apache.org/derby/) | [derby-10.14.2.0.jar](https://mvnrepository.com/artifact/org.apache.derby/derby) |
| [H2](https://www.h2database.com/) | [h2-2.2.224.jar](https://mvnrepository.com/artifact/com.h2database/h2) |
| [HSQLDB](http://hsqldb.org/) | [hsqldb-2.3.3.jar](https://mvnrepository.com/artifact/org.hsqldb/hsqldb) |
@ -17,6 +19,7 @@ The following databases are currently supported and tested:
| [PostgreSQL](https://www.postgresql.org/) | [postgresql-42.4.4.jar](https://mvnrepository.com/artifact/org.postgresql/postgresql) |
| [SQLite](https://www.sqlite.org/) | [sqlite-jdbc-3.42.0.0.jar](https://mvnrepository.com/artifact/org.xerial/sqlite-jdbc) |
| [TimescaleDB](https://www.timescale.com/) | [postgresql-42.4.4.jar](https://mvnrepository.com/artifact/org.postgresql/postgresql) |
| [OracleDB](https://www.oracle.com/database/) | [com.oracle.database.jdbc.ojdbc11-23.5.0.2407.jar](https://mvnrepository.com/artifact/org.openhab.osgiify/com.oracle.database.jdbc.ojdbc11) |
## Table of Contents
@ -37,11 +40,13 @@ The following databases are currently supported and tested:
## Configuration
This service can be configured in the file `services/jdbc.cfg`.
This service can be configured in the file `services/jdbc.cfg` or through mainUI under the settings of the specific JDBC DB Add-on.
Note that the relevance of the parameters and default values may be different for specific database types.
The listed defaults are used when not overriden by the specific database Add-on.
| Property | Default | Required | Description |
| --------------------------- | ------------------------------------------------------------ | :-------: | ------------------------------------------------------------ |
| url | | Yes | JDBC URL to establish a connection to your database. Examples:<br/><br/>`jdbc:derby:./testDerby;create=true`<br/>`jdbc:h2:./testH2`<br/>`jdbc:hsqldb:./testHsqlDb`<br/>`jdbc:mariadb://192.168.0.1:3306/testMariadb`<br/>`jdbc:mysql://192.168.0.1:3306/testMysql?serverTimezone=UTC`<br/>`jdbc:postgresql://192.168.0.1:5432/testPostgresql`<br/>`jdbc:timescaledb://192.168.0.1:5432/testPostgresql`<br/>`jdbc:sqlite:./testSqlite.db`.<br/><br/>If no database is available it will be created; for example the url `jdbc:h2:./testH2` creates a new H2 database in openHAB folder. Example to create your own MySQL database directly:<br/><br/>`CREATE DATABASE 'yourDB' CHARACTER SET utf8 COLLATE utf8_general_ci;` |
| url | | Yes | JDBC URL to establish a connection to your database. Examples:<br/><br/>`jdbc:derby:./testDerby;create=true`<br/>`jdbc:h2:./testH2`<br/>`jdbc:hsqldb:./testHsqlDb`<br/>`jdbc:mariadb://192.168.0.1:3306/testMariadb`<br/>`jdbc:mysql://192.168.0.1:3306/testMysql?serverTimezone=UTC`<br/>`jdbc:postgresql://192.168.0.1:5432/testPostgresql`<br/>`jdbc:timescaledb://192.168.0.1:5432/testPostgresql`<br/>`jdbc:sqlite:./testSqlite.db`<br/>`jdbc:oracle:thin:@dbname?TNS_ADMIN=./dbname_tns_admin_folder`.<br/><br/>If no database is available it will be created; for example the url `jdbc:h2:./testH2` creates a new H2 database in openHAB folder. Example to create your own MySQL database directly:<br/><br/>`CREATE DATABASE 'yourDB' CHARACTER SET utf8 COLLATE utf8_general_ci;` |
| user | | if needed | database user name |
| password | | if needed | database user password |
| errReconnectThreshold | 0 | No | when the service is deactivated (0 means ignore) |
@ -88,6 +93,44 @@ services/jdbc.cfg
url=jdbc:postgresql://192.168.0.1:5432/testPostgresql
```
### Oracle DB Specific Configuration
Oracle connectivity has been tested on an Oracle Always Free Tier Autonomous DB 19c.
You need to configure your database connection to not use an Oracle Wallet, but use the Java Key Store (JKS).
To connect to an Oracle Autonomous Database, use the instructions at https://www.oracle.com/database/technologies/java-connectivity-to-atp.html#pre-requisites-tab, under Java Key Stores (JKS).
Your services/jdbc.cfg should contain the following minimal configuration for connecting to an Oracle Autonomous Database:
```
url=jdbc:oracle:thin:@dbname?TNS_ADMIN=./dbname_tns_admin_folder
user=openhab
password=openhab_password
```
The `TNS_ADMIN` parameter points to the directory where the the `tnsnames.ora`file, `ojdbc.properties` file and key files (from the ADB wallet download) are located.
Other Oracle DB setups may require different connection parameters.
It is advised to create a specific user with sufficient permissions and space for OpenHAB persistence.
This is the user that should be in `jdbc.cfg`.
The user default schema will be used.
Default data types for an Oracle DB are different from the general defaults:
| sqltype.COLOR | `VARCHAR2(70)` |
| sqltype.CONTACT | `VARCHAR2(6)` |
| sqltype.DATETIME | `TIMESTAMP` |
| sqltype.DIMMER | `NUMBER(3)` |
| sqltype.IMAGE | `CLOB` |
| sqltype.LOCATION | `VARCHAR2(50)` |
| sqltype.NUMBER | `FLOAT` |
| sqltype.PLAYER | `VARCHAR2(20)` |
| sqltype.ROLLERSHUTTER | `NUMBER(3)` |
| sqltype.STRING | `VARCHAR2(16000 CHAR)` |
| sqltype.SWITCH | `VARCHAR2(6)` |
| sqltype.tablePrimaryKey | `TIMESTAMP` |
| sqltype.tablePrimaryValue | `CURRENT_TIME` |
### Case Sensitive Item Names
To avoid numbered suffixes entirely, `tableUseRealItemNames` and `tableCaseSensitiveItemNames` must both be enabled.

View File

@ -15,8 +15,8 @@
<name>openHAB Add-ons :: Bundles :: Persistence Service :: JDBC</name>
<properties>
<bnd.importpackage>!org.osgi.service.jdbc.*,!sun.security.*,!org.apache.lucene.*,!org.apache.logging.log4j,!waffle.windows.auth.*,!org.hibernate.*,!org.jboss.*,!org.codehaus.groovy.*,!com.codahale.metrics.*,!com.google.protobuf.*,!com.ibm.icu.*,!com.ibm.jvm.*,!com.mchange.*,!com.sun.*,!com.vividsolutions.*,!io.prometheus.*,com.mysql.*;resolution:=optional,org.apache.derby.*;resolution:=optional,org.h2.*;resolution:=optional,org.hsqldb;resolution:=optional,org.hsqldb.jdbc;resolution:=optional,org.mariadb.*;resolution:=optional,org.postgresql.*;resolution:=optional,org.sqlite;resolution:=optional,org.sqlite.jdbc4;resolution:=optional,javassist*;resolution:=optional</bnd.importpackage>
<dep.noembedding>derby,h2,hsqldb,mariadb-java-client,mysql-connector-j,postgresql,sqlite-jdbc</dep.noembedding>
<bnd.importpackage>!org.osgi.service.jdbc.*,!sun.security.*,!org.apache.lucene.*,!org.apache.logging.log4j,!waffle.windows.auth.*,!org.hibernate.*,!org.jboss.*,!org.codehaus.groovy.*,!com.codahale.metrics.*,!com.google.protobuf.*,!com.ibm.icu.*,!com.ibm.jvm.*,!com.mchange.*,!com.sun.*,!com.vividsolutions.*,!io.prometheus.*,com.mysql.*;resolution:=optional,org.apache.derby.*;resolution:=optional,org.h2.*;resolution:=optional,org.hsqldb;resolution:=optional,org.hsqldb.jdbc;resolution:=optional,org.mariadb.*;resolution:=optional,org.postgresql.*;resolution:=optional,org.sqlite;resolution:=optional,org.sqlite.jdbc4;resolution:=optional,oracle.*;resolution:=optional,javassist*;resolution:=optional</bnd.importpackage>
<dep.noembedding>derby,h2,hsqldb,mariadb-java-client,mysql-connector-j,postgresql,sqlite-jdbc,com.oracle.database.jdbc.ojdbc11</dep.noembedding>
<project.build.sourceEncoding>UTF-8</project.build.sourceEncoding>
<project.reporting.outputEncoding>UTF-8</project.reporting.outputEncoding>
@ -32,6 +32,7 @@
<mysql.version>8.2.0</mysql.version>
<postgresql.version>42.4.4</postgresql.version>
<sqlite.version>3.42.0.0</sqlite.version>
<oracle.version>23.5.0.2407</oracle.version>
</properties>
<dependencies>
@ -93,7 +94,10 @@
<artifactId>sqlite-jdbc</artifactId>
<version>${sqlite.version}</version>
</dependency>
<dependency>
<groupId>org.openhab.osgiify</groupId>
<artifactId>com.oracle.database.jdbc.ojdbc11</artifactId>
<version>${oracle.version}</version>
</dependency>
</dependencies>
</project>

View File

@ -2,54 +2,60 @@
<features name="org.openhab.persistence.jdbc-${project.version}" xmlns="http://karaf.apache.org/xmlns/features/v1.4.0">
<repository>mvn:org.openhab.core.features.karaf/org.openhab.core.features.karaf.openhab-core/${ohc.version}/xml/features</repository>
<!-- JDBC Persistence for: Apache Derby, H2, HSQLDB, MariaDB, MySQL, PostgreSQL, SQLite -->
<!-- JDBC Persistence for: Apache Derby, H2, HSQLDB, MariaDB, MySQL, PostgreSQL, SQLite, Oracle -->
<feature name="openhab-persistence-jdbc-derby" description="JDBC Persistence Apache Derby" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:org.apache.derby/derby/10.14.2.0</bundle>
<bundle start-level="80">mvn:org.apache.derby/derby/${derby.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-h2" description="JDBC Persistence H2" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:com.h2database/h2/2.2.224</bundle>
<bundle start-level="80">mvn:com.h2database/h2/${h2.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-hsqldb" description="JDBC Persistence HSQLDB" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:org.hsqldb/hsqldb/2.3.3</bundle>
<bundle start-level="80">mvn:org.hsqldb/hsqldb/${hsqldb.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-mariadb" description="JDBC Persistence MariaDB" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:org.mariadb.jdbc/mariadb-java-client/3.0.8</bundle>
<bundle start-level="80">mvn:org.mariadb.jdbc/mariadb-java-client/${mariadb.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-mysql" description="JDBC Persistence MySQL" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:com.mysql/mysql-connector-j/8.2.0</bundle>
<bundle start-level="80">mvn:com.mysql/mysql-connector-j/${mysql.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-postgresql" description="JDBC Persistence PostgreSQL" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:org.postgresql/postgresql/42.4.4</bundle>
<bundle start-level="80">mvn:org.postgresql/postgresql/${postgresql.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-sqlite" description="JDBC Persistence SQLite" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:org.xerial/sqlite-jdbc/3.42.0.0</bundle>
<bundle start-level="80">mvn:org.xerial/sqlite-jdbc/${sqlite.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
<feature name="openhab-persistence-jdbc-oracle" description="JDBC Persistence Oracle" version="${project.version}">
<configfile finalname="${openhab.conf}/services/jdbc.cfg" override="false">mvn:org.openhab.addons.features.karaf/org.openhab.addons.features.karaf.openhab-addons-external/${project.version}/cfg/jdbc</configfile>
<feature prerequisite="false" dependency="false">openhab-runtime-base</feature>
<bundle start-level="80">mvn:org.openhab.osgiify/com.oracle.database.jdbc.ojdbc11/${oracle.version}</bundle>
<bundle start-level="80">mvn:org.openhab.addons.bundles/org.openhab.persistence.jdbc/${project.version}</bundle>
</feature>
</features>

View File

@ -127,8 +127,8 @@ public class JdbcConfiguration {
// set database type and database type class
setDBDAOClass(Objects.requireNonNull(parsedURL.getProperty("dbShortcut"))); // derby, h2, hsqldb, mariadb,
// mysql, postgresql,
// sqlite, timescaledb
// mysql, postgresql, sqlite,
// timescaledb, oracle
// set user
if (user != null && !user.isBlank()) {
dBDAO.databaseProps.setProperty("dataSource.user", user);
@ -231,6 +231,7 @@ public class JdbcConfiguration {
String dn = dBDAO.databaseProps.getProperty("driverClassName");
if (dn == null) {
dn = dBDAO.databaseProps.getProperty("dataSourceClassName");
dBDAO.databaseProps.setProperty("dataSource.url", url);
} else {
dBDAO.databaseProps.setProperty("jdbcUrl", url);
}
@ -340,6 +341,9 @@ public class JdbcConfiguration {
case "sqlite":
warn += "\tSQLite: version >= 3.42.0.0 from https://mvnrepository.com/artifact/org.xerial/sqlite-jdbc\n";
break;
case "oracle":
warn += "\tOracle: version >= 23.5.0.0 from https://mvnrepository.com/artifact/org.openhab.osgiify/com.oracle.database.jdbc.ojdbc11\n";
break;
}
}
logger.warn(warn, serviceName);

View File

@ -603,7 +603,7 @@ public class JdbcBaseDAO {
String it = getSqlTypes().get(itemType);
if (it == null) {
logger.warn("JDBC::storeItemValueProvider: No SQL type defined for item type {}", itemType);
} else if (it.toUpperCase().contains("DOUBLE")) {
} else if (it.toUpperCase().contains("DOUBLE") || (it.toUpperCase().contains("FLOAT"))) {
vo.setValueTypes(it, java.lang.Double.class);
double value = ((Number) convertedState).doubleValue();
logger.debug("JDBC::storeItemValueProvider: newVal.doubleValue: '{}'", value);
@ -666,7 +666,7 @@ public class JdbcBaseDAO {
if (it == null) {
throw new UnsupportedOperationException("No SQL type defined for item type NUMBERITEM");
}
if (it.toUpperCase().contains("DOUBLE")) {
if (it.toUpperCase().contains("DOUBLE") || (it.toUpperCase().contains("FLOAT"))) {
return unit == null ? new DecimalType(objectAsNumber(v).doubleValue())
: QuantityType.valueOf(objectAsNumber(v).doubleValue(), unit);
} else if (it.toUpperCase().contains("DECIMAL") || it.toUpperCase().contains("NUMERIC")) {
@ -723,10 +723,12 @@ public class JdbcBaseDAO {
}
protected Integer objectAsInteger(Object v) {
if (v instanceof Byte) {
return ((Byte) v).intValue();
} else if (v instanceof Integer) {
return (Integer) v;
if (v instanceof Byte byteValue) {
return byteValue.intValue();
} else if (v instanceof Integer intValue) {
return intValue;
} else if (v instanceof BigDecimal bdValue) {
return bdValue.intValue();
}
throw new UnsupportedOperationException("Integer of type '" + v.getClass().getName() + "' is not supported");
}

View File

@ -0,0 +1,303 @@
/**
* Copyright (c) 2010-2024 Contributors to the openHAB project
*
* See the NOTICE file(s) distributed with this work for additional
* information.
*
* This program and the accompanying materials are made available under the
* terms of the Eclipse Public License 2.0 which is available at
* http://www.eclipse.org/legal/epl-2.0
*
* SPDX-License-Identifier: EPL-2.0
*/
package org.openhab.persistence.jdbc.internal.db;
import java.sql.SQLException;
import java.time.ZoneId;
import java.time.ZonedDateTime;
import java.util.List;
import org.eclipse.jdt.annotation.NonNullByDefault;
import org.knowm.yank.Yank;
import org.knowm.yank.exceptions.YankSQLException;
import org.openhab.core.items.Item;
import org.openhab.core.persistence.FilterCriteria;
import org.openhab.core.persistence.FilterCriteria.Ordering;
import org.openhab.core.types.State;
import org.openhab.persistence.jdbc.internal.dto.ItemVO;
import org.openhab.persistence.jdbc.internal.dto.ItemsVO;
import org.openhab.persistence.jdbc.internal.exceptions.JdbcSQLException;
import org.openhab.persistence.jdbc.internal.utils.StringUtilsExt;
import org.slf4j.Logger;
import org.slf4j.LoggerFactory;
import oracle.sql.TIMESTAMP;
/**
* Extended Database Configuration class for Oracle Database. Class represents
* the extended database-specific configuration. Overrides and supplements the
* default settings from JdbcBaseDAO. Enter only the differences to JdbcBaseDAO here.
*
* @author Helmut Lehmeyer - Initial contribution
* @author Mark Herwege - Implemented for Oracle DB
*/
@NonNullByDefault
public class JdbcOracleDAO extends JdbcBaseDAO {
@SuppressWarnings("unused")
private static final String DRIVER_CLASS_NAME = oracle.jdbc.driver.OracleDriver.class.getName();
private static final String DATA_SOURCE_CLASS_NAME = oracle.jdbc.datasource.impl.OracleDataSource.class.getName();
private final Logger logger = LoggerFactory.getLogger(JdbcOracleDAO.class);
protected String sqlGetItemTableID = "SELECT itemId FROM #itemsManageTable# WHERE #colname# = ?";
/********
* INIT *
********/
public JdbcOracleDAO() {
initSqlTypes();
initDbProps();
initSqlQueries();
}
private void initSqlQueries() {
logger.debug("JDBC::initSqlQueries: '{}'", this.getClass().getSimpleName());
sqlPingDB = "SELECT 1 FROM DUAL";
sqlGetDB = "SELECT SYS_CONTEXT('USERENV', 'CURRENT_SCHEMA') FROM DUAL"; // Not needed, just query schema that
// will be used
sqlIfTableExists = "SELECT * FROM USER_TABLES WHERE TABLE_NAME = UPPER('#searchTable#')";
sqlCreateNewEntryInItemsTable = "INSERT INTO #itemsManageTable# (ItemId, #colname#) VALUES (DEFAULT, ?)";
sqlCreateItemsTableIfNot = """
DECLARE
table_exists NUMBER;
BEGIN
SELECT COUNT(*) INTO table_exists FROM USER_TABLES WHERE TABLE_NAME = UPPER('#itemsManageTable#');
IF table_exists = 0 THEN
EXECUTE IMMEDIATE 'CREATE TABLE #itemsManageTable#
( ItemId NUMBER GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL
, #colname# #coltype# NOT NULL
, CONSTRAINT #itemsManageTable#_PKEY PRIMARY KEY (ItemId)
)';
END IF;
END;""";
sqlDropItemsTableIfExists = """
DECLARE
table_exists NUMBER;
BEGIN
SELECT COUNT(*) INTO table_exists FROM USER_TABLES WHERE TABLE_NAME = UPPER('#itemsManageTable#');
IF table_exists = 0 THEN
EXECUTE IMMEDIATE 'DROP TABLE #itemsManageTable#';
END IF;
END;""";
sqlGetItemTables = "SELECT TABLE_NAME FROM USER_TABLES WHERE TABLE_NAME != UPPER('#itemsManageTable#')";
sqlGetTableColumnTypes = "SELECT COLUMN_NAME, DATA_TYPE, NULLABLE FROM USER_TAB_COLUMNS WHERE TABLE_NAME = UPPER('#tableName#')";
sqlCreateItemTable = """
DECLARE
table_exists NUMBER;
BEGIN
SELECT COUNT(*) INTO table_exists FROM USER_TABLES WHERE TABLE_NAME = UPPER('#tableName#');
IF table_exists = 0 THEN
EXECUTE IMMEDIATE 'CREATE TABLE #tableName#
( time #tablePrimaryKey# NOT NULL
, value #dbType#
, CONSTRAINT #tableName#_PKEY PRIMARY KEY (time)
)';
END IF;
END;""";
sqlAlterTableColumn = "ALTER TABLE #tableName# MODIFY (#columnName# #columnType#)";
sqlInsertItemValue = """
MERGE INTO #tableName# tgt
USING (SELECT CAST(? AS TIMESTAMP) AS TIME, CAST(? AS #dbType#) AS VALUE FROM DUAL) src ON (tgt.TIME = src.TIME)
WHEN MATCHED THEN
UPDATE SET tgt.VALUE = src.VALUE
WHEN NOT MATCHED THEN
INSERT (TIME, VALUE) VALUES (src.TIME, src.VALUE)""";
}
/**
* INFO: http://www.java2s.com/Code/Java/Database-SQL-JDBC/StandardSQLDataTypeswithTheirJavaEquivalents.htm
*/
private void initSqlTypes() {
sqlTypes.put("CALLITEM", "VARCHAR2(200 CHAR)");
sqlTypes.put("COLORITEM", "VARCHAR2(70)");
sqlTypes.put("CONTACTITEM", "VARCHAR2(6)");
sqlTypes.put("DATETIMEITEM", "TIMESTAMP");
sqlTypes.put("DIMMERITEM", "NUMBER(3)");
sqlTypes.put("IMAGEITEM", "CLOB");
sqlTypes.put("LOCATIONITEM", "VARCHAR2(50)");
sqlTypes.put("NUMBERITEM", "FLOAT");
sqlTypes.put("PLAYERITEM", "VARCHAR2(20)");
sqlTypes.put("ROLLERSHUTTERITEM", "NUMBER(3)");
// VARCHAR2 max length 32767 bytes for MAX_STRING_SIZE=EXTENDED, only 4000 bytes when MAX_STRING_SIZE=STANDARD
// (EXTENDED is default for ADB). As default character set for ADB is AL32UTF8, it takes between 1 and 4 bytes
// per character, where most typical characters will only take one. Therefore use a maximum of 16000 characters.
sqlTypes.put("STRINGITEM", "VARCHAR2(16000 CHAR)");
sqlTypes.put("SWITCHITEM", "VARCHAR2(6)");
sqlTypes.put("tablePrimaryKey", "TIMESTAMP");
sqlTypes.put("tablePrimaryValue", "CURRENT_TIMESTAMP");
logger.debug("JDBC::initSqlTypes: Initialized the type array sqlTypes={}", sqlTypes.values());
}
/**
* INFO: https://github.com/brettwooldridge/HikariCP
*/
private void initDbProps() {
// Tuning for performance and draining connection on ADB
// See https://blogs.oracle.com/developers/post/hikaricp-best-practices-for-oracle-database-and-spring-boot
System.setProperty("com.zaxxer.hikari.aliveBypassWindowMs", "-1");
// Setting as system property because HikariCP as instantiated through Yank does not pass on these connection
// properties from dataSource properties to the connection
System.setProperty("oracle.jdbc.defaultConnectionValidation", "LOCAL");
System.setProperty("oracle.jdbc.defaultRowPrefetch", "20");
// Properties for HikariCP
databaseProps.setProperty("dataSourceClassName", DATA_SOURCE_CLASS_NAME);
databaseProps.setProperty("maximumPoolSize", "3");
databaseProps.setProperty("minimumIdle", "2");
}
/**************
* ITEMS DAOs *
**************/
@Override
public Long doCreateNewEntryInItemsTable(ItemsVO vo) throws JdbcSQLException {
String sql = StringUtilsExt.replaceArrayMerge(sqlCreateNewEntryInItemsTable,
new String[] { "#itemsManageTable#", "#colname#" },
new String[] { vo.getItemsManageTable(), vo.getColname() });
Object[] params = { vo.getItemName() };
logger.debug("JDBC::doCreateNewEntryInItemsTable sql={} item={}", sql, vo.getItemName());
try {
Yank.execute(sql, params);
} catch (YankSQLException e) {
throw new JdbcSQLException(e);
}
// We need to return the itemId, but Yank.insert does not retrieve the value from Oracle. So do an explicit
// query
// for it.
sql = StringUtilsExt.replaceArrayMerge(sqlGetItemTableID, new String[] { "#itemsManageTable#", "#colname#" },
new String[] { vo.getItemsManageTable(), vo.getColname() });
logger.debug("JDBC::doGetEntryIdInItemsTable sql={}", sql);
try {
return Yank.queryScalar(sql, Long.class, params);
} catch (YankSQLException e) {
throw new JdbcSQLException(e);
}
}
@Override
public ItemsVO doCreateItemsTableIfNot(ItemsVO vo) throws JdbcSQLException {
String sql = StringUtilsExt.replaceArrayMerge(sqlCreateItemsTableIfNot,
new String[] { "#itemsManageTable#", "#colname#", "#coltype#" },
new String[] { vo.getItemsManageTable(), vo.getColname(), "VARCHAR2(500)" });
logger.debug("JDBC::doCreateItemsTableIfNot sql={}", sql);
try {
Yank.execute(sql, null);
} catch (YankSQLException e) {
throw new JdbcSQLException(e);
}
return vo;
}
/*************
* ITEM DAOs *
*************/
@Override
public void doUpdateItemTableNames(List<ItemVO> vol) throws JdbcSQLException {
logger.debug("JDBC::doUpdateItemTableNames vol.size = {}", vol.size());
for (ItemVO itemTable : vol) {
String sql = "RENAME " + itemTable.getTableName() + " TO " + itemTable.getNewTableName();
logger.debug("JDBC::updateTableName sql={} oldValue='{}' newValue='{}'", sql, itemTable.getTableName(),
itemTable.getNewTableName());
try {
Yank.execute(sql, null);
} catch (YankSQLException e) {
throw new JdbcSQLException(e);
}
}
}
@Override
public void doStoreItemValue(Item item, State itemState, ItemVO vo) throws JdbcSQLException {
doStoreItemValue(item, itemState, vo, ZonedDateTime.now());
}
@Override
public void doStoreItemValue(Item item, State itemState, ItemVO vo, ZonedDateTime date) throws JdbcSQLException {
ItemVO storedVO = storeItemValueProvider(item, itemState, vo);
String sql = StringUtilsExt.replaceArrayMerge(sqlInsertItemValue, new String[] { "#tableName#", "#dbType#" },
new String[] { storedVO.getTableName(), storedVO.getDbType() });
java.sql.Timestamp timestamp = new java.sql.Timestamp(date.toInstant().toEpochMilli());
Object[] params = { timestamp, storedVO.getValue() };
logger.debug("JDBC::doStoreItemValue sql={} value='{}'", sql, storedVO.getValue());
try {
Yank.execute(sql, params);
} catch (YankSQLException e) {
throw new JdbcSQLException(e);
}
}
/****************************
* SQL generation Providers *
****************************/
@Override
protected String histItemFilterQueryProvider(FilterCriteria filter, int numberDecimalcount, String table,
String simpleName, ZoneId timeZone) {
logger.debug(
"JDBC::getHistItemFilterQueryProvider filter = {}, numberDecimalcount = {}, table = {}, simpleName = {}",
filter, numberDecimalcount, table, simpleName);
String filterString = resolveTimeFilter(filter, timeZone);
filterString += (filter.getOrdering() == Ordering.ASCENDING) ? " ORDER BY time ASC" : " ORDER BY time DESC";
if (filter.getPageSize() != Integer.MAX_VALUE) {
filterString += " OFFSET " + filter.getPageNumber() * filter.getPageSize() + " ROWS FETCH NEXT "
+ filter.getPageSize() + " ROWS ONLY";
}
// SELECT time, ROUND(value,3) FROM number_item_0114 ORDER BY time DESC OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY
// rounding HALF UP
String queryString = "NUMBERITEM".equalsIgnoreCase(simpleName) && numberDecimalcount > -1
? "SELECT time, ROUND(value," + numberDecimalcount + ") FROM " + table
: "SELECT time, value FROM " + table;
if (!filterString.isEmpty()) {
queryString += filterString;
}
logger.debug("JDBC::query queryString = {}", queryString);
return queryString;
}
@Override
protected String resolveTimeFilter(FilterCriteria filter, ZoneId timeZone) {
String filterString = "";
ZonedDateTime beginDate = filter.getBeginDate();
if (beginDate != null) {
filterString += filterString.isEmpty() ? " WHERE" : " AND";
filterString += " TIME>=TO_TIMESTAMP('" + JDBC_DATE_FORMAT.format(beginDate.withZoneSameInstant(timeZone))
+ "', 'YYYY-MM-dd HH24:MI:SS')";
}
ZonedDateTime endDate = filter.getEndDate();
if (endDate != null) {
filterString += filterString.isEmpty() ? " WHERE" : " AND";
filterString += " TIME<=TO_TIMESTAMP('" + JDBC_DATE_FORMAT.format(endDate.withZoneSameInstant(timeZone))
+ "', 'YYYY-MM-dd HH24:MI:SS')";
}
return filterString;
}
@Override
protected ZonedDateTime objectAsZonedDateTime(Object v) {
if (v instanceof TIMESTAMP objectAsOracleTimestamp) {
try {
return objectAsOracleTimestamp.timestampValue().toInstant().atZone(ZoneId.systemDefault());
} catch (SQLException e) {
throw new UnsupportedOperationException("Date of type '" + v.getClass().getName()
+ "', no Timestamp representation exists for '" + objectAsOracleTimestamp.toString() + "'");
}
} else {
return super.objectAsZonedDateTime(v);
}
}
}

View File

@ -44,7 +44,7 @@ public class StringUtilsExt {
public static String replaceArrayMerge(String str, String separate, Object[] separators) {
String s = str;
for (int i = 0; i < separators.length; i++) {
s = s.replaceFirst(separate, (String) separators[i]);
s = s.replaceAll(separate, (String) separators[i]);
}
return s;
}
@ -55,7 +55,7 @@ public class StringUtilsExt {
public static String replaceArrayMerge(String str, String[] separate, String[] separators) {
String s = str;
for (int i = 0; i < separators.length; i++) {
s = s.replaceFirst(separate[i], separators[i]);
s = s.replaceAll(separate[i], separators[i]);
}
return s;
}
@ -161,24 +161,22 @@ public class StringUtilsExt {
props.put("pathQuery", dbURI.getQuery());
}
String pathURI = dbURI.getPath();
if (pathURI != null) {
String path = "";
if (dbURI.getPath() != null) {
String gp = dbURI.getPath();
String st = "/";
if (gp.indexOf("/") <= 1) {
if (substrPos(gp, st).size() > 1) {
path = stringBeforeLastSubstr(gp, st) + st;
if ((pathURI.indexOf("/") >= 0) && (pathURI.indexOf("/") <= 1)) {
if (stringAfterSubstr(pathURI, "/").contains("/")) {
path = stringBeforeLastSubstr(pathURI, "/") + "/";
} else {
path = stringBeforeSubstr(gp, st) + st;
path = stringBeforeSubstr(pathURI, "/") + "/";
}
}
if (dbURI.getScheme() != null && dbURI.getScheme().length() == 1) {
path = dbURI.getScheme() + ":" + path;
String schemeURI = dbURI.getScheme();
if (schemeURI != null && schemeURI.length() == 1) {
path = schemeURI + ":" + path;
}
props.put("serverPath", path);
}
if (dbURI.getPath() != null) {
props.put("databaseName", stringAfterLastSubstr(dbURI.getPath(), "/"));
props.put("databaseName", pathURI.contains("/") ? stringAfterLastSubstr(pathURI, "/") : pathURI);
}
if (dbURI.getPort() != -1) {
props.put("portNumber", dbURI.getPort() + "");

View File

@ -0,0 +1,14 @@
<?xml version="1.0" encoding="UTF-8"?>
<addon:addon id="jdbc-postgresql" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
xmlns:addon="https://openhab.org/schemas/addon/v1.0.0"
xsi:schemaLocation="https://openhab.org/schemas/addon/v1.0.0 https://openhab.org/schemas/addon-1.0.0.xsd">
<type>persistence</type>
<name>JDBC Persistence (Oracle)</name>
<description>This is the persistence add-on for JDBC.</description>
<service-id>org.openhab.jdbc</service-id>
<config-description-ref uri="persistence:jdbc"/>
</addon:addon>

View File

@ -10,9 +10,8 @@
<!--
# I N S T A L L J D B C P E R S I S T E N C E S E R V I C E
#
# https://github.com/openhab/openhab/wiki/JDBC-Persistence
#
# Tested databases/url-prefix: jdbc:derby, jdbc:h2, jdbc:hsqldb, jdbc:mariadb, jdbc:mysql, jdbc:postgresql, jdbc:sqlite
# Tested databases/url-prefix: jdbc:derby, jdbc:h2, jdbc:hsqldb, jdbc:mariadb, jdbc:mysql, jdbc:postgresql, jdbc:sqlite,
jdbc:oracle
#
# derby, h2, hsqldb, sqlite can be embedded,
# If no database is available it will be created, for example the url 'jdbc:h2:./testH2' creates a new DB in OpenHab Folder.
@ -32,6 +31,7 @@
# jdbc:url=jdbc:mysql://192.168.0.1:3306/testMysql
# jdbc:url=jdbc:postgresql://192.168.0.1:5432/testPostgresql
# jdbc:url=jdbc:sqlite:./testSqlite.db
# jdbc:oracle:thin:@dbname?TNS_ADMIN=./dbname_tns_admin_folder
-->
<parameter name="url" type="text" required="true">
<label>Database URL</label>
@ -45,7 +45,8 @@
jdbc:mariadb://192.168.0.1:3306/testMariadb<br>
jdbc:mysql://192.168.0.1:3306/testMysql<br>
jdbc:postgresql://192.168.0.1:5432/testPostgresql<br>
jdbc:sqlite:./testSqlite.db]]></description>
jdbc:sqlite:./testSqlite.db<br>
jdbc:oracle:thin:@dbname?TNS_ADMIN=./dbname_tns_admin_folder]]></description>
</parameter>
<parameter name="user" type="text" required="true">