2 * Copyright (c) 2010-2024 Contributors to the openHAB project
4 * See the NOTICE file(s) distributed with this work for additional
7 * This program and the accompanying materials are made available under the
8 * terms of the Eclipse Public License 2.0 which is available at
9 * http://www.eclipse.org/legal/epl-2.0
11 * SPDX-License-Identifier: EPL-2.0
13 package org.openhab.persistence.jdbc.internal.db;
15 import java.time.ZoneId;
16 import java.time.ZonedDateTime;
17 import java.util.List;
19 import org.eclipse.jdt.annotation.NonNullByDefault;
20 import org.knowm.yank.Yank;
21 import org.knowm.yank.exceptions.YankSQLException;
22 import org.openhab.core.items.Item;
23 import org.openhab.core.persistence.FilterCriteria;
24 import org.openhab.core.persistence.FilterCriteria.Ordering;
25 import org.openhab.core.types.State;
26 import org.openhab.persistence.jdbc.internal.dto.Column;
27 import org.openhab.persistence.jdbc.internal.dto.ItemVO;
28 import org.openhab.persistence.jdbc.internal.dto.ItemsVO;
29 import org.openhab.persistence.jdbc.internal.exceptions.JdbcSQLException;
30 import org.openhab.persistence.jdbc.internal.utils.DbMetaData;
31 import org.openhab.persistence.jdbc.internal.utils.StringUtilsExt;
32 import org.slf4j.Logger;
33 import org.slf4j.LoggerFactory;
36 * Extended Database Configuration class. Class represents
37 * the extended database-specific configuration. Overrides and supplements the
38 * default settings from JdbcBaseDAO. Enter only the differences to JdbcBaseDAO here.
40 * @author Helmut Lehmeyer - Initial contribution
43 public class JdbcPostgresqlDAO extends JdbcBaseDAO {
44 private static final String DRIVER_CLASS_NAME = org.postgresql.Driver.class.getName();
45 @SuppressWarnings("unused")
46 private static final String DATA_SOURCE_CLASS_NAME = org.postgresql.ds.PGSimpleDataSource.class.getName();
48 private final Logger logger = LoggerFactory.getLogger(JdbcPostgresqlDAO.class);
53 public JdbcPostgresqlDAO() {
59 private void initSqlQueries() {
60 logger.debug("JDBC::initSqlQueries: '{}'", this.getClass().getSimpleName());
61 // System Information Functions: https://www.postgresql.org/docs/9.2/static/functions-info.html
62 sqlGetDB = "SELECT CURRENT_DATABASE()";
63 sqlIfTableExists = "SELECT * FROM PG_TABLES WHERE TABLENAME='#searchTable#'";
64 sqlCreateItemsTableIfNot = "CREATE TABLE IF NOT EXISTS #itemsManageTable# (itemid SERIAL NOT NULL, #colname# #coltype# NOT NULL, CONSTRAINT #itemsManageTable#_pkey PRIMARY KEY (itemid))";
65 sqlCreateNewEntryInItemsTable = "INSERT INTO items (itemname) SELECT itemname FROM #itemsManageTable# UNION VALUES ('#itemname#') EXCEPT SELECT itemname FROM items";
66 sqlGetItemTables = """
67 SELECT table_name FROM information_schema.tables WHERE table_type='BASE TABLE' AND table_schema=(SELECT table_schema \
68 FROM information_schema.tables WHERE table_type='BASE TABLE' AND table_name='#itemsManageTable#') AND NOT table_name='#itemsManageTable#'\
70 // The PostgreSQL equivalent to MySQL columns.column_type is data_type (e.g. "timestamp with time zone") and
71 // udt_name which contains a shorter alias (e.g. "timestamptz"). We alias data_type as "column_type" and
72 // udt_name as "column_type_alias" to be compatible with the 'Column' class used in Yank.queryBeanList
73 sqlGetTableColumnTypes = """
74 SELECT column_name, data_type as column_type, udt_name as column_type_alias, is_nullable FROM information_schema.columns \
75 WHERE table_name='#tableName#' AND table_catalog='#jdbcUriDatabaseName#' AND table_schema=(SELECT table_schema FROM information_schema.tables WHERE table_type='BASE TABLE' \
76 AND table_name='#itemsManageTable#')\
78 // NOTICE: on PostgreSql >= 9.5, sqlInsertItemValue query template is modified to do an "upsert" (overwrite
79 // existing value). The version check and query change is performed at initAfterFirstDbConnection()
80 sqlInsertItemValue = "INSERT INTO #tableName# (TIME, VALUE) VALUES( #tablePrimaryValue#, CAST( ? as #dbType#) )";
81 sqlAlterTableColumn = "ALTER TABLE #tableName# ALTER COLUMN #columnName# TYPE #columnType#";
85 public void initAfterFirstDbConnection() {
86 logger.debug("JDBC::initAfterFirstDbConnection: Initializing step, after db is connected.");
87 DbMetaData dbMeta = new DbMetaData();
89 // Perform "upsert" (on PostgreSql >= 9.5): Overwrite previous VALUE if same TIME (Primary Key) is provided
90 // This is the default at JdbcBaseDAO and is equivalent to MySQL: ON DUPLICATE KEY UPDATE VALUE
91 // see: https://www.postgresql.org/docs/9.5/sql-insert.html
92 if (dbMeta.isDbVersionGreater(9, 4)) {
93 logger.debug("JDBC::initAfterFirstDbConnection: Values with the same time will be upserted (Pg >= 9.5)");
94 sqlInsertItemValue = """
95 INSERT INTO #tableName# (TIME, VALUE) VALUES( #tablePrimaryValue#, CAST( ? as #dbType#) )\
96 ON CONFLICT (TIME) DO UPDATE SET VALUE=EXCLUDED.VALUE\
102 * INFO: http://www.java2s.com/Code/Java/Database-SQL-JDBC/StandardSQLDataTypeswithTheirJavaEquivalents.htm
104 private void initSqlTypes() {
105 // Initialize the type array
106 sqlTypes.put("CALLITEM", "VARCHAR");
107 sqlTypes.put("COLORITEM", "VARCHAR");
108 sqlTypes.put("CONTACTITEM", "VARCHAR");
109 sqlTypes.put("DATETIMEITEM", "TIMESTAMPTZ");
110 sqlTypes.put("DIMMERITEM", "SMALLINT");
111 sqlTypes.put("IMAGEITEM", "VARCHAR");
112 sqlTypes.put("LOCATIONITEM", "VARCHAR");
113 sqlTypes.put("NUMBERITEM", "DOUBLE PRECISION");
114 sqlTypes.put("PLAYERITEM", "VARCHAR");
115 sqlTypes.put("ROLLERSHUTTERITEM", "SMALLINT");
116 sqlTypes.put("STRINGITEM", "VARCHAR");
117 sqlTypes.put("SWITCHITEM", "VARCHAR");
118 sqlTypes.put("tablePrimaryKey", "TIMESTAMPTZ");
119 logger.debug("JDBC::initSqlTypes: Initialized the type array sqlTypes={}", sqlTypes.values());
123 * INFO: https://github.com/brettwooldridge/HikariCP
125 private void initDbProps() {
127 // databaseProps.setProperty("dataSource.cachePrepStmts", "true");
128 // databaseProps.setProperty("dataSource.prepStmtCacheSize", "250");
129 // databaseProps.setProperty("dataSource.prepStmtCacheSqlLimit", "2048");
131 // Properties for HikariCP
132 databaseProps.setProperty("driverClassName", DRIVER_CLASS_NAME);
133 // driverClassName OR BETTER USE dataSourceClassName
134 // databaseProps.setProperty("dataSourceClassName", DATA_SOURCE_CLASS_NAME);
135 // databaseProps.setProperty("maximumPoolSize", "3");
136 // databaseProps.setProperty("minimumIdle", "2");
143 public ItemsVO doCreateItemsTableIfNot(ItemsVO vo) throws JdbcSQLException {
144 String sql = StringUtilsExt.replaceArrayMerge(sqlCreateItemsTableIfNot,
145 new String[] { "#itemsManageTable#", "#colname#", "#coltype#", "#itemsManageTable#" },
146 new String[] { vo.getItemsManageTable(), vo.getColname(), vo.getColtype(), vo.getItemsManageTable() });
147 logger.debug("JDBC::doCreateItemsTableIfNot sql={}", sql);
149 Yank.execute(sql, null);
150 } catch (YankSQLException e) {
151 throw new JdbcSQLException(e);
157 public Long doCreateNewEntryInItemsTable(ItemsVO vo) throws JdbcSQLException {
158 String sql = StringUtilsExt.replaceArrayMerge(sqlCreateNewEntryInItemsTable,
159 new String[] { "#itemsManageTable#", "#itemname#" },
160 new String[] { vo.getItemsManageTable(), vo.getItemName() });
161 logger.debug("JDBC::doCreateNewEntryInItemsTable sql={}", sql);
163 return Yank.insert(sql, null);
164 } catch (YankSQLException e) {
165 throw new JdbcSQLException(e);
170 public List<ItemsVO> doGetItemTables(ItemsVO vo) throws JdbcSQLException {
171 String sql = StringUtilsExt.replaceArrayMerge(this.sqlGetItemTables,
172 new String[] { "#itemsManageTable#", "#itemsManageTable#" },
173 new String[] { vo.getItemsManageTable(), vo.getItemsManageTable() });
174 this.logger.debug("JDBC::doGetItemTables sql={}", sql);
176 return Yank.queryBeanList(sql, ItemsVO.class, null);
177 } catch (YankSQLException e) {
178 throw new JdbcSQLException(e);
183 * Override because for PostgreSQL a different query is required with a 3rd argument (itemsManageTable)
186 public List<Column> doGetTableColumns(ItemsVO vo) throws JdbcSQLException {
187 String sql = StringUtilsExt.replaceArrayMerge(sqlGetTableColumnTypes,
188 new String[] { "#jdbcUriDatabaseName#", "#tableName#", "#itemsManageTable#" },
189 new String[] { vo.getJdbcUriDatabaseName(), vo.getTableName(), vo.getItemsManageTable() });
190 logger.debug("JDBC::doGetTableColumns sql={}", sql);
192 return Yank.queryBeanList(sql, Column.class, null);
193 } catch (YankSQLException e) {
194 throw new JdbcSQLException(e);
203 * Override since PostgreSQL does not support setting NOT NULL in the same clause as ALTER COLUMN .. TYPE
206 public void doAlterTableColumn(String tableName, String columnName, String columnType, boolean nullable)
207 throws JdbcSQLException {
208 String sql = StringUtilsExt.replaceArrayMerge(sqlAlterTableColumn,
209 new String[] { "#tableName#", "#columnName#", "#columnType#" },
210 new String[] { tableName, columnName, columnType });
211 logger.info("JDBC::doAlterTableColumn sql={}", sql);
213 Yank.execute(sql, null);
215 String sql2 = StringUtilsExt.replaceArrayMerge(
216 "ALTER TABLE #tableName# ALTER COLUMN #columnName# SET NOT NULL",
217 new String[] { "#tableName#", "#columnName#" }, new String[] { tableName, columnName });
218 logger.info("JDBC::doAlterTableColumn sql={}", sql2);
219 Yank.execute(sql2, null);
221 } catch (YankSQLException e) {
222 throw new JdbcSQLException(e);
227 public void doStoreItemValue(Item item, State itemState, ItemVO vo) throws JdbcSQLException {
228 ItemVO storedVO = storeItemValueProvider(item, itemState, vo);
229 String sql = StringUtilsExt.replaceArrayMerge(sqlInsertItemValue,
230 new String[] { "#tableName#", "#dbType#", "#tablePrimaryValue#" },
231 new String[] { storedVO.getTableName(), storedVO.getDbType(), sqlTypes.get("tablePrimaryValue") });
232 Object[] params = { storedVO.getValue() };
233 logger.debug("JDBC::doStoreItemValue sql={} value='{}'", sql, storedVO.getValue());
235 Yank.execute(sql, params);
236 } catch (YankSQLException e) {
237 throw new JdbcSQLException(e);
242 public void doStoreItemValue(Item item, State itemState, ItemVO vo, ZonedDateTime date) throws JdbcSQLException {
243 ItemVO storedVO = storeItemValueProvider(item, itemState, vo);
244 String sql = StringUtilsExt.replaceArrayMerge(sqlInsertItemValue,
245 new String[] { "#tableName#", "#dbType#", "#tablePrimaryValue#" },
246 new String[] { storedVO.getTableName(), storedVO.getDbType(), "?" });
247 java.sql.Timestamp timestamp = new java.sql.Timestamp(date.toInstant().toEpochMilli());
248 Object[] params = { timestamp, storedVO.getValue() };
249 logger.debug("JDBC::doStoreItemValue sql={} timestamp={} value='{}'", sql, timestamp, storedVO.getValue());
251 Yank.execute(sql, params);
252 } catch (YankSQLException e) {
253 throw new JdbcSQLException(e);
257 /****************************
258 * SQL generation Providers *
259 ****************************/
262 protected String histItemFilterQueryProvider(FilterCriteria filter, int numberDecimalcount, String table,
263 String simpleName, ZoneId timeZone) {
265 "JDBC::getHistItemFilterQueryProvider filter = {}, numberDecimalcount = {}, table = {}, simpleName = {}",
266 filter.toString(), numberDecimalcount, table, simpleName);
268 String filterString = "";
269 ZonedDateTime beginDate = filter.getBeginDate();
270 if (beginDate != null) {
271 filterString += filterString.isEmpty() ? " WHERE" : " AND";
272 filterString += " TIME>='" + JDBC_DATE_FORMAT.format(beginDate.withZoneSameInstant(timeZone)) + "'";
274 ZonedDateTime endDate = filter.getEndDate();
275 if (endDate != null) {
276 filterString += filterString.isEmpty() ? " WHERE" : " AND";
277 filterString += " TIME<='" + JDBC_DATE_FORMAT.format(endDate.withZoneSameInstant(timeZone)) + "'";
279 filterString += (filter.getOrdering() == Ordering.ASCENDING) ? " ORDER BY time ASC" : " ORDER BY time DESC";
280 if (filter.getPageSize() != 0x7fffffff) {
282 // http://www.jooq.org/doc/3.5/manual/sql-building/sql-statements/select-statement/limit-clause/
283 filterString += " OFFSET " + filter.getPageNumber() * filter.getPageSize() + " LIMIT "
284 + filter.getPageSize();
286 String queryString = "NUMBERITEM".equalsIgnoreCase(simpleName) && numberDecimalcount > -1
287 ? "SELECT time, ROUND(CAST (value AS numeric)," + numberDecimalcount + ") FROM " + table
288 : "SELECT time, value FROM " + table;
289 if (!filterString.isEmpty()) {
290 queryString += filterString;
292 logger.debug("JDBC::query queryString = {}", queryString);
300 /******************************
301 * public Getters and Setters *
302 ******************************/