From b7ffaf0b0f59cf13935043101daf32dbff8140eb Mon Sep 17 00:00:00 2001 From: harshanl Date: Wed, 7 Sep 2016 15:01:09 +0530 Subject: [PATCH] Fixed issues in DAO implementations and MSSQL db script --- .../dao/impl/device/OracleDeviceDAOImpl.java | 21 ++- .../impl/device/PostgreSQLDeviceDAOImpl.java | 3 + .../impl/device/SQLServerDeviceDAOImpl.java | 23 ++- .../dao/OperationManagementDAOFactory.java | 3 +- .../impl/operation/H2OperationDAOImpl.java | 174 ------------------ .../main/resources/dbscripts/cdm/mssql.sql | 2 +- 6 files changed, 46 insertions(+), 180 deletions(-) delete mode 100644 components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/impl/operation/H2OperationDAOImpl.java diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/OracleDeviceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/OracleDeviceDAOImpl.java index ced650ebe1..d070660d7a 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/OracleDeviceDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/OracleDeviceDAOImpl.java @@ -31,6 +31,7 @@ import java.sql.PreparedStatement; import java.sql.ResultSet; import java.sql.SQLException; import java.util.ArrayList; +import java.util.Date; import java.util.List; /** @@ -55,6 +56,8 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { boolean isOwnershipProvided = false; String status = request.getStatus(); boolean isStatusProvided = false; + Date since = request.getSince(); + boolean isSinceProvided = false; try { conn = this.getConnection(); String sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (SELECT d1.ID AS DEVICE_ID, " + @@ -62,7 +65,20 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { "e.OWNERSHIP, e.STATUS, e.DATE_OF_LAST_UPDATE, e.DATE_OF_ENROLMENT, " + "e.ID AS ENROLMENT_ID FROM DM_ENROLMENT e, (SELECT d.ID, d.DESCRIPTION, d.NAME, " + "d.DEVICE_IDENTIFICATION, t.NAME AS DEVICE_TYPE FROM DM_DEVICE d, " + - "DM_DEVICE_TYPE t WHERE DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ?"; + "DM_DEVICE_TYPE t "; + + //Add the query to filter active devices on timestamp + if (since != null) { + sql = sql + ", DM_DEVICE_DETAIL dt"; + isSinceProvided = true; + } + + sql = sql + " WHERE DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ?"; + + //Add query for last updated timestamp + if (isSinceProvided) { + sql = sql + " AND dt.DEVICE_ID = d.ID AND dt.UPDATE_TIMESTAMP > ?"; + } //Add the query for device-type if (deviceType != null && !deviceType.isEmpty()) { @@ -98,6 +114,9 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); int paramIdx = 2; + if (isSinceProvided) { + stmt.setLong(paramIdx++, since.getTime()); + } if (isDeviceTypeProvided) { stmt.setString(paramIdx++, request.getDeviceType()); } diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/PostgreSQLDeviceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/PostgreSQLDeviceDAOImpl.java index 878e310742..2651916025 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/PostgreSQLDeviceDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/PostgreSQLDeviceDAOImpl.java @@ -30,6 +30,7 @@ import java.sql.PreparedStatement; import java.sql.ResultSet; import java.sql.SQLException; import java.util.ArrayList; +import java.util.Date; import java.util.List; /** @@ -54,6 +55,8 @@ public class PostgreSQLDeviceDAOImpl extends AbstractDeviceDAOImpl { boolean isOwnershipProvided = false; String status = request.getStatus(); boolean isStatusProvided = false; + Date since = request.getSince(); + boolean isSinceProvided = false; try { conn = this.getConnection(); String sql = "SELECT d1.ID AS DEVICE_ID, d1.DESCRIPTION, d1.NAME AS DEVICE_NAME, d1.DEVICE_TYPE, " + diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/SQLServerDeviceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/SQLServerDeviceDAOImpl.java index 476b703ad8..a8f6f5b345 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/SQLServerDeviceDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/device/SQLServerDeviceDAOImpl.java @@ -30,6 +30,7 @@ import java.sql.PreparedStatement; import java.sql.ResultSet; import java.sql.SQLException; import java.util.ArrayList; +import java.util.Date; import java.util.List; /** @@ -54,13 +55,28 @@ public class SQLServerDeviceDAOImpl extends AbstractDeviceDAOImpl { boolean isOwnershipProvided = false; String status = request.getStatus(); boolean isStatusProvided = false; + Date since = request.getSince(); + boolean isSinceProvided = false; try { conn = this.getConnection(); String sql = "SELECT d1.ID AS DEVICE_ID, d1.DESCRIPTION, d1.NAME AS DEVICE_NAME, d1.DEVICE_TYPE, " + "d1.DEVICE_IDENTIFICATION, e.OWNER, e.OWNERSHIP, e.STATUS, e.DATE_OF_LAST_UPDATE, " + "e.DATE_OF_ENROLMENT, e.ID AS ENROLMENT_ID FROM DM_ENROLMENT e, (SELECT d.ID, d.DESCRIPTION, " + - "d.NAME, d.DEVICE_IDENTIFICATION, t.NAME AS DEVICE_TYPE FROM DM_DEVICE d, DM_DEVICE_TYPE t " + - "WHERE DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ?"; + "d.NAME, d.DEVICE_IDENTIFICATION, t.NAME AS DEVICE_TYPE " + + "FROM DM_DEVICE d, DM_DEVICE_TYPE t "; + + //Add the query to filter active devices on timestamp + if (since != null) { + sql = sql + ", DM_DEVICE_DETAIL dt"; + isSinceProvided = true; + } + + sql = sql + " WHERE DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ?"; + + //Add query for last updated timestamp + if (isSinceProvided) { + sql = sql + " AND dt.DEVICE_ID = d.ID AND dt.UPDATE_TIMESTAMP > ?"; + } //Add the query for device-type if (deviceType != null && !deviceType.isEmpty()) { @@ -96,6 +112,9 @@ public class SQLServerDeviceDAOImpl extends AbstractDeviceDAOImpl { stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); int paramIdx = 2; + if (isSinceProvided) { + stmt.setLong(paramIdx++, since.getTime()); + } if (isDeviceTypeProvided) { stmt.setString(paramIdx++, request.getDeviceType()); } diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/OperationManagementDAOFactory.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/OperationManagementDAOFactory.java index e22a83c59e..bfa28a6652 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/OperationManagementDAOFactory.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/OperationManagementDAOFactory.java @@ -28,7 +28,6 @@ import org.wso2.carbon.device.mgt.core.config.datasource.DataSourceConfig; import org.wso2.carbon.device.mgt.core.config.datasource.JNDILookupDefinition; import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; import org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.*; -import org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.operation.H2OperationDAOImpl; import org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.operation.MySQLOperationDAOImpl; import org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.operation.OracleOperationDAOImpl; import org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.operation.PostgreSQLOperationDAOImpl; @@ -77,7 +76,7 @@ public class OperationManagementDAOFactory { case DeviceManagementConstants.DataBaseTypes.DB_TYPE_POSTGRESQL: return new PostgreSQLOperationDAOImpl(); case DeviceManagementConstants.DataBaseTypes.DB_TYPE_H2: - return new H2OperationDAOImpl(); + return new GenericOperationDAOImpl(); case DeviceManagementConstants.DataBaseTypes.DB_TYPE_MYSQL: return new MySQLOperationDAOImpl(); default: diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/impl/operation/H2OperationDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/impl/operation/H2OperationDAOImpl.java deleted file mode 100644 index ef2b57b2a5..0000000000 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/impl/operation/H2OperationDAOImpl.java +++ /dev/null @@ -1,174 +0,0 @@ -/* - * Copyright (c) 2016a, WSO2 Inc. (http://www.wso2.org) All Rights Reserved. - * - * WSO2 Inc. licenses this file to you under the Apache License, - * Version 2.0 (the "License"); you may not use this file except - * in compliance with the License. - * you may obtain a copy of the License at - * - * http://www.apache.org/licenses/LICENSE-2.0 - * - * Unless required by applicable law or agreed to in writing, - * software distributed under the License is distributed on an - * "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY - * KIND, either express or implied. See the License for the - * specific language governing permissions and limitations - * under the License. - */ - -package org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.operation; - -import org.wso2.carbon.context.PrivilegedCarbonContext; -import org.wso2.carbon.device.mgt.common.DeviceIdentifier; -import org.wso2.carbon.device.mgt.common.operation.mgt.Activity; -import org.wso2.carbon.device.mgt.common.operation.mgt.ActivityStatus; -import org.wso2.carbon.device.mgt.common.operation.mgt.OperationResponse; -import org.wso2.carbon.device.mgt.core.operation.mgt.dao.OperationManagementDAOException; -import org.wso2.carbon.device.mgt.core.operation.mgt.dao.OperationManagementDAOFactory; -import org.wso2.carbon.device.mgt.core.operation.mgt.dao.OperationManagementDAOUtil; -import org.wso2.carbon.device.mgt.core.operation.mgt.dao.impl.GenericOperationDAOImpl; -import org.wso2.carbon.device.mgt.core.operation.mgt.dao.util.OperationDAOUtil; - -import java.io.IOException; -import java.sql.Connection; -import java.sql.PreparedStatement; -import java.sql.ResultSet; -import java.sql.SQLException; -import java.util.ArrayList; -import java.util.List; - -/** - * This class holds the implementation of OperationDAO which can be used to support H2 db syntax. - */ -public class H2OperationDAOImpl extends GenericOperationDAOImpl { - - @Override - public List getActivitiesUpdatedAfter(long timestamp, int limit, int offset) throws OperationManagementDAOException { - PreparedStatement stmt = null; - ResultSet rs = null; - List activities = new ArrayList<>(); - try { - Connection conn = OperationManagementDAOFactory.getConnection(); - String sql = "SELECT feom.ENROLMENT_ID, feom.OPERATION_ID, feom.CREATED_TIMESTAMP, o.TYPE AS OPERATION_TYPE, " + - "o.OPERATION_CODE, orsp.OPERATION_RESPONSE, orsp.LATEST_RECEIVED_TIMESTAMP AS RECEIVED_TIMESTAMP, " + - "orsp.ID AS OP_RES_ID, feom.STATUS, feom.UPDATED_TIMESTAMP, feom.DEVICE_IDENTIFICATION, " + - "feom.DEVICE_TYPE FROM (SELECT eom.ENROLMENT_ID, eom.OPERATION_ID, eom.STATUS, eom.CREATED_TIMESTAMP, " + - "eom.UPDATED_TIMESTAMP, fe.DEVICE_IDENTIFICATION, fe.DEVICE_TYPE FROM " + - "(SELECT ENROLMENT_ID, OPERATION_ID, STATUS, CREATED_TIMESTAMP, UPDATED_TIMESTAMP " + - "FROM DM_ENROLMENT_OP_MAPPING WHERE UPDATED_TIMESTAMP > ? ORDER BY OPERATION_ID LIMIT ? OFFSET ?) eom " + - "LEFT OUTER JOIN (SELECT e.ID AS ENROLMENT_ID, d.ID AS DEVICE_ID, d.DEVICE_IDENTIFICATION, " + - "t.NAME AS DEVICE_TYPE FROM DM_ENROLMENT e LEFT OUTER JOIN DM_DEVICE d ON e.DEVICE_ID = d.ID " + - "LEFT OUTER JOIN DM_DEVICE_TYPE t ON d.DEVICE_TYPE_ID = t.ID WHERE d.TENANT_ID = ? AND " + - "e.TENANT_ID = ?) fe ON fe.ENROLMENT_ID = eom.ENROLMENT_ID) feom LEFT OUTER JOIN DM_OPERATION o " + - "ON feom.OPERATION_ID = o.ID LEFT OUTER JOIN (SELECT ID, ENROLMENT_ID, OPERATION_ID, " + - "OPERATION_RESPONSE, MAX(RECEIVED_TIMESTAMP) LATEST_RECEIVED_TIMESTAMP " + - "FROM DM_DEVICE_OPERATION_RESPONSE GROUP BY ENROLMENT_ID , OPERATION_ID) orsp " + - "ON o.ID = orsp.OPERATION_ID AND feom.ENROLMENT_ID = orsp.ENROLMENT_ID GROUP BY feom.ENROLMENT_ID, " + - "feom.OPERATION_ID, feom.CREATED_TIMESTAMP, o.TYPE, o.OPERATION_CODE, orsp.OPERATION_RESPONSE, " + - "orsp.LATEST_RECEIVED_TIMESTAMP, orsp.ID, feom.STATUS, feom.UPDATED_TIMESTAMP, " + - "feom.DEVICE_IDENTIFICATION, feom.DEVICE_TYPE"; - - stmt = conn.prepareStatement(sql); - - stmt.setLong(1, timestamp); - stmt.setInt(2, limit); - stmt.setInt(3, offset); - int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); - stmt.setInt(4, tenantId); - stmt.setInt(5, tenantId); - - rs = stmt.executeQuery(); - - int operationId = 0; - int enrolmentId = 0; - int responseId = 0; - Activity activity = null; - ActivityStatus activityStatus = null; - while (rs.next()) { - - if (operationId != rs.getInt("OPERATION_ID")) { - activity = new Activity(); - activities.add(activity); - List statusList = new ArrayList<>(); - activityStatus = new ActivityStatus(); - - operationId = rs.getInt("OPERATION_ID"); - enrolmentId = rs.getInt("ENROLMENT_ID"); - - activity.setType(Activity.Type.valueOf(rs.getString("OPERATION_TYPE"))); - activity.setCreatedTimeStamp(new java.util.Date(rs.getLong(("CREATED_TIMESTAMP")) * 1000).toString()); - activity.setCode(rs.getString("OPERATION_CODE")); - - DeviceIdentifier deviceIdentifier = new DeviceIdentifier(); - deviceIdentifier.setId(rs.getString("DEVICE_IDENTIFICATION")); - deviceIdentifier.setType(rs.getString("DEVICE_TYPE")); - activityStatus.setDeviceIdentifier(deviceIdentifier); - - activityStatus.setStatus(ActivityStatus.Status.valueOf(rs.getString("STATUS"))); - - List operationResponses = new ArrayList<>(); - if (rs.getInt("UPDATED_TIMESTAMP") != 0) { - activityStatus.setUpdatedTimestamp(new java.util.Date( - rs.getLong(("UPDATED_TIMESTAMP")) * 1000).toString()); - - } - if (rs.getTimestamp("RECEIVED_TIMESTAMP") != (null)) { - operationResponses.add(OperationDAOUtil.getOperationResponse(rs)); - responseId = rs.getInt("OP_RES_ID"); - } - activityStatus.setResponses(operationResponses); - statusList.add(activityStatus); - activity.setActivityStatus(statusList); - activity.setActivityId(OperationDAOUtil.getActivityId(rs.getInt("OPERATION_ID"))); - - } - - if (operationId == rs.getInt("OPERATION_ID") && enrolmentId != rs.getInt("ENROLMENT_ID")) { - activityStatus = new ActivityStatus(); - - activity.setType(Activity.Type.valueOf(rs.getString("OPERATION_TYPE"))); - activity.setCreatedTimeStamp(new java.util.Date(rs.getLong(("CREATED_TIMESTAMP")) * 1000).toString()); - activity.setCode(rs.getString("OPERATION_CODE")); - - DeviceIdentifier deviceIdentifier = new DeviceIdentifier(); - deviceIdentifier.setId(rs.getString("DEVICE_IDENTIFICATION")); - deviceIdentifier.setType(rs.getString("DEVICE_TYPE")); - activityStatus.setDeviceIdentifier(deviceIdentifier); - - activityStatus.setStatus(ActivityStatus.Status.valueOf(rs.getString("STATUS"))); - - List operationResponses = new ArrayList<>(); - if (rs.getInt("UPDATED_TIMESTAMP") != 0) { - activityStatus.setUpdatedTimestamp(new java.util.Date( - rs.getLong(("UPDATED_TIMESTAMP")) * 1000).toString()); - } - if (rs.getTimestamp("RECEIVED_TIMESTAMP") != (null)) { - operationResponses.add(OperationDAOUtil.getOperationResponse(rs)); - responseId = rs.getInt("OP_RES_ID"); - } - activityStatus.setResponses(operationResponses); - activity.getActivityStatus().add(activityStatus); - - enrolmentId = rs.getInt("ENROLMENT_ID"); - } - - if (rs.getInt("OP_RES_ID") != 0 && responseId != rs.getInt("OP_RES_ID")) { - if (rs.getTimestamp("RECEIVED_TIMESTAMP") != (null)) { - activityStatus.getResponses().add(OperationDAOUtil.getOperationResponse(rs)); - responseId = rs.getInt("OP_RES_ID"); - } - } - } - } catch (SQLException e) { - throw new OperationManagementDAOException("Error occurred while getting the operation details from " + - "the database.", e); - } catch (ClassNotFoundException e) { - throw new OperationManagementDAOException("Error occurred while converting the operation response to string.", e); - } catch (IOException e) { - throw new OperationManagementDAOException("IO exception occurred while converting the operations responses.", e); - } finally { - OperationManagementDAOUtil.cleanupResources(stmt, rs); - } - return activities; - } -} \ No newline at end of file diff --git a/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/mssql.sql b/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/mssql.sql index d230792327..f66ed45578 100644 --- a/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/mssql.sql +++ b/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/mssql.sql @@ -14,7 +14,7 @@ CREATE TABLE DM_DEVICE ( NAME VARCHAR(100) DEFAULT NULL, DEVICE_TYPE_ID INTEGER DEFAULT NULL, DEVICE_IDENTIFICATION VARCHAR(300) DEFAULT NULL, - LAST_UPDATED_TIMESTAMP TIMESTAMP NOT NULL, + LAST_UPDATED_TIMESTAMP DATETIME2 NOT NULL, TENANT_ID INTEGER DEFAULT 0, PRIMARY KEY (ID), CONSTRAINT FK_DM_DEVICE_DM_DEVICE_TYPE2 FOREIGN KEY (DEVICE_TYPE_ID)