From 27cceecd33a2f28f726f3d8e39a88e5cc078ef34 Mon Sep 17 00:00:00 2001 From: Kavin Prathaban Date: Tue, 25 Apr 2023 07:50:37 +0000 Subject: [PATCH] Fix device enrolment using MSSQL as database (#72) ## Purpose * Fixes https://roadmap.entgra.net/issues/9859 ## Description * Fix device enrolment using MSSQL as database * Fix test case failures of database engine getting a null value Co-authored-by: prathabanKavin Co-authored-by: Pahansith Gunathilake Reviewed-on: https://repository.entgra.net/community/device-mgt-core/pulls/72 Co-authored-by: Kavin Prathaban Co-committed-by: Kavin Prathaban --- .../core/dao/DeviceManagementDAOFactory.java | 18 +- ...pl.java => AbstractEnrollmentDAOImpl.java} | 2 +- .../enrolment/GenericEnrollmentDAOImpl.java | 555 ++++++++++++++++++ .../enrolment/SQLServerEnrollmentDAOImpl.java | 554 +++++++++++++++++ .../dao/DeviceStatusPersistenceTests.java | 14 +- .../core/dao/EnrolmentPersistenceTests.java | 15 +- .../main/resources/dbscripts/cdm/mssql.sql | 16 + 7 files changed, 1157 insertions(+), 17 deletions(-) rename components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/{EnrollmentDAOImpl.java => AbstractEnrollmentDAOImpl.java} (99%) create mode 100644 components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/GenericEnrollmentDAOImpl.java create mode 100644 components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/SQLServerEnrollmentDAOImpl.java diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/DeviceManagementDAOFactory.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/DeviceManagementDAOFactory.java index cbd7c697f4a..b6aadb113f6 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/DeviceManagementDAOFactory.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/DeviceManagementDAOFactory.java @@ -31,6 +31,8 @@ import org.wso2.carbon.device.mgt.core.dao.impl.device.GenericDeviceDAOImpl; import org.wso2.carbon.device.mgt.core.dao.impl.device.OracleDeviceDAOImpl; import org.wso2.carbon.device.mgt.core.dao.impl.device.PostgreSQLDeviceDAOImpl; import org.wso2.carbon.device.mgt.core.dao.impl.device.SQLServerDeviceDAOImpl; +import org.wso2.carbon.device.mgt.core.dao.impl.enrolment.GenericEnrollmentDAOImpl; +import org.wso2.carbon.device.mgt.core.dao.impl.enrolment.SQLServerEnrollmentDAOImpl; import org.wso2.carbon.device.mgt.core.dao.impl.tracker.TrackerDAOImpl; import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; import org.wso2.carbon.device.mgt.core.device.details.mgt.dao.DeviceDetailsDAO; @@ -41,7 +43,6 @@ import org.wso2.carbon.device.mgt.core.privacy.dao.impl.PrivacyComplianceDAOImpl import javax.sql.DataSource; import java.sql.Connection; import java.sql.SQLException; -import java.sql.Timestamp; import java.util.Hashtable; import java.util.List; @@ -122,7 +123,20 @@ public class DeviceManagementDAOFactory { } public static EnrollmentDAO getEnrollmentDAO() { - return new EnrollmentDAOImpl(); + if (databaseEngine != null) { + switch (databaseEngine) { + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_MSSQL: + return new SQLServerEnrollmentDAOImpl(); + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_POSTGRESQL: + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_ORACLE: + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_H2: + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_MYSQL: + return new GenericEnrollmentDAOImpl(); + default: + throw new UnsupportedDatabaseEngineException("Unsupported database engine : " + databaseEngine); + } + } + throw new IllegalStateException("Database engine has not initialized properly."); } public static TrackerDAO getTrackerDAO() { diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/EnrollmentDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/AbstractEnrollmentDAOImpl.java similarity index 99% rename from components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/EnrollmentDAOImpl.java rename to components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/AbstractEnrollmentDAOImpl.java index 7b3e08cd509..a3757bc523d 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/EnrollmentDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/AbstractEnrollmentDAOImpl.java @@ -37,7 +37,7 @@ import java.util.ArrayList; import java.util.Date; import java.util.List; -public class EnrollmentDAOImpl implements EnrollmentDAO { +public abstract class AbstractEnrollmentDAOImpl implements EnrollmentDAO { @Override public EnrolmentInfo addEnrollment(int deviceId, EnrolmentInfo enrolmentInfo, diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/GenericEnrollmentDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/GenericEnrollmentDAOImpl.java new file mode 100644 index 00000000000..041efbf285d --- /dev/null +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/GenericEnrollmentDAOImpl.java @@ -0,0 +1,555 @@ +/* + * Copyright (c) 2023, 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.dao.impl.enrolment; + +import org.wso2.carbon.context.PrivilegedCarbonContext; +import org.wso2.carbon.device.mgt.common.Device; +import org.wso2.carbon.device.mgt.common.DeviceManagementConstants; +import org.wso2.carbon.device.mgt.common.EnrolmentInfo; +import org.wso2.carbon.device.mgt.core.dao.DeviceManagementDAOException; +import org.wso2.carbon.device.mgt.core.dao.DeviceManagementDAOFactory; +import org.wso2.carbon.device.mgt.core.dao.impl.AbstractEnrollmentDAOImpl; +import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; + +import java.sql.*; +import java.util.ArrayList; +import java.util.Date; +import java.util.List; + +public class GenericEnrollmentDAOImpl extends AbstractEnrollmentDAOImpl { + + @Override + public EnrolmentInfo addEnrollment(int deviceId, EnrolmentInfo enrolmentInfo, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + try { + conn = this.getConnection(); + String sql = "INSERT INTO DM_ENROLMENT(DEVICE_ID, OWNER, OWNERSHIP, STATUS, " + + "DATE_OF_ENROLMENT, DATE_OF_LAST_UPDATE, TENANT_ID) VALUES(?, ?, ?, ?, ?, ?, ?)"; + stmt = conn.prepareStatement(sql, new String[] {"id"}); + Timestamp enrollmentTime = new Timestamp(new Date().getTime()); + stmt.setInt(1, deviceId); + stmt.setString(2, enrolmentInfo.getOwner()); + stmt.setString(3, enrolmentInfo.getOwnership().toString()); + stmt.setString(4, enrolmentInfo.getStatus().toString()); + stmt.setTimestamp(5, enrollmentTime); + stmt.setTimestamp(6, enrollmentTime); + stmt.setInt(7, tenantId); + stmt.execute(); + + rs = stmt.getGeneratedKeys(); + if (rs.next()) { + int enrolmentId = rs.getInt(1); + enrolmentInfo.setId(enrolmentId); + enrolmentInfo.setDateOfEnrolment(enrollmentTime.getTime()); + enrolmentInfo.setDateOfLastUpdate(enrollmentTime.getTime()); + addDeviceStatus(enrolmentId, enrolmentInfo.getStatus()); + return enrolmentInfo; + } + return null; + } catch (SQLException e) { + e.printStackTrace(); + throw new DeviceManagementDAOException("Error occurred while adding enrolment configuration", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public int updateEnrollment(EnrolmentInfo enrolmentInfo, int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET OWNERSHIP = ?, STATUS = ?, DATE_OF_LAST_UPDATE = ? " + + "WHERE ID = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, enrolmentInfo.getOwnership().toString()); + stmt.setString(2, enrolmentInfo.getStatus().toString()); + stmt.setTimestamp(3, new Timestamp(new Date().getTime())); + stmt.setInt(4, enrolmentInfo.getId()); + stmt.setInt(5, tenantId); + int updatedCount = stmt.executeUpdate(); + if (updatedCount == 1){ + addDeviceStatus(enrolmentInfo.getId(), enrolmentInfo.getStatus()); + } + return updatedCount; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while updating enrolment configuration", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public boolean updateEnrollmentStatus(List enrolmentInfos) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + boolean status = false; + int updateStatus = -1; + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET STATUS = ? WHERE ID = ?"; + stmt = conn.prepareStatement(sql); + if (conn.getMetaData().supportsBatchUpdates()) { + for (EnrolmentInfo enrolmentInfo : enrolmentInfos) { + stmt.setString(1, enrolmentInfo.getStatus().toString()); + stmt.setInt(2, enrolmentInfo.getId()); + stmt.addBatch(); + } + updateStatus = stmt.executeBatch().length; + } else { + for (EnrolmentInfo enrolmentInfo : enrolmentInfos) { + stmt.setString(1, enrolmentInfo.getStatus().toString()); + stmt.setInt(2, enrolmentInfo.getId()); + updateStatus = stmt.executeUpdate(); + } + } + if (updateStatus > 0) { + status = true; + for (EnrolmentInfo enrolmentInfo : enrolmentInfos) { + addDeviceStatus(enrolmentInfo); + } + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while updating enrolment status of given device-list.", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + return status; + } + + @Override + public int removeEnrollment(int deviceId, String currentOwner, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + int status = -1; + try { + conn = this.getConnection(); + String sql = "DELETE FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql, new String[] {"id"}); + stmt.setInt(1, deviceId); + stmt.setString(2, currentOwner); + stmt.setInt(3, tenantId); + stmt.executeUpdate(); + + rs = stmt.getGeneratedKeys(); + if (rs.next()) { + status = 1; + } + return status; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while removing device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + private int getCountOfDevicesOfOwner(String owner, int tenantID) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + int count = 0; + try { + conn = this.getConnection(); + String checkQuery = "SELECT COUNT(ID) AS COUNT FROM DM_ENROLMENT WHERE OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(checkQuery); + stmt.setString(1, owner); + stmt.setInt(2, tenantID); + rs = stmt.executeQuery(); + if(rs.next()){ + count = rs.getInt("COUNT"); + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while trying to get device " + + "count of Owner : "+owner, e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + return count; + } + + @Override + public boolean setStatus(String currentOwner, EnrolmentInfo.Status status, + int tenantId) throws DeviceManagementDAOException { + return setStatusAllDevices(currentOwner, status, tenantId); + } + + @Override + public boolean setStatusAllDevices(String currentOwner, EnrolmentInfo.Status status, int tenantId) + throws DeviceManagementDAOException{ + Connection conn; + PreparedStatement stmt = null; + Timestamp updateTime = new Timestamp(new Date().getTime()); + if(getCountOfDevicesOfOwner(currentOwner, tenantId) > 0){ + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET STATUS = ?, DATE_OF_LAST_UPDATE = ? WHERE OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, status.toString()); + stmt.setTimestamp(2, updateTime); + stmt.setString(3, currentOwner); + stmt.setInt(4, tenantId); + stmt.executeUpdate(); + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + return addDeviceStatus(currentOwner, status, tenantId); + } else { + return false; + } + } + + @Override + public boolean setStatus(int enrolmentID, EnrolmentInfo.Status status, int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + Timestamp updateTime = new Timestamp(new Date().getTime()); + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET STATUS = ?, DATE_OF_LAST_UPDATE = ? WHERE ID = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, status.toString()); + stmt.setTimestamp(2, updateTime); + stmt.setInt(3, enrolmentID); + stmt.setInt(4, tenantId); + int updatedRowCount = stmt.executeUpdate(); + if (updatedRowCount != 1){ + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment: "+ + updatedRowCount + " rows were updated instead of one row!!!"); + } + // save the device status history + addDeviceStatus(enrolmentID, status); + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + return true; + } + + private boolean addDeviceStatus(EnrolmentInfo config) throws DeviceManagementDAOException { + return addDeviceStatus(config.getId(), config.getStatus()); + } + + private boolean addDeviceStatus(String currentOwner, EnrolmentInfo.Status status, int tenantId) throws DeviceManagementDAOException { + Connection conn; + String changedBy = PrivilegedCarbonContext.getThreadLocalCarbonContext().getUsername(); + if (changedBy == null){ + changedBy = DeviceManagementConstants.MaintenanceProperties.MAINTENANCE_USER; + } + PreparedStatement stmt = null; + ResultSet rs = null; + List enrolmentInfoList = new ArrayList<>(); + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, currentOwner); + stmt.setInt(2, tenantId); + rs = stmt.executeQuery(); + while (rs.next()) { + int enrolmentId = rs.getInt("ID"); + int deviceId = rs.getInt("DEVICE_ID"); + enrolmentInfoList.add(new int[]{enrolmentId, deviceId}); + } + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + Timestamp updateTime = new Timestamp(new Date().getTime()); + sql = "INSERT INTO DM_DEVICE_STATUS (ENROLMENT_ID, DEVICE_ID, STATUS, UPDATE_TIME, CHANGED_BY) VALUES(?, ?, ?, ?, ?)"; + try (PreparedStatement ps = conn.prepareStatement(sql)) { + if (conn.getMetaData().supportsBatchUpdates()) { + for(int[] info: enrolmentInfoList){ + ps.setInt(1, info[0]); + ps.setInt(2, info[1]); + ps.setString(3, status.toString()); + ps.setTimestamp(4, updateTime); + ps.setString(5, changedBy); + ps.addBatch(); + } + int[] batchResult = ps.executeBatch(); + for (int i : batchResult) { + if (i == 0 || i == Statement.SUCCESS_NO_INFO || i == Statement.EXECUTE_FAILED) { + return false; + } + } + } else { + for(int[] info: enrolmentInfoList){ + ps.setInt(1, info[0]); + ps.setInt(2, info[1]); + ps.setString(3, status.toString()); + ps.setTimestamp(4, updateTime); + ps.setString(5, changedBy); + ps.execute(); + } + + } + } + + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolments " + + "information of owner '" + currentOwner + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + return true; + } + + private boolean addDeviceStatus(int enrolmentId, EnrolmentInfo.Status status) throws DeviceManagementDAOException { + Connection conn; + String changedBy = PrivilegedCarbonContext.getThreadLocalCarbonContext().getUsername(); + if (changedBy == null){ + changedBy = DeviceManagementConstants.MaintenanceProperties.MAINTENANCE_USER; + } + PreparedStatement stmt = null; + try { + conn = this.getConnection(); + // get the device id and last udpated status from the device status table + String sql = "SELECT DEVICE_ID, STATUS FROM DM_DEVICE_STATUS WHERE ENROLMENT_ID = ? ORDER BY UPDATE_TIME DESC LIMIT 1"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, enrolmentId); + ResultSet rs = stmt.executeQuery(); + int deviceId = -1; + EnrolmentInfo.Status previousStatus = null; + if (rs.next()) { + // if there is a record corresponding to the enrolment we save the status and the device id + previousStatus = EnrolmentInfo.Status.valueOf(rs.getString("STATUS")); + deviceId = rs.getInt("DEVICE_ID"); + } + DeviceManagementDAOUtil.cleanupResources(stmt, null); + // if there was no record for the enrolment or the previous status is not the same as the current status + // we'll add a record + if (previousStatus == null || previousStatus != status){ + if (deviceId == -1) { + // we need the device id in order to add a new record, therefore we get it from the enrolment table + sql = "SELECT DEVICE_ID FROM DM_ENROLMENT WHERE ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, enrolmentId); + rs = stmt.executeQuery(); + if (rs.next()) { + deviceId = rs.getInt("DEVICE_ID"); + } else { + // if there were no records corresponding to the enrolment id this is a problem. i.e. enrolment + // id is invalid + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment: no record for enrolment id " + enrolmentId); + } + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + + sql = "INSERT INTO DM_DEVICE_STATUS (ENROLMENT_ID, DEVICE_ID, STATUS, UPDATE_TIME, CHANGED_BY) VALUES(?, ?, ?, ?, ?)"; + stmt = conn.prepareStatement(sql); + Timestamp updateTime = new Timestamp(new Date().getTime()); + stmt.setInt(1, enrolmentId); + stmt.setInt(2, deviceId); + stmt.setString(3, status.toString()); + stmt.setTimestamp(4, updateTime); + stmt.setString(5, changedBy); + stmt.execute(); + } else { + // no need to update status since the last recorded status is the same as the current status + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + return true; + } + @Override + public EnrolmentInfo.Status getStatus(int deviceId, String currentOwner, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo.Status status = null; + try { + conn = this.getConnection(); + String sql = "SELECT STATUS FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setString(2, currentOwner); + stmt.setInt(3, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + status = EnrolmentInfo.Status.valueOf(rs.getString("STATUS")); + } + return status; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public EnrolmentInfo getEnrollment(int deviceId, String currentOwner, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo enrolmentInfo = null; + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setString(2, currentOwner); + stmt.setInt(3, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + enrolmentInfo = this.loadEnrolment(rs); + } + return enrolmentInfo; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolment " + + "information of user '" + currentOwner + "' upon device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public EnrolmentInfo getEnrollment(int deviceId, int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo enrolmentInfo = null; + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND TENANT_ID = ? " + + "ORDER BY DATE_OF_LAST_UPDATE DESC"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setInt(2, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + enrolmentInfo = this.loadEnrolment(rs); + } + return enrolmentInfo; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolment " + + "information of device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public List getEnrollmentsOfUser(int deviceId, String user, int tenantId) + throws DeviceManagementDAOException { + List enrolmentInfos = new ArrayList<>(); + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo enrolmentInfo = null; + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setString(2, user); + stmt.setInt(3, tenantId); + rs = stmt.executeQuery(); + while (rs.next()) { + enrolmentInfo = this.loadEnrolment(rs); + enrolmentInfos.add(enrolmentInfo); + } + return enrolmentInfos; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolments " + + "information of user '" + user + "' upon device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public boolean updateOwnerOfEnrollment(List devices, String owner, int tenantId) + throws DeviceManagementDAOException { + try { + Connection conn = this.getConnection(); + boolean updateStatus = true; + String sql = "UPDATE DM_ENROLMENT " + + "SET OWNER = ?, IS_TRANSFERRED = ?, DATE_OF_LAST_UPDATE = ? " + + "WHERE ID = ? AND TENANT_ID = ?"; + try (PreparedStatement ps = conn.prepareStatement(sql)) { + if (conn.getMetaData().supportsBatchUpdates()) { + for (Device device : devices) { + ps.setString(1, owner); + ps.setBoolean(2, device.getEnrolmentInfo().isTransferred()); + ps.setTimestamp(3, new Timestamp(new Date().getTime())); + ps.setInt(4, device.getEnrolmentInfo().getId()); + ps.setInt(5, tenantId); + ps.addBatch(); + } + int[] batchResult = ps.executeBatch(); + for (int i : batchResult) { + if (i == 0 || i == Statement.SUCCESS_NO_INFO || i == Statement.EXECUTE_FAILED) { + updateStatus = false; + break; + } + } + } else { + for (Device device : devices) { + ps.setString(1, owner); + ps.setBoolean(2, device.getEnrolmentInfo().isTransferred()); + ps.setInt(3, device.getId()); + ps.setInt(4, tenantId); + if (ps.executeUpdate() == 0) { + updateStatus = false; + break; + } + } + } + } + return updateStatus; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while obtaining the DB connection to update the " + + "owner of the device enrollment.", e); + } + } + + private Connection getConnection() throws SQLException { + return DeviceManagementDAOFactory.getConnection(); + } + + private EnrolmentInfo loadEnrolment(ResultSet rs) throws SQLException { + EnrolmentInfo enrolmentInfo = new EnrolmentInfo(); + enrolmentInfo.setOwner(rs.getString("OWNER")); + enrolmentInfo.setOwnership(EnrolmentInfo.OwnerShip.valueOf(rs.getString("OWNERSHIP"))); + enrolmentInfo.setTransferred(rs.getBoolean("IS_TRANSFERRED")); + enrolmentInfo.setDateOfEnrolment(rs.getTimestamp("DATE_OF_ENROLMENT").getTime()); + enrolmentInfo.setDateOfLastUpdate(rs.getTimestamp("DATE_OF_LAST_UPDATE").getTime()); + enrolmentInfo.setStatus(EnrolmentInfo.Status.valueOf(rs.getString("STATUS"))); + enrolmentInfo.setId(rs.getInt("ID")); + return enrolmentInfo; + } + +} diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/SQLServerEnrollmentDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/SQLServerEnrollmentDAOImpl.java new file mode 100644 index 00000000000..8041d07a598 --- /dev/null +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/dao/impl/enrolment/SQLServerEnrollmentDAOImpl.java @@ -0,0 +1,554 @@ +/* + * Copyright (c) 2023, 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.dao.impl.enrolment; + +import org.wso2.carbon.context.PrivilegedCarbonContext; +import org.wso2.carbon.device.mgt.common.Device; +import org.wso2.carbon.device.mgt.common.DeviceManagementConstants; +import org.wso2.carbon.device.mgt.common.EnrolmentInfo; +import org.wso2.carbon.device.mgt.core.dao.DeviceManagementDAOException; +import org.wso2.carbon.device.mgt.core.dao.DeviceManagementDAOFactory; +import org.wso2.carbon.device.mgt.core.dao.impl.AbstractEnrollmentDAOImpl; +import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; +import java.sql.*; +import java.util.ArrayList; +import java.util.Date; +import java.util.List; + +public class SQLServerEnrollmentDAOImpl extends AbstractEnrollmentDAOImpl { + + @Override + public EnrolmentInfo addEnrollment(int deviceId, EnrolmentInfo enrolmentInfo, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + try { + conn = this.getConnection(); + String sql = "INSERT INTO DM_ENROLMENT(DEVICE_ID, OWNER, OWNERSHIP, STATUS, " + + "DATE_OF_ENROLMENT, DATE_OF_LAST_UPDATE, TENANT_ID) VALUES(?, ?, ?, ?, ?, ?, ?)"; + stmt = conn.prepareStatement(sql, new String[] {"id"}); + Timestamp enrollmentTime = new Timestamp(new Date().getTime()); + stmt.setInt(1, deviceId); + stmt.setString(2, enrolmentInfo.getOwner()); + stmt.setString(3, enrolmentInfo.getOwnership().toString()); + stmt.setString(4, enrolmentInfo.getStatus().toString()); + stmt.setTimestamp(5, enrollmentTime); + stmt.setTimestamp(6, enrollmentTime); + stmt.setInt(7, tenantId); + stmt.execute(); + + rs = stmt.getGeneratedKeys(); + if (rs.next()) { + int enrolmentId = rs.getInt(1); + enrolmentInfo.setId(enrolmentId); + enrolmentInfo.setDateOfEnrolment(enrollmentTime.getTime()); + enrolmentInfo.setDateOfLastUpdate(enrollmentTime.getTime()); + addDeviceStatus(enrolmentId, enrolmentInfo.getStatus()); + return enrolmentInfo; + } + return null; + } catch (SQLException e) { + e.printStackTrace(); + throw new DeviceManagementDAOException("Error occurred while adding enrolment configuration", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public int updateEnrollment(EnrolmentInfo enrolmentInfo, int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET OWNERSHIP = ?, STATUS = ?, DATE_OF_LAST_UPDATE = ? " + + "WHERE ID = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, enrolmentInfo.getOwnership().toString()); + stmt.setString(2, enrolmentInfo.getStatus().toString()); + stmt.setTimestamp(3, new Timestamp(new Date().getTime())); + stmt.setInt(4, enrolmentInfo.getId()); + stmt.setInt(5, tenantId); + int updatedCount = stmt.executeUpdate(); + if (updatedCount == 1){ + addDeviceStatus(enrolmentInfo.getId(), enrolmentInfo.getStatus()); + } + return updatedCount; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while updating enrolment configuration", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public boolean updateEnrollmentStatus(List enrolmentInfos) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + boolean status = false; + int updateStatus = -1; + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET STATUS = ? WHERE ID = ?"; + stmt = conn.prepareStatement(sql); + if (conn.getMetaData().supportsBatchUpdates()) { + for (EnrolmentInfo enrolmentInfo : enrolmentInfos) { + stmt.setString(1, enrolmentInfo.getStatus().toString()); + stmt.setInt(2, enrolmentInfo.getId()); + stmt.addBatch(); + } + updateStatus = stmt.executeBatch().length; + } else { + for (EnrolmentInfo enrolmentInfo : enrolmentInfos) { + stmt.setString(1, enrolmentInfo.getStatus().toString()); + stmt.setInt(2, enrolmentInfo.getId()); + updateStatus = stmt.executeUpdate(); + } + } + if (updateStatus > 0) { + status = true; + for (EnrolmentInfo enrolmentInfo : enrolmentInfos) { + addDeviceStatus(enrolmentInfo); + } + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while updating enrolment status of given device-list.", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + return status; + } + + @Override + public int removeEnrollment(int deviceId, String currentOwner, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + int status = -1; + try { + conn = this.getConnection(); + String sql = "DELETE FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql, new String[] {"id"}); + stmt.setInt(1, deviceId); + stmt.setString(2, currentOwner); + stmt.setInt(3, tenantId); + stmt.executeUpdate(); + + rs = stmt.getGeneratedKeys(); + if (rs.next()) { + status = 1; + } + return status; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while removing device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + private int getCountOfDevicesOfOwner(String owner, int tenantID) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + int count = 0; + try { + conn = this.getConnection(); + String checkQuery = "SELECT COUNT(ID) AS COUNT FROM DM_ENROLMENT WHERE OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(checkQuery); + stmt.setString(1, owner); + stmt.setInt(2, tenantID); + rs = stmt.executeQuery(); + if(rs.next()){ + count = rs.getInt("COUNT"); + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while trying to get device " + + "count of Owner : "+owner, e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + return count; + } + + @Override + public boolean setStatus(String currentOwner, EnrolmentInfo.Status status, + int tenantId) throws DeviceManagementDAOException { + return setStatusAllDevices(currentOwner, status, tenantId); + } + + @Override + public boolean setStatusAllDevices(String currentOwner, EnrolmentInfo.Status status, int tenantId) + throws DeviceManagementDAOException{ + Connection conn; + PreparedStatement stmt = null; + Timestamp updateTime = new Timestamp(new Date().getTime()); + if(getCountOfDevicesOfOwner(currentOwner, tenantId) > 0){ + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET STATUS = ?, DATE_OF_LAST_UPDATE = ? WHERE OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, status.toString()); + stmt.setTimestamp(2, updateTime); + stmt.setString(3, currentOwner); + stmt.setInt(4, tenantId); + stmt.executeUpdate(); + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + return addDeviceStatus(currentOwner, status, tenantId); + } else { + return false; + } + } + + @Override + public boolean setStatus(int enrolmentID, EnrolmentInfo.Status status, int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + Timestamp updateTime = new Timestamp(new Date().getTime()); + try { + conn = this.getConnection(); + String sql = "UPDATE DM_ENROLMENT SET STATUS = ?, DATE_OF_LAST_UPDATE = ? WHERE ID = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, status.toString()); + stmt.setTimestamp(2, updateTime); + stmt.setInt(3, enrolmentID); + stmt.setInt(4, tenantId); + int updatedRowCount = stmt.executeUpdate(); + if (updatedRowCount != 1){ + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment: "+ + updatedRowCount + " rows were updated instead of one row!!!"); + } + // save the device status history + addDeviceStatus(enrolmentID, status); + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + return true; + } + + private boolean addDeviceStatus(EnrolmentInfo config) throws DeviceManagementDAOException { + return addDeviceStatus(config.getId(), config.getStatus()); + } + + private boolean addDeviceStatus(String currentOwner, EnrolmentInfo.Status status, int tenantId) throws DeviceManagementDAOException { + Connection conn; + String changedBy = PrivilegedCarbonContext.getThreadLocalCarbonContext().getUsername(); + if (changedBy == null){ + changedBy = DeviceManagementConstants.MaintenanceProperties.MAINTENANCE_USER; + } + PreparedStatement stmt = null; + ResultSet rs = null; + List enrolmentInfoList = new ArrayList<>(); + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, currentOwner); + stmt.setInt(2, tenantId); + rs = stmt.executeQuery(); + while (rs.next()) { + int enrolmentId = rs.getInt("ID"); + int deviceId = rs.getInt("DEVICE_ID"); + enrolmentInfoList.add(new int[]{enrolmentId, deviceId}); + } + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + Timestamp updateTime = new Timestamp(new Date().getTime()); + sql = "INSERT INTO DM_DEVICE_STATUS (ENROLMENT_ID, DEVICE_ID, STATUS, UPDATE_TIME, CHANGED_BY) VALUES(?, ?, ?, ?, ?)"; + try (PreparedStatement ps = conn.prepareStatement(sql)) { + if (conn.getMetaData().supportsBatchUpdates()) { + for(int[] info: enrolmentInfoList){ + ps.setInt(1, info[0]); + ps.setInt(2, info[1]); + ps.setString(3, status.toString()); + ps.setTimestamp(4, updateTime); + ps.setString(5, changedBy); + ps.addBatch(); + } + int[] batchResult = ps.executeBatch(); + for (int i : batchResult) { + if (i == 0 || i == Statement.SUCCESS_NO_INFO || i == Statement.EXECUTE_FAILED) { + return false; + } + } + } else { + for(int[] info: enrolmentInfoList){ + ps.setInt(1, info[0]); + ps.setInt(2, info[1]); + ps.setString(3, status.toString()); + ps.setTimestamp(4, updateTime); + ps.setString(5, changedBy); + ps.execute(); + } + + } + } + + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolments " + + "information of owner '" + currentOwner + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + return true; + } + + private boolean addDeviceStatus(int enrolmentId, EnrolmentInfo.Status status) throws DeviceManagementDAOException { + Connection conn; + String changedBy = PrivilegedCarbonContext.getThreadLocalCarbonContext().getUsername(); + if (changedBy == null){ + changedBy = DeviceManagementConstants.MaintenanceProperties.MAINTENANCE_USER; + } + PreparedStatement stmt = null; + try { + conn = this.getConnection(); + // get the device id and last udpated status from the device status table + String sql = "SELECT TOP 1 DEVICE_ID, STATUS FROM DM_DEVICE_STATUS WHERE ENROLMENT_ID = ? ORDER BY UPDATE_TIME DESC"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, enrolmentId); + ResultSet rs = stmt.executeQuery(); + int deviceId = -1; + EnrolmentInfo.Status previousStatus = null; + if (rs.next()) { + // if there is a record corresponding to the enrolment we save the status and the device id + previousStatus = EnrolmentInfo.Status.valueOf(rs.getString("STATUS")); + deviceId = rs.getInt("DEVICE_ID"); + } + DeviceManagementDAOUtil.cleanupResources(stmt, null); + // if there was no record for the enrolment or the previous status is not the same as the current status + // we'll add a record + if (previousStatus == null || previousStatus != status){ + if (deviceId == -1) { + // we need the device id in order to add a new record, therefore we get it from the enrolment table + sql = "SELECT DEVICE_ID FROM DM_ENROLMENT WHERE ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, enrolmentId); + rs = stmt.executeQuery(); + if (rs.next()) { + deviceId = rs.getInt("DEVICE_ID"); + } else { + // if there were no records corresponding to the enrolment id this is a problem. i.e. enrolment + // id is invalid + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment: no record for enrolment id " + enrolmentId); + } + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + + sql = "INSERT INTO DM_DEVICE_STATUS (ENROLMENT_ID, DEVICE_ID, STATUS, UPDATE_TIME, CHANGED_BY) VALUES(?, ?, ?, ?, ?)"; + stmt = conn.prepareStatement(sql); + Timestamp updateTime = new Timestamp(new Date().getTime()); + stmt.setInt(1, enrolmentId); + stmt.setInt(2, deviceId); + stmt.setString(3, status.toString()); + stmt.setTimestamp(4, updateTime); + stmt.setString(5, changedBy); + stmt.execute(); + } else { + // no need to update status since the last recorded status is the same as the current status + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, null); + } + return true; + } + @Override + public EnrolmentInfo.Status getStatus(int deviceId, String currentOwner, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo.Status status = null; + try { + conn = this.getConnection(); + String sql = "SELECT STATUS FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setString(2, currentOwner); + stmt.setInt(3, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + status = EnrolmentInfo.Status.valueOf(rs.getString("STATUS")); + } + return status; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while setting the status of device enrolment", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public EnrolmentInfo getEnrollment(int deviceId, String currentOwner, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo enrolmentInfo = null; + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setString(2, currentOwner); + stmt.setInt(3, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + enrolmentInfo = this.loadEnrolment(rs); + } + return enrolmentInfo; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolment " + + "information of user '" + currentOwner + "' upon device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public EnrolmentInfo getEnrollment(int deviceId, int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo enrolmentInfo = null; + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND TENANT_ID = ? " + + "ORDER BY DATE_OF_LAST_UPDATE DESC"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setInt(2, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + enrolmentInfo = this.loadEnrolment(rs); + } + return enrolmentInfo; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolment " + + "information of device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public List getEnrollmentsOfUser(int deviceId, String user, int tenantId) + throws DeviceManagementDAOException { + List enrolmentInfos = new ArrayList<>(); + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + EnrolmentInfo enrolmentInfo = null; + try { + conn = this.getConnection(); + String sql = "SELECT ID, DEVICE_ID, OWNER, OWNERSHIP, STATUS, IS_TRANSFERRED, DATE_OF_ENROLMENT, " + + "DATE_OF_LAST_UPDATE, TENANT_ID FROM DM_ENROLMENT WHERE DEVICE_ID = ? AND OWNER = ? AND TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setInt(1, deviceId); + stmt.setString(2, user); + stmt.setInt(3, tenantId); + rs = stmt.executeQuery(); + while (rs.next()) { + enrolmentInfo = this.loadEnrolment(rs); + enrolmentInfos.add(enrolmentInfo); + } + return enrolmentInfos; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolments " + + "information of user '" + user + "' upon device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + + @Override + public boolean updateOwnerOfEnrollment(List devices, String owner, int tenantId) + throws DeviceManagementDAOException { + try { + Connection conn = this.getConnection(); + boolean updateStatus = true; + String sql = "UPDATE DM_ENROLMENT " + + "SET OWNER = ?, IS_TRANSFERRED = ?, DATE_OF_LAST_UPDATE = ? " + + "WHERE ID = ? AND TENANT_ID = ?"; + try (PreparedStatement ps = conn.prepareStatement(sql)) { + if (conn.getMetaData().supportsBatchUpdates()) { + for (Device device : devices) { + ps.setString(1, owner); + ps.setBoolean(2, device.getEnrolmentInfo().isTransferred()); + ps.setTimestamp(3, new Timestamp(new Date().getTime())); + ps.setInt(4, device.getEnrolmentInfo().getId()); + ps.setInt(5, tenantId); + ps.addBatch(); + } + int[] batchResult = ps.executeBatch(); + for (int i : batchResult) { + if (i == 0 || i == Statement.SUCCESS_NO_INFO || i == Statement.EXECUTE_FAILED) { + updateStatus = false; + break; + } + } + } else { + for (Device device : devices) { + ps.setString(1, owner); + ps.setBoolean(2, device.getEnrolmentInfo().isTransferred()); + ps.setInt(3, device.getId()); + ps.setInt(4, tenantId); + if (ps.executeUpdate() == 0) { + updateStatus = false; + break; + } + } + } + } + return updateStatus; + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while obtaining the DB connection to update the " + + "owner of the device enrollment.", e); + } + } + + private Connection getConnection() throws SQLException { + return DeviceManagementDAOFactory.getConnection(); + } + + private EnrolmentInfo loadEnrolment(ResultSet rs) throws SQLException { + EnrolmentInfo enrolmentInfo = new EnrolmentInfo(); + enrolmentInfo.setOwner(rs.getString("OWNER")); + enrolmentInfo.setOwnership(EnrolmentInfo.OwnerShip.valueOf(rs.getString("OWNERSHIP"))); + enrolmentInfo.setTransferred(rs.getBoolean("IS_TRANSFERRED")); + enrolmentInfo.setDateOfEnrolment(rs.getTimestamp("DATE_OF_ENROLMENT").getTime()); + enrolmentInfo.setDateOfLastUpdate(rs.getTimestamp("DATE_OF_LAST_UPDATE").getTime()); + enrolmentInfo.setStatus(EnrolmentInfo.Status.valueOf(rs.getString("STATUS"))); + enrolmentInfo.setId(rs.getInt("ID")); + return enrolmentInfo; + } + +} diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/DeviceStatusPersistenceTests.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/DeviceStatusPersistenceTests.java index 65c22e11613..b2a8903c7fb 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/DeviceStatusPersistenceTests.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/DeviceStatusPersistenceTests.java @@ -39,9 +39,15 @@ import static org.wso2.carbon.device.mgt.common.EnrolmentInfo.Status.*; public class DeviceStatusPersistenceTests extends BaseDeviceManagementTest { private static final Log log = LogFactory.getLog(DeviceStatusPersistenceTests.class); - private EnrollmentDAO enrollmentDAO = DeviceManagementDAOFactory.getEnrollmentDAO(); + EnrollmentDAO enrollmentDAO; private DeviceStatusDAO deviceStatusDAO = DeviceManagementDAOFactory.getDeviceStatusDAO(); + @BeforeClass + @Override + public void init() throws Exception { + enrollmentDAO = DeviceManagementDAOFactory.getEnrollmentDAO(); + } + /** * Validate that the list of statuses received match the statuses * @param device @@ -245,10 +251,4 @@ public class DeviceStatusPersistenceTests extends BaseDeviceManagementTest { } return false; } - - @BeforeClass - @Override - public void init() throws Exception { - - } } diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/EnrolmentPersistenceTests.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/EnrolmentPersistenceTests.java index 9497324798e..10bf0a1b641 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/EnrolmentPersistenceTests.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/test/java/org/wso2/carbon/device/mgt/core/dao/EnrolmentPersistenceTests.java @@ -33,7 +33,14 @@ import java.sql.SQLException; public class EnrolmentPersistenceTests extends BaseDeviceManagementTest { private static final Log log = LogFactory.getLog(EnrolmentPersistenceTests.class); - private EnrollmentDAO enrollmentDAO = DeviceManagementDAOFactory.getEnrollmentDAO(); + EnrollmentDAO enrollmentDAO; + + @BeforeClass + @Override + public void init() throws Exception { + this.initDataSource(); + enrollmentDAO = DeviceManagementDAOFactory.getEnrollmentDAO(); + } @Test public void testAddEnrolment() { @@ -86,10 +93,4 @@ public class EnrolmentPersistenceTests extends BaseDeviceManagementTest { } return enrolmentInfo; } - - @BeforeClass - @Override - public void init() throws Exception { - this.initDataSource(); - } } diff --git a/features/device-mgt/org.wso2.carbon.device.mgt.basics.feature/src/main/resources/dbscripts/cdm/mssql.sql b/features/device-mgt/org.wso2.carbon.device.mgt.basics.feature/src/main/resources/dbscripts/cdm/mssql.sql index d43294bd34e..c8b809ae48b 100644 --- a/features/device-mgt/org.wso2.carbon.device.mgt.basics.feature/src/main/resources/dbscripts/cdm/mssql.sql +++ b/features/device-mgt/org.wso2.carbon.device.mgt.basics.feature/src/main/resources/dbscripts/cdm/mssql.sql @@ -10,6 +10,13 @@ CREATE TABLE DM_DEVICE_TYPE ( CONSTRAINT DEVICE_TYPE_NAME UNIQUE(NAME, PROVIDER_TENANT_ID) ); +IF NOT EXISTS (SELECT * FROM SYS.INDEXES WHERE NAME = 'IDX_DEVICE_TYPE' AND OBJECT_ID = OBJECT_ID('DM_DEVICE_TYPE')) +CREATE INDEX IDX_DEVICE_TYPE ON DM_DEVICE_TYPE (NAME, PROVIDER_TENANT_ID); +IF NOT EXISTS (SELECT * FROM SYS.INDEXES WHERE NAME = 'IDX_DEVICE_NAME' AND OBJECT_ID = OBJECT_ID('DM_DEVICE_TYPE')) +CREATE INDEX IDX_DEVICE_NAME ON DM_DEVICE_TYPE (NAME); +IF NOT EXISTS (SELECT * FROM SYS.INDEXES WHERE NAME = 'IDX_DEVICE_TYPE_DEVICE_NAME' AND OBJECT_ID = OBJECT_ID('DM_DEVICE_TYPE')) +CREATE INDEX IDX_DEVICE_TYPE_DEVICE_NAME ON DM_DEVICE_TYPE (ID, NAME); + IF NOT EXISTS (SELECT * FROM SYS.OBJECTS WHERE OBJECT_ID = OBJECT_ID(N'[DBO].[DM_DEVICE_CERTIFICATE]') AND TYPE IN (N'U')) CREATE TABLE DM_DEVICE_CERTIFICATE ( ID INTEGER IDENTITY(1,1) NOT NULL, @@ -165,6 +172,13 @@ CREATE TABLE DM_ENROLMENT_OP_MAPPING ( PUSH_NOTIFICATION_STATUS VARCHAR(50) NULL, CREATED_TIMESTAMP BIGINT NOT NULL, UPDATED_TIMESTAMP BIGINT NOT NULL, + OPERATION_CODE VARCHAR(50) NOT NULL, + INITIATED_BY VARCHAR(100) NULL, + TYPE VARCHAR(20) NOT NULL, + DEVICE_ID INTEGER DEFAULT NULL, + DEVICE_TYPE VARCHAR(300) NOT NULL, + DEVICE_IDENTIFICATION VARCHAR(300) DEFAULT NULL, + TENANT_ID INTEGER DEFAULT 0, PRIMARY KEY (ID), CONSTRAINT FK_DM_DEVICE_OPERATION_MAPPING_DEVICE FOREIGN KEY (ENROLMENT_ID) REFERENCES DM_ENROLMENT (ID) ON DELETE NO ACTION ON UPDATE NO ACTION, @@ -178,6 +192,8 @@ IF NOT EXISTS (SELECT * FROM SYS.INDEXES WHERE NAME = 'IDX_EN_OP_MAPPING_EN_ID' CREATE INDEX IDX_EN_OP_MAPPING_EN_ID ON DM_ENROLMENT_OP_MAPPING(ENROLMENT_ID); IF NOT EXISTS (SELECT * FROM SYS.INDEXES WHERE NAME = 'IDX_EN_OP_MAPPING_OP_ID' AND OBJECT_ID = OBJECT_ID('DM_ENROLMENT_OP_MAPPING')) CREATE INDEX IDX_EN_OP_MAPPING_OP_ID ON DM_ENROLMENT_OP_MAPPING(OPERATION_ID); +IF NOT EXISTS (SELECT * FROM SYS.INDEXES WHERE NAME = 'IDX_EN_OP_MAPPING_EN_ID_STATUS' AND OBJECT_ID = OBJECT_ID('DM_ENROLMENT_OP_MAPPING')) +CREATE INDEX IDX_EN_OP_MAPPING_EN_ID_STATUS ON DM_ENROLMENT_OP_MAPPING(ENROLMENT_ID, STATUS); IF NOT EXISTS (SELECT * FROM SYS.OBJECTS WHERE OBJECT_ID = OBJECT_ID(N'[DBO].[DM_DEVICE_OPERATION_RESPONSE]') AND TYPE IN (N'U')) CREATE TABLE DM_DEVICE_OPERATION_RESPONSE (