diff --git a/components/certificate-mgt/org.wso2.carbon.certificate.mgt.core/src/main/java/org/wso2/carbon/certificate/mgt/core/dao/impl/OracleCertificateDAOImpl.java b/components/certificate-mgt/org.wso2.carbon.certificate.mgt.core/src/main/java/org/wso2/carbon/certificate/mgt/core/dao/impl/OracleCertificateDAOImpl.java index 69e61138bb..a206162518 100644 --- a/components/certificate-mgt/org.wso2.carbon.certificate.mgt.core/src/main/java/org/wso2/carbon/certificate/mgt/core/dao/impl/OracleCertificateDAOImpl.java +++ b/components/certificate-mgt/org.wso2.carbon.certificate.mgt.core/src/main/java/org/wso2/carbon/certificate/mgt/core/dao/impl/OracleCertificateDAOImpl.java @@ -54,7 +54,7 @@ public class OracleCertificateDAOImpl extends AbstractCertificateDAOImpl { try { Connection conn = this.getConnection(); String sql = "SELECT CERTIFICATE, SERIAL_NUMBER, TENANT_ID, USERNAME FROM " - + "DM_DEVICE_CERTIFICATE WHERE TENANT_ID = ? ORDER BY ID DESC WHERE OFFSET >= ? AND ROWNUM <= ?"; + + "DM_DEVICE_CERTIFICATE WHERE TENANT_ID = ? ORDER BY ID DESC OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); stmt.setInt(2, rowNum); diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/OracleGadgetDataServiceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/OracleGadgetDataServiceDAOImpl.java index 7fdc731b47..b90a9046b0 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/OracleGadgetDataServiceDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/OracleGadgetDataServiceDAOImpl.java @@ -61,11 +61,10 @@ public class OracleGadgetDataServiceDAOImpl extends AbstractGadgetDataServiceDAO int totalRecordsCount = 0; try { con = this.getConnection(); - String sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (SELECT FEATURE_CODE, COUNT(DEVICE_ID) " + - "AS DEVICE_COUNT FROM " + GadgetDataServiceDAOConstants.DatabaseView.DEVICES_VIEW_2 + - " WHERE TENANT_ID = ? GROUP BY FEATURE_CODE ORDER BY DEVICE_COUNT DESC) rs) " + - "WHERE offset >= ? AND ROWNUM <= ?"; - + String sql = "SELECT FEATURE_CODE, COUNT(DEVICE_ID) AS DEVICE_COUNT FROM " + GadgetDataServiceDAOConstants. + DatabaseView.DEVICES_VIEW_2 + + " WHERE TENANT_ID = ? GROUP BY FEATURE_CODE ORDER BY DEVICE_COUNT DESC " + + "OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = con.prepareStatement(sql); stmt.setInt(1, tenantId); stmt.setInt(2, startIndex); @@ -138,11 +137,9 @@ public class OracleGadgetDataServiceDAOImpl extends AbstractGadgetDataServiceDAO advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; } } - sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (SELECT DEVICE_ID, DEVICE_IDENTIFICATION, PLATFORM, " + - "OWNERSHIP, CONNECTIVITY_STATUS FROM " + GadgetDataServiceDAOConstants.DatabaseView.DEVICES_VIEW_1 + - " WHERE TENANT_ID = ? " + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC) rs) " + - "WHERE offset >= ? AND ROWNUM <= ?"; - + sql = "SELECT DEVICE_ID, DEVICE_IDENTIFICATION, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM " + + GadgetDataServiceDAOConstants.DatabaseView.DEVICES_VIEW_1 + " WHERE TENANT_ID = ? " + + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = con.prepareStatement(sql); // [2] appending filter column values, if exist stmt.setInt(1, tenantId); @@ -235,10 +232,9 @@ public class OracleGadgetDataServiceDAOImpl extends AbstractGadgetDataServiceDAO advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; } } - sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (SELECT DEVICE_ID, DEVICE_IDENTIFICATION, PLATFORM, " + - "OWNERSHIP, CONNECTIVITY_STATUS FROM " + GadgetDataServiceDAOConstants.DatabaseView.DEVICES_VIEW_2 + - " WHERE TENANT_ID = ? AND FEATURE_CODE = ? " + advancedSqlFiltering + - "ORDER BY DEVICE_ID ASC) rs) WHERE offset >= ? AND ROWNUM <= ?"; + sql = "SELECT DEVICE_ID, DEVICE_IDENTIFICATION, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM " + + GadgetDataServiceDAOConstants.DatabaseView.DEVICES_VIEW_2 + " WHERE TENANT_ID = ? AND FEATURE_CODE = ? " + + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = con.prepareStatement(sql); // [2] appending filter column values, if exist stmt.setInt(1, tenantId); 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 d070660d7a..a1773f505f 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 @@ -19,6 +19,8 @@ package org.wso2.carbon.device.mgt.core.dao.impl.device; import org.wso2.carbon.device.mgt.common.Device; +import org.wso2.carbon.device.mgt.common.DeviceIdentifier; +import org.wso2.carbon.device.mgt.common.EnrolmentInfo; import org.wso2.carbon.device.mgt.common.PaginationRequest; import org.wso2.carbon.device.mgt.core.dao.DeviceManagementDAOException; import org.wso2.carbon.device.mgt.core.dao.DeviceManagementDAOFactory; @@ -60,12 +62,11 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { boolean isSinceProvided = false; try { conn = this.getConnection(); - String sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (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 "; + + 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 "; //Add the query to filter active devices on timestamp if (since != null) { @@ -109,7 +110,7 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { isStatusProvided = true; } - sql = sql + " ) rs ) WHERE OFFSET >= ? AND ROWNUM <= ?"; + sql = sql + " ORDER BY ENROLMENT_ID OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); @@ -159,13 +160,13 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { List devices = null; try { conn = this.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( 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 " + - "t.NAME = ? AND d.TENANT_ID = ? ) d1 WHERE d1.ID = e.DEVICE_ID AND TENANT_ID = " + - "? ) rs ) WHERE offset >= ? AND ROWNUM <= ?"; + 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 t.NAME = ? " + + "AND d.TENANT_ID = ?) d1 WHERE d1.ID = e.DEVICE_ID AND TENANT_ID = ? ORDER BY ENROLMENT_ID" + + " OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setString(1, request.getDeviceType()); stmt.setInt(2, tenantId); @@ -194,13 +195,12 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { List devices = new ArrayList<>(); try { conn = this.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( SELECT e1.OWNER, e1.OWNERSHIP, e1.ENROLMENT_ID, e1.DEVICE_ID, e1.STATUS, " + - "e1.DATE_OF_LAST_UPDATE, e1.DATE_OF_ENROLMENT, d.DESCRIPTION, d.NAME AS DEVICE_NAME, " + - "d.DEVICE_IDENTIFICATION, t.NAME AS DEVICE_TYPE FROM DM_DEVICE d, (SELECT e.OWNER, e.OWNERSHIP, " + - "e.ID AS ENROLMENT_ID, e.DEVICE_ID, e.STATUS, e.DATE_OF_LAST_UPDATE, " + - "e.DATE_OF_ENROLMENT FROM DM_ENROLMENT e WHERE e.TENANT_ID = ? AND e.OWNER = ? ) e1, " + - "DM_DEVICE_TYPE t WHERE d.ID = e1.DEVICE_ID AND t.ID = d.DEVICE_TYPE_ID ) rs ) WHERE offset >= " + - "? AND ROWNUM <= ?"; + String sql = "SELECT e1.OWNER, e1.OWNERSHIP, e1.ENROLMENT_ID, e1.DEVICE_ID, e1.STATUS, e1.DATE_OF_LAST_UPDATE," + + " e1.DATE_OF_ENROLMENT, d.DESCRIPTION, d.NAME AS DEVICE_NAME, d.DEVICE_IDENTIFICATION, t.NAME " + + "AS DEVICE_TYPE FROM DM_DEVICE d, (SELECT e.OWNER, e.OWNERSHIP, e.ID AS ENROLMENT_ID, " + + "e.DEVICE_ID, e.STATUS, e.DATE_OF_LAST_UPDATE, e.DATE_OF_ENROLMENT FROM DM_ENROLMENT e WHERE " + + "e.TENANT_ID = ? AND e.OWNER = ?) e1, DM_DEVICE_TYPE t WHERE d.ID = e1.DEVICE_ID " + + "AND t.ID = d.DEVICE_TYPE_ID ORDER BY ENROLMENT_ID OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); stmt.setString(2, request.getOwner()); @@ -229,13 +229,13 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { List devices = new ArrayList<>(); try { conn = this.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( 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.NAME, d.DESCRIPTION, t.NAME AS DEVICE_TYPE, " + - "d.DEVICE_IDENTIFICATION FROM DM_DEVICE d, DM_DEVICE_TYPE t WHERE d.DEVICE_TYPE_ID = " + - "t.ID AND d.NAME LIKE ? AND d.TENANT_ID = ? ) d1 WHERE DEVICE_ID = " + - "e.DEVICE_ID AND TENANT_ID = ? ) rs ) WHERE offset >= ? AND ROWNUM <= ?"; + 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.NAME, " + + "d.DESCRIPTION, t.NAME AS DEVICE_TYPE, d.DEVICE_IDENTIFICATION FROM DM_DEVICE d, " + + "DM_DEVICE_TYPE t WHERE d.DEVICE_TYPE_ID = t.ID AND d.NAME LIKE ? AND d.TENANT_ID = ?) d1 " + + "WHERE DEVICE_ID = e.DEVICE_ID AND TENANT_ID = ? ORDER BY ENROLMENT_ID " + + "OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setString(1, request.getDeviceName() + "%"); stmt.setInt(2, tenantId); @@ -265,13 +265,13 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { List devices = new ArrayList<>(); try { conn = this.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( SELECT d.ID AS DEVICE_ID, d.DESCRIPTION, d.NAME AS DEVICE_NAME, " + - "t.NAME AS DEVICE_TYPE, d.DEVICE_IDENTIFICATION, e.OWNER, e.OWNERSHIP, e.STATUS, " + - "e.DATE_OF_LAST_UPDATE, e.DATE_OF_ENROLMENT, e.ID AS ENROLMENT_ID FROM (SELECT e.ID, " + - "e.DEVICE_ID, e.OWNER, e.OWNERSHIP, e.STATUS, e.DATE_OF_ENROLMENT, e.DATE_OF_LAST_UPDATE, " + - "e.ID AS ENROLMENT_ID FROM DM_ENROLMENT e WHERE TENANT_ID = ? AND OWNERSHIP = ?) e, " + - "DM_DEVICE d, DM_DEVICE_TYPE t WHERE DEVICE_ID = e.DEVICE_ID AND d.DEVICE_TYPE_ID = " + - "t.ID AND d.TENANT_ID = ? ) rs ) WHERE offset >= ? AND ROWNUM <= ?"; + String sql = "SELECT d.ID AS DEVICE_ID, d.DESCRIPTION, d.NAME AS DEVICE_NAME, t.NAME AS DEVICE_TYPE, " + + "d.DEVICE_IDENTIFICATION, e.OWNER, e.OWNERSHIP, e.STATUS, e.DATE_OF_LAST_UPDATE, " + + "e.DATE_OF_ENROLMENT, e.ID AS ENROLMENT_ID FROM (SELECT e.ID, e.DEVICE_ID, e.OWNER, e.OWNERSHIP, e.STATUS, " + + "e.DATE_OF_ENROLMENT, e.DATE_OF_LAST_UPDATE, e.ID AS ENROLMENT_ID FROM DM_ENROLMENT e " + + "WHERE TENANT_ID = ? AND OWNERSHIP = ?) e, DM_DEVICE d, DM_DEVICE_TYPE t " + + "WHERE DEVICE_ID = e.DEVICE_ID AND d.DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ? ORDER BY ENROLMENT_ID " + + "OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); stmt.setString(2, request.getOwnership()); @@ -301,13 +301,13 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { List devices = new ArrayList<>(); try { conn = this.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( SELECT d.ID AS DEVICE_ID, d.DESCRIPTION, d.NAME AS DEVICE_NAME, " + - "t.NAME AS DEVICE_TYPE, d.DEVICE_IDENTIFICATION, e.OWNER, e.OWNERSHIP, e.STATUS, " + - "e.DATE_OF_LAST_UPDATE, e.DATE_OF_ENROLMENT, e.ID AS ENROLMENT_ID FROM (SELECT e.ID, " + - "e.DEVICE_ID, e.OWNER, e.OWNERSHIP, e.STATUS, e.DATE_OF_ENROLMENT, e.DATE_OF_LAST_UPDATE, " + - "e.ID AS ENROLMENT_ID FROM DM_ENROLMENT e WHERE TENANT_ID = ? AND STATUS = ?) e, " + - "DM_DEVICE d, DM_DEVICE_TYPE t WHERE DEVICE_ID = e.DEVICE_ID AND d.DEVICE_TYPE_ID = " + - "t.ID AND d.TENANT_ID = ? ) rs ) WHERE offset >= ? AND ROWNUM <= ?"; + String sql = "SELECT d.ID AS DEVICE_ID, d.DESCRIPTION, d.NAME AS DEVICE_NAME, t.NAME AS DEVICE_TYPE, " + + "d.DEVICE_IDENTIFICATION, e.OWNER, e.OWNERSHIP, e.STATUS, e.DATE_OF_LAST_UPDATE, " + + "e.DATE_OF_ENROLMENT, e.ID AS ENROLMENT_ID FROM (SELECT e.ID, e.DEVICE_ID, e.OWNER, e.OWNERSHIP, e.STATUS, " + + "e.DATE_OF_ENROLMENT, e.DATE_OF_LAST_UPDATE, e.ID AS ENROLMENT_ID FROM DM_ENROLMENT e " + + "WHERE TENANT_ID = ? AND STATUS = ?) e, DM_DEVICE d, DM_DEVICE_TYPE t " + + "WHERE DEVICE_ID = e.DEVICE_ID AND d.DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ? ORDER BY ENROLMENT_ID " + + "OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); stmt.setString(2, request.getStatus()); @@ -356,13 +356,12 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { ResultSet rs = null; try { conn = this.getConnection(); - String sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (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.NAME, d.DESCRIPTION, d.DEVICE_IDENTIFICATION, t.NAME AS DEVICE_TYPE FROM " + - "DM_DEVICE d, DM_DEVICE_TYPE t WHERE d.DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ?" + filteringString + - ") d1 WHERE d1.ID = e.DEVICE_ID) rs) WHERE offset >= ? AND ROWNUM <= ?"; - + 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.NAME, " + + "d.DESCRIPTION, d.DEVICE_IDENTIFICATION, t.NAME AS DEVICE_TYPE FROM DM_DEVICE d, " + + "DM_DEVICE_TYPE t WHERE d.DEVICE_TYPE_ID = t.ID AND d.TENANT_ID = ?" + filteringString + + ") d1 WHERE d1.ID = e.DEVICE_ID ORDER BY ENROLMENT_ID OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); @@ -394,6 +393,36 @@ public class OracleDeviceDAOImpl extends AbstractDeviceDAOImpl { return devices; } + public int getEnrolmentByStatus(DeviceIdentifier deviceId, EnrolmentInfo.Status status, + int tenantId) throws DeviceManagementDAOException { + Connection conn; + PreparedStatement stmt = null; + ResultSet rs = null; + try { + conn = this.getConnection(); + String sql = "SELECT e.ID ENROLMENT_ID FROM DM_ENROLMENT e, (SELECT d.ID FROM DM_DEVICE d, DM_DEVICE_TYPE t " + + "WHERE d.DEVICE_TYPE_ID = t.ID AND d.DEVICE_IDENTIFICATION = ? AND t.NAME = ? AND d.TENANT_ID = ?) dtm " + + "WHERE e.DEVICE_ID = dtm.ID AND e.STATUS = ? AND e.TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setString(1, deviceId.getId()); + stmt.setString(2, deviceId.getType()); + stmt.setInt(3, tenantId); + stmt.setString(4, status.toString()); + stmt.setInt(5, tenantId); + rs = stmt.executeQuery(); + if (rs.next()) { + return rs.getInt("ENROLMENT_ID"); + } else { + return -1; // if no results found + } + } catch (SQLException e) { + throw new DeviceManagementDAOException("Error occurred while retrieving the enrolment " + + "id of device '" + deviceId + "'", e); + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + } + private Connection getConnection() throws SQLException { return DeviceManagementDAOFactory.getConnection(); } diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/group/mgt/dao/GroupDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/group/mgt/dao/GroupDAOImpl.java index 1dc62b8046..df70f43502 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/group/mgt/dao/GroupDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/group/mgt/dao/GroupDAOImpl.java @@ -187,7 +187,7 @@ public class GroupDAOImpl implements GroupDAO { try { Connection conn = GroupManagementDAOFactory.getConnection(); String sql = "SELECT G.ID, G.GROUP_NAME, G.DESCRIPTION, G.DATE_OF_CREATE, G.DATE_OF_LAST_UPDATE, \n" + - "G.OWNER FROM DM_GROUP AS G INNER JOIN DM_DEVICE_GROUP_MAP AS GM ON G.ID = GM.GROUP_ID " + + "G.OWNER FROM DM_GROUP G INNER JOIN DM_DEVICE_GROUP_MAP GM ON G.ID = GM.GROUP_ID " + "WHERE GM.DEVICE_ID = ? AND GM.TENANT_ID = ?"; stmt = conn.prepareStatement(sql); stmt.setInt(1, deviceId); diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/notification/mgt/dao/impl/OracleNotificationDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/notification/mgt/dao/impl/OracleNotificationDAOImpl.java index f5ca55ebbd..1ced4b898f 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/notification/mgt/dao/impl/OracleNotificationDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/notification/mgt/dao/impl/OracleNotificationDAOImpl.java @@ -51,7 +51,7 @@ public class OracleNotificationDAOImpl extends AbstractNotificationDAOImpl { "NOTIFICATION_ID, DEVICE_ID, OPERATION_ID, STATUS, DESCRIPTION FROM DM_NOTIFICATION WHERE " + "TENANT_ID = ?) n1 WHERE n1.DEVICE_ID = d.ID AND d.DEVICE_TYPE_ID=t.ID AND TENANT_ID = ?"; - sql = sql + " WHERE OFFSET >= ? AND ROWNUM <= ?"; + sql = sql + " ORDER BY n1.NOTIFICATION_ID OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, tenantId); 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/OracleOperationDAOImpl.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/OracleOperationDAOImpl.java index 0a3bfadad2..f37419422d 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.core/src/main/java/org/wso2/carbon/device/mgt/core/operation/mgt/dao/impl/operation/OracleOperationDAOImpl.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/OracleOperationDAOImpl.java @@ -18,13 +18,20 @@ 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.PaginationRequest; +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.dto.operation.mgt.Operation; 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; @@ -46,10 +53,11 @@ public class OracleOperationDAOImpl extends GenericOperationDAOImpl { List operations = new ArrayList(); try { Connection conn = OperationManagementDAOFactory.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( SELECT o.ID, TYPE, CREATED_TIMESTAMP, RECEIVED_TIMESTAMP, " + - "OPERATION_CODE, om.STATUS FROM DM_OPERATION o INNER JOIN (SELECT * " + - "FROM DM_ENROLMENT_OP_MAPPING dm WHERE dm.ENROLMENT_ID = ?) om ON o.ID = " + - "om.OPERATION_ID ORDER BY o.CREATED_TIMESTAMP DESC ) rs ) WHERE offset >= ? AND ROWNUM <= ?"; + String sql = "SELECT o.ID, TYPE, o.CREATED_TIMESTAMP, o.RECEIVED_TIMESTAMP, " + + "o.OPERATION_CODE, om.STATUS, om.ID AS OM_MAPPING_ID, om.UPDATED_TIMESTAMP FROM DM_OPERATION o " + + "INNER JOIN (SELECT dm.OPERATION_ID, dm.ID, dm.STATUS, dm.UPDATED_TIMESTAMP FROM DM_ENROLMENT_OP_MAPPING dm " + + "WHERE dm.ENROLMENT_ID = ?) om ON o.ID = om.OPERATION_ID ORDER BY o.CREATED_TIMESTAMP DESC " + + "OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, enrolmentId); stmt.setInt(2, request.getStartIndex()); @@ -71,8 +79,9 @@ public class OracleOperationDAOImpl extends GenericOperationDAOImpl { operations.add(operation); } } catch (SQLException e) { - throw new OperationManagementDAOException("SQL error occurred while retrieving the operation " + - "available for the device'" + enrolmentId + "' with status '", e); + throw new OperationManagementDAOException( + "SQL error occurred while retrieving the operation " + "available for the device'" + enrolmentId + + "' with status '", e); } finally { OperationManagementDAOUtil.cleanupResources(stmt, rs); } @@ -80,19 +89,19 @@ public class OracleOperationDAOImpl extends GenericOperationDAOImpl { } @Override - public List getOperationsByDeviceAndStatus(int enrolmentId, PaginationRequest request, - Operation.Status status) - throws OperationManagementDAOException { + public List getOperationsByDeviceAndStatus(int enrolmentId, + PaginationRequest request, Operation.Status status) throws OperationManagementDAOException { PreparedStatement stmt = null; ResultSet rs = null; Operation operation; List operations = new ArrayList(); try { Connection conn = OperationManagementDAOFactory.getConnection(); - String sql = "SELECT * FROM ( SELECT ROWNUM offset, rs.* FROM ( SELECT o.ID, TYPE, CREATED_TIMESTAMP, RECEIVED_TIMESTAMP, " + - "OPERATION_CODE FROM DM_OPERATION o INNER JOIN (SELECT * FROM DM_ENROLMENT_OP_MAPPING dm WHERE " + - "dm.ENROLMENT_ID = ? AND dm.STATUS = ?) om ON o.ID = om.OPERATION_ID ORDER BY o." + - "CREATED_TIMESTAMP DESC ) rs ) WHERE offset >= ? AND ROWNUM <= ?"; + String sql = "SELECT o.ID, TYPE, o.CREATED_TIMESTAMP, o.RECEIVED_TIMESTAMP, o.OPERATION_CODE, " + + "om.ID AS OM_MAPPING_ID, om.UPDATED_TIMESTAMP FROM DM_OPERATION o " + + "INNER JOIN (SELECT dm.OPERATION_ID, dm.ID, dm.STATUS, dm.UPDATED_TIMESTAMP FROM DM_ENROLMENT_OP_MAPPING dm " + + "WHERE dm.ENROLMENT_ID = ? AND dm.STATUS = ?) om ON o.ID = om.OPERATION_ID ORDER BY " + + "o.CREATED_TIMESTAMP DESC OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; stmt = conn.prepareStatement(sql); stmt.setInt(1, enrolmentId); stmt.setString(2, status.toString()); @@ -115,12 +124,241 @@ public class OracleOperationDAOImpl extends GenericOperationDAOImpl { operations.add(operation); } } catch (SQLException e) { - throw new OperationManagementDAOException("SQL error occurred while retrieving the operation " + - "available for the device'" + enrolmentId + "' with status '" - + status.toString(), e); + throw new OperationManagementDAOException( + "SQL error occurred while retrieving the operation " + "available for the device'" + enrolmentId + + "' with status '" + status.toString(), e); } finally { OperationManagementDAOUtil.cleanupResources(stmt, rs); } return operations; } + + @Override + public void updateEnrollmentOperationsStatus(int enrolmentId, String operationCode, + Operation.Status existingStatus, Operation.Status newStatus) throws OperationManagementDAOException { + PreparedStatement stmt = null; + ResultSet rs = null; + try { + Connection connection = OperationManagementDAOFactory.getConnection(); + String query = "SELECT EOM.ID FROM DM_ENROLMENT_OP_MAPPING EOM INNER JOIN DM_OPERATION DM " + + "ON DM.ID = EOM.OPERATION_ID WHERE EOM.ENROLMENT_ID = ? AND DM.OPERATION_CODE = ? " + + "AND EOM.STATUS = ?"; + stmt = connection.prepareStatement(query); + stmt.setInt(1, enrolmentId); + stmt.setString(2, operationCode); + stmt.setString(3, existingStatus.toString()); + // This will return only one result always. + rs = stmt.executeQuery(); + int id = 0; + while (rs.next()) { + id = rs.getInt("ID"); + } + if (id != 0) { + stmt = connection.prepareStatement( + "UPDATE DM_ENROLMENT_OP_MAPPING SET STATUS = ?, " + "UPDATED_TIMESTAMP = ? WHERE ID = ?"); + stmt.setString(1, newStatus.toString()); + stmt.setLong(2, System.currentTimeMillis() / 1000); + stmt.setInt(3, id); + stmt.executeUpdate(); + } + + } catch (SQLException e) { + throw new OperationManagementDAOException( + "Error occurred while update device mapping operation status " + "metadata", e); + } finally { + OperationManagementDAOUtil.cleanupResources(stmt); + } + } + + @Override + public boolean updateTaskOperation(int enrolmentId, String operationCode) throws OperationManagementDAOException { + PreparedStatement stmt = null; + ResultSet rs = null; + boolean result = false; + try { + Connection connection = OperationManagementDAOFactory.getConnection(); + String query = "SELECT EOM.ID FROM DM_ENROLMENT_OP_MAPPING EOM INNER JOIN DM_OPERATION DM " + + "ON DM.ID = EOM.OPERATION_ID WHERE EOM.ENROLMENT_ID = ? AND DM.OPERATION_CODE = ? AND " + + "EOM.STATUS = ?"; + stmt = connection.prepareStatement(query); + stmt.setInt(1, enrolmentId); + stmt.setString(2, operationCode); + stmt.setString(3, Operation.Status.PENDING.toString()); + // This will return only one result always. + rs = stmt.executeQuery(); + int id = 0; + if (rs.next()) { + id = rs.getInt("ID"); + } + if (id != 0) { + stmt = connection.prepareStatement( + "UPDATE DM_ENROLMENT_OP_MAPPING SET UPDATED_TIMESTAMP = ? " + "WHERE ID = ?"); + stmt.setLong(1, System.currentTimeMillis() / 1000); + stmt.setInt(2, id); + stmt.executeUpdate(); + result = true; + } + } catch (SQLException e) { + throw new OperationManagementDAOException( + "Error occurred while update device mapping operation status " + "metadata", e); + } finally { + OperationManagementDAOUtil.cleanupResources(stmt); + } + return result; + } + + @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 opm.ENROLMENT_ID, opm.CREATED_TIMESTAMP, opm.UPDATED_TIMESTAMP, opm.OPERATION_ID,\n" + + "op.OPERATION_CODE, op.TYPE OPERATION_TYPE, opm.STATUS, en.DEVICE_ID,\n" + + "ops.RECEIVED_TIMESTAMP, ops.ID OP_RES_ID, ops.OPERATION_RESPONSE,\n" + + "de.DEVICE_IDENTIFICATION, dt.NAME DEVICE_TYPE\n" + "FROM DM_ENROLMENT_OP_MAPPING opm\n" + + "LEFT JOIN DM_OPERATION op ON opm.OPERATION_ID = op.ID \n" + + "LEFT JOIN DM_ENROLMENT en ON opm.ENROLMENT_ID = en.ID \n" + + "LEFT JOIN DM_DEVICE de ON en.DEVICE_ID = de.ID \n" + + "LEFT JOIN DM_DEVICE_TYPE dt ON dt.ID = de.DEVICE_TYPE_ID \n" + + "LEFT JOIN DM_DEVICE_OPERATION_RESPONSE ops ON \n" + + "opm.ENROLMENT_ID = ops.ENROLMENT_ID AND opm.OPERATION_ID = ops.OPERATION_ID \n" + + "WHERE opm.UPDATED_TIMESTAMP > ? \n" + "AND de.TENANT_ID = ? \n"; + + if (timestamp == 0) { + sql += "ORDER BY opm.OPERATION_ID OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; + } else { + sql += "ORDER BY opm.UPDATED_TIMESTAMP asc OFFSET ? ROWS FETCH NEXT ? ROWS ONLY"; + } + stmt = conn.prepareStatement(sql); + stmt.setLong(1, timestamp); + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + stmt.setInt(2, tenantId); + stmt.setInt(3, offset); + stmt.setInt(4, limit); + + 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; + } + + @Override + public int getActivityCountUpdatedAfter(long timestamp) throws OperationManagementDAOException { + PreparedStatement stmt = null; + ResultSet rs = null; + try { + Connection conn = OperationManagementDAOFactory.getConnection(); + String sql = "SELECT COUNT(*) COUNT FROM DM_ENROLMENT_OP_MAPPING m \n" + + "INNER JOIN DM_ENROLMENT d ON m.ENROLMENT_ID = d.ID \n" + + "WHERE m.UPDATED_TIMESTAMP > ? AND d.TENANT_ID = ?"; + stmt = conn.prepareStatement(sql); + stmt.setLong(1, timestamp); + stmt.setInt(2, PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId()); + rs = stmt.executeQuery(); + if (rs.next()) { + return rs.getInt("COUNT"); + } + } catch (SQLException e) { + throw new OperationManagementDAOException( + "Error occurred while getting the activity count from " + "the database.", e); + } finally { + OperationManagementDAOUtil.cleanupResources(stmt, rs); + } + return 0; + } } \ No newline at end of file diff --git a/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/oracle.sql b/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/oracle.sql index f3883d8c3c..9f5013c47c 100644 --- a/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/oracle.sql +++ b/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/oracle.sql @@ -25,7 +25,7 @@ CREATE TABLE DM_GROUP ( ID NUMBER(10) NOT NULL, DESCRIPTION CLOB DEFAULT NULL, GROUP_NAME VARCHAR2(100) DEFAULT NULL, - DATE_OF_ENROLLMENT TIMESTAMP(0) DEFAULT NULL, + DATE_OF_CREATE TIMESTAMP(0) DEFAULT NULL, DATE_OF_LAST_UPDATE TIMESTAMP(0) DEFAULT NULL, OWNER VARCHAR2(45) DEFAULT NULL, TENANT_ID NUMBER(10) DEFAULT 0,