From cb5736854ad97d263e1599a3d744f48dc8fed4d1 Mon Sep 17 00:00:00 2001 From: Dileesha Rajapakse Date: Tue, 10 May 2016 14:58:02 +0530 Subject: [PATCH 1/4] Fixed issues in Oracle DB script --- .../main/resources/dbscripts/cdm/oracle.sql | 144 +++++++++++------- 1 file changed, 91 insertions(+), 53 deletions(-) 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 ab74524c593..3f6d81226bf 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 @@ -2,7 +2,7 @@ CREATE TABLE DM_DEVICE_TYPE ( ID NUMBER(10) NOT NULL, NAME VARCHAR2(300) DEFAULT NULL, PROVIDER_TENANT_ID INTEGER DEFAULT 0, - SHARED_WITH_ALL_TENANTS BOOLEAN NOT NULL DEFAULT FALSE, + SHARED_WITH_ALL_TENANTS NUMBER(1) DEFAULT 0 NOT NULL, CONSTRAINT PK_DM_DEVICE_TYPE PRIMARY KEY (ID) ) / @@ -20,6 +20,31 @@ WHEN (NEW.ID IS NULL) END; / +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_LAST_UPDATE TIMESTAMP(0) DEFAULT NULL, + OWNER VARCHAR2(45) DEFAULT NULL, + TENANT_ID NUMBER(10) DEFAULT 0, + CONSTRAINT PK_DM_GROUP PRIMARY KEY (ID) +) +/ +-- Generate ID using sequence and trigger +CREATE SEQUENCE DM_GROUP_seq START WITH 1 INCREMENT BY 1 NOCACHE +/ +CREATE OR REPLACE TRIGGER DM_GROUP_seq_tr +BEFORE INSERT +ON DM_GROUP +REFERENCING NEW AS NEW +FOR EACH ROW +WHEN (NEW.ID IS NULL) + BEGIN + SELECT DM_GROUP_seq.NEXTVAL INTO :NEW.ID FROM DUAL; + END; +/ + CREATE TABLE DM_DEVICE_CERTIFICATE ( ID NUMBER(10) NOT NULL, SERIAL_NUMBER VARCHAR2(500) DEFAULT NULL, @@ -65,6 +90,29 @@ WHEN (NEW.ID IS NULL) END; / +CREATE TABLE DM_DEVICE_GROUP_MAP ( + ID NUMBER(10) NOT NULL, + DEVICE_ID NUMBER(10) DEFAULT NULL, + GROUP_ID NUMBER(10) DEFAULT NULL, + TENANT_ID NUMBER(10) DEFAULT 0, + PRIMARY KEY (ID), + CONSTRAINT fk_DM_DEV_GROUP_MAP_DM_DEV2 FOREIGN KEY (DEVICE_ID) + REFERENCES DM_DEVICE (ID), + CONSTRAINT fk_DM_DEV_GROUP_MAP_DM_GROUP2 FOREIGN KEY (GROUP_ID) + REFERENCES DM_GROUP (ID) +); + +-- Generate ID using sequence and trigger +CREATE SEQUENCE DM_DEVICE_GROUP_MAP_seq START WITH 1 INCREMENT BY 1; + +CREATE OR REPLACE TRIGGER DM_DEVICE_GROUP_MAP_seq_tr +BEFORE INSERT ON DM_DEVICE_GROUP_MAP FOR EACH ROW +WHEN (NEW.ID IS NULL) + BEGIN + SELECT DM_DEVICE_GROUP_MAP_seq.NEXTVAL INTO :NEW.ID FROM DUAL; + END; +/ + CREATE TABLE DM_OPERATION ( ID NUMBER(10) NOT NULL, TYPE VARCHAR2(50) NOT NULL, @@ -576,23 +624,23 @@ CREATE TABLE DM_DEVICE_GROUP_POLICY ( TENANT_ID NUMBER(10) NOT NULL, PRIMARY KEY (ID), CONSTRAINT FK_DM_DEVICE_GROUP_POLICY - FOREIGN KEY (DEVICE_GROUP_ID) - REFERENCES DM_GROUP (ID) - , + FOREIGN KEY (DEVICE_GROUP_ID) + REFERENCES DM_GROUP (ID) + , CONSTRAINT FK_DM_DEVICE_GROUP_DM_POLICY - FOREIGN KEY (POLICY_ID) - REFERENCES DM_POLICY (ID) + FOREIGN KEY (POLICY_ID) + REFERENCES DM_POLICY (ID) ) ; -- Generate ID using sequence and trigger CREATE SEQUENCE DM_DEVICE_GROUP_POLICY_seq START WITH 1 INCREMENT BY 1; CREATE OR REPLACE TRIGGER DM_DEVICE_GROUP_POLICY_seq_tr - BEFORE INSERT ON DM_DEVICE_GROUP_POLICY FOR EACH ROW - WHEN (NEW.ID IS NULL) -BEGIN - SELECT DM_DEVICE_GROUP_POLICY_seq.NEXTVAL INTO :NEW.ID FROM DUAL; -END; +BEFORE INSERT ON DM_DEVICE_GROUP_POLICY FOR EACH ROW +WHEN (NEW.ID IS NULL) + BEGIN + SELECT DM_DEVICE_GROUP_POLICY_seq.NEXTVAL INTO :NEW.ID FROM DUAL; + END; / @@ -690,9 +738,9 @@ WHEN (NEW.NOTIFICATION_ID IS NULL) -- Device Info and Search Table -- BEGIN - EXECUTE IMMEDIATE 'DROP TABLE DM_DEVICE_INFO'; -EXCEPTION - WHEN OTHERS THEN NULL; + EXECUTE IMMEDIATE 'DROP TABLE DM_DEVICE_INFO'; + EXCEPTION + WHEN OTHERS THEN NULL; END; / @@ -702,10 +750,10 @@ CREATE TABLE DM_DEVICE_INFO ( KEY_FIELD VARCHAR2(45) NULL, VALUE_FIELD VARCHAR2(100) NULL, PRIMARY KEY (ID) - , + , CONSTRAINT DM_DEVICE_INFO_DEVICE - FOREIGN KEY (DEVICE_ID) - REFERENCES DM_DEVICE (ID) + FOREIGN KEY (DEVICE_ID) + REFERENCES DM_DEVICE (ID) ) ; @@ -713,21 +761,17 @@ CREATE TABLE DM_DEVICE_INFO ( CREATE SEQUENCE DM_DEVICE_INFO_seq START WITH 1 INCREMENT BY 1; CREATE OR REPLACE TRIGGER DM_DEVICE_INFO_seq_tr - BEFORE INSERT ON DM_DEVICE_INFO FOR EACH ROW - WHEN (NEW.ID IS NULL) -BEGIN - SELECT DM_DEVICE_INFO_seq.NEXTVAL INTO :NEW.ID FROM DUAL; -END; +BEFORE INSERT ON DM_DEVICE_INFO FOR EACH ROW +WHEN (NEW.ID IS NULL) + BEGIN + SELECT DM_DEVICE_INFO_seq.NEXTVAL INTO :NEW.ID FROM DUAL; + END; / -CREATE INDEX DM_DEVICE_INFO_DEVICE_idx ON DM_DEVICE_INFO (DEVICE_ID ASC); - - - BEGIN - EXECUTE IMMEDIATE 'DROP TABLE DM_DEVICE_LOCATION'; -EXCEPTION - WHEN OTHERS THEN NULL; + EXECUTE IMMEDIATE 'DROP TABLE DM_DEVICE_LOCATION'; + EXCEPTION + WHEN OTHERS THEN NULL; END; / @@ -744,10 +788,10 @@ CREATE TABLE DM_DEVICE_LOCATION ( COUNTRY VARCHAR2(45) NULL, UPDATE_TIMESTAMP NUMBER(19) NOT NULL, PRIMARY KEY (ID) - , + , CONSTRAINT DM_DEVICE_LOCATION_DEVICE - FOREIGN KEY (DEVICE_ID) - REFERENCES DM_DEVICE (ID) + FOREIGN KEY (DEVICE_ID) + REFERENCES DM_DEVICE (ID) ) ; @@ -755,21 +799,17 @@ CREATE TABLE DM_DEVICE_LOCATION ( CREATE SEQUENCE DM_DEVICE_LOCATION_seq START WITH 1 INCREMENT BY 1; CREATE OR REPLACE TRIGGER DM_DEVICE_LOCATION_seq_tr - BEFORE INSERT ON DM_DEVICE_LOCATION FOR EACH ROW - WHEN (NEW.ID IS NULL) -BEGIN - SELECT DM_DEVICE_LOCATION_seq.NEXTVAL INTO :NEW.ID FROM DUAL; -END; +BEFORE INSERT ON DM_DEVICE_LOCATION FOR EACH ROW +WHEN (NEW.ID IS NULL) + BEGIN + SELECT DM_DEVICE_LOCATION_seq.NEXTVAL INTO :NEW.ID FROM DUAL; + END; / -CREATE INDEX DM_DEVICE_LOCATION_DEVICE_idx ON DM_DEVICE_LOCATION (DEVICE_ID ASC); - - - BEGIN - EXECUTE IMMEDIATE 'DROP TABLE DM_DEVICE_DETAIL'; -EXCEPTION - WHEN OTHERS THEN NULL; + EXECUTE IMMEDIATE 'DROP TABLE DM_DEVICE_DETAIL'; + EXCEPTION + WHEN OTHERS THEN NULL; END; / @@ -793,20 +833,18 @@ CREATE TABLE DM_DEVICE_DETAIL ( UPDATE_TIMESTAMP NUMBER(19) NOT NULL, PRIMARY KEY (ID), CONSTRAINT FK_DM_DEVICE_DETAILS_DEVICE - FOREIGN KEY (DEVICE_ID) - REFERENCES DM_DEVICE (ID) + FOREIGN KEY (DEVICE_ID) + REFERENCES DM_DEVICE (ID) ); -- Generate ID using sequence and trigger CREATE SEQUENCE DM_DEVICE_DETAIL_seq START WITH 1 INCREMENT BY 1; CREATE OR REPLACE TRIGGER DM_DEVICE_DETAIL_seq_tr - BEFORE INSERT ON DM_DEVICE_DETAIL FOR EACH ROW - WHEN (NEW.ID IS NULL) -BEGIN - SELECT DM_DEVICE_DETAIL_seq.NEXTVAL INTO :NEW.ID FROM DUAL; -END; +BEFORE INSERT ON DM_DEVICE_DETAIL FOR EACH ROW +WHEN (NEW.ID IS NULL) + BEGIN + SELECT DM_DEVICE_DETAIL_seq.NEXTVAL INTO :NEW.ID FROM DUAL; + END; / -CREATE INDEX FK_DM_DEVICE_DETAILS_DEVICE_idx ON DM_DEVICE_DETAIL (DEVICE_ID ASC); - From adec59e9340b85a014a789c742c5905241b250b6 Mon Sep 17 00:00:00 2001 From: dilanua Date: Tue, 10 May 2016 15:26:20 +0530 Subject: [PATCH 2/4] Adding inter-mediate postgre-sql and oracle support to dashboard analytics feature --- .../dao/impl/GadgetDataServiceDAOImpl.java | 1 + .../main/resources/dbscripts/cdm/oracle.sql | 55 +++++++++++++++++++ .../resources/dbscripts/cdm/postgresql.sql | 55 +++++++++++++++++++ 3 files changed, 111 insertions(+) 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/GadgetDataServiceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOImpl.java index d13bf8c1d7a..f6db11bc51b 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOImpl.java @@ -56,6 +56,7 @@ public class GadgetDataServiceDAOImpl implements GadgetDataServiceDAO { return deviceCountByGroupEntry; } + @Override public DeviceCountByGroupEntry getDeviceCount(FilterSet filterSet) throws InvalidParameterValueException, SQLException { 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 3f6d81226bf..c4a2fd0267c 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 @@ -848,3 +848,58 @@ WHEN (NEW.ID IS NULL) END; / +-- DASHBOARD RELATED VIEWS -- + +CREATE VIEW DEVICES_VIEW_1 AS +SELECT +DEVICE_INFO.DEVICE_ID, +DEVICE_INFO.PLATFORM, +DEVICE_INFO.OWNERSHIP, +DEVICE_INFO.CONNECTIVITY_STATUS, +NVL(DEVICE_WITH_POLICY_INFO.POLICY_ID, -1) AS POLICY_ID, +NVL(DEVICE_WITH_POLICY_INFO.IS_COMPLIANT, -1) AS IS_COMPLIANT, +DEVICE_INFO.TENANT_ID +FROM +(SELECT +DM_DEVICE.ID AS DEVICE_ID, +DM_DEVICE_TYPE.NAME AS PLATFORM, +DM_ENROLMENT.OWNERSHIP, +DM_ENROLMENT.STATUS AS CONNECTIVITY_STATUS, +DM_DEVICE.TENANT_ID +FROM DM_DEVICE, DM_DEVICE_TYPE, DM_ENROLMENT +WHERE DM_DEVICE.DEVICE_TYPE_ID = DM_DEVICE_TYPE.ID AND DM_DEVICE.ID = DM_ENROLMENT.DEVICE_ID) DEVICE_INFO +LEFT JOIN +(SELECT +DEVICE_ID, +POLICY_ID, +STATUS AS IS_COMPLIANT +FROM DM_POLICY_COMPLIANCE_STATUS) DEVICE_WITH_POLICY_INFO +ON DEVICE_INFO.DEVICE_ID = DEVICE_WITH_POLICY_INFO.DEVICE_ID +ORDER BY DEVICE_INFO.DEVICE_ID; + +CREATE VIEW DEVICES_VIEW_2 AS +SELECT +DM_DEVICE.ID AS DEVICE_ID, +DM_DEVICE_DETAIL.DEVICE_MODEL, +DM_DEVICE_DETAIL.VENDOR, +DM_DEVICE_DETAIL.OS_VERSION, +DM_ENROLMENT.OWNERSHIP, +DM_ENROLMENT.OWNER, +DM_ENROLMENT.STATUS AS CONNECTIVITY_STATUS, +DM_POLICY_COMPLIANCE_STATUS.POLICY_ID, +DM_DEVICE_TYPE.NAME AS PLATFORM, +DM_POLICY_COMPLIANCE_FEATURES.FEATURE_CODE, +DM_POLICY_COMPLIANCE_FEATURES.STATUS AS IS_COMPLAINT, +DM_DEVICE.TENANT_ID +FROM +DM_POLICY_COMPLIANCE_FEATURES, DM_POLICY_COMPLIANCE_STATUS, DM_ENROLMENT, DM_DEVICE, DM_DEVICE_TYPE, DM_DEVICE_DETAIL +WHERE +DM_POLICY_COMPLIANCE_FEATURES.COMPLIANCE_STATUS_ID = DM_POLICY_COMPLIANCE_STATUS.ID AND +DM_POLICY_COMPLIANCE_STATUS.ENROLMENT_ID = DM_ENROLMENT.ID AND +DM_POLICY_COMPLIANCE_STATUS.DEVICE_ID = DM_DEVICE.ID AND +DM_DEVICE.DEVICE_TYPE_ID = DM_DEVICE_TYPE.ID AND +DM_DEVICE.ID = DM_DEVICE_DETAIL.DEVICE_ID +ORDER BY TENANT_ID, DEVICE_ID; + +-- END OF DASHBOARD RELATED VIEWS -- + diff --git a/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/postgresql.sql b/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/postgresql.sql index 3f5b7965b89..7e8c8a3e0c0 100644 --- a/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/postgresql.sql +++ b/features/device-mgt/org.wso2.carbon.device.mgt.server.feature/src/main/resources/dbscripts/cdm/postgresql.sql @@ -429,3 +429,58 @@ CREATE TABLE IF NOT EXISTS DM_DEVICE_DETAIL ( ON UPDATE NO ACTION ); +-- DASHBOARD RELATED VIEWS -- + +CREATE VIEW DEVICES_VIEW_1 AS +SELECT +DEVICE_INFO.DEVICE_ID, +DEVICE_INFO.PLATFORM, +DEVICE_INFO.OWNERSHIP, +DEVICE_INFO.CONNECTIVITY_STATUS, +COALESCE(DEVICE_WITH_POLICY_INFO.POLICY_ID, -1) AS POLICY_ID, +COALESCE(DEVICE_WITH_POLICY_INFO.IS_COMPLIANT, -1) AS IS_COMPLIANT, +DEVICE_INFO.TENANT_ID +FROM +(SELECT +DM_DEVICE.ID AS DEVICE_ID, +DM_DEVICE_TYPE.NAME AS PLATFORM, +DM_ENROLMENT.OWNERSHIP, +DM_ENROLMENT.STATUS AS CONNECTIVITY_STATUS, +DM_DEVICE.TENANT_ID +FROM DM_DEVICE, DM_DEVICE_TYPE, DM_ENROLMENT +WHERE DM_DEVICE.DEVICE_TYPE_ID = DM_DEVICE_TYPE.ID AND DM_DEVICE.ID = DM_ENROLMENT.DEVICE_ID) DEVICE_INFO +LEFT JOIN +(SELECT +DEVICE_ID, +POLICY_ID, +STATUS AS IS_COMPLIANT +FROM DM_POLICY_COMPLIANCE_STATUS) DEVICE_WITH_POLICY_INFO +ON DEVICE_INFO.DEVICE_ID = DEVICE_WITH_POLICY_INFO.DEVICE_ID +ORDER BY DEVICE_INFO.DEVICE_ID; + +CREATE VIEW DEVICES_VIEW_2 AS +SELECT +DM_DEVICE.ID AS DEVICE_ID, +DM_DEVICE_DETAIL.DEVICE_MODEL, +DM_DEVICE_DETAIL.VENDOR, +DM_DEVICE_DETAIL.OS_VERSION, +DM_ENROLMENT.OWNERSHIP, +DM_ENROLMENT.OWNER, +DM_ENROLMENT.STATUS AS CONNECTIVITY_STATUS, +DM_POLICY_COMPLIANCE_STATUS.POLICY_ID, +DM_DEVICE_TYPE.NAME AS PLATFORM, +DM_POLICY_COMPLIANCE_FEATURES.FEATURE_CODE, +DM_POLICY_COMPLIANCE_FEATURES.STATUS AS IS_COMPLAINT, +DM_DEVICE.TENANT_ID +FROM +DM_POLICY_COMPLIANCE_FEATURES, DM_POLICY_COMPLIANCE_STATUS, DM_ENROLMENT, DM_DEVICE, DM_DEVICE_TYPE, DM_DEVICE_DETAIL +WHERE +DM_POLICY_COMPLIANCE_FEATURES.COMPLIANCE_STATUS_ID = DM_POLICY_COMPLIANCE_STATUS.ID AND +DM_POLICY_COMPLIANCE_STATUS.ENROLMENT_ID = DM_ENROLMENT.ID AND +DM_POLICY_COMPLIANCE_STATUS.DEVICE_ID = DM_DEVICE.ID AND +DM_DEVICE.DEVICE_TYPE_ID = DM_DEVICE_TYPE.ID AND +DM_DEVICE.ID = DM_DEVICE_DETAIL.DEVICE_ID +ORDER BY TENANT_ID, DEVICE_ID; + +-- END OF DASHBOARD RELATED VIEWS -- + From 0534cd0a7edbeeb37b55f56f6126d1c484d09369 Mon Sep 17 00:00:00 2001 From: dilanua Date: Tue, 10 May 2016 18:52:44 +0530 Subject: [PATCH 3/4] Adding h2, mysql, postgre-sql and oracle support to dashboard analytics feature --- ...java => AbstractGadgetDataServiceDAO.java} | 249 +----------------- .../GadgetDataServiceDAOConstants.java | 4 +- .../dao/GadgetDataServiceDAOFactory.java | 24 +- .../core/dao/DeviceManagementDAOFactory.java | 4 +- 4 files changed, 30 insertions(+), 251 deletions(-) rename components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/{impl/GadgetDataServiceDAOImpl.java => AbstractGadgetDataServiceDAO.java} (71%) rename components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/{impl => }/GadgetDataServiceDAOConstants.java (87%) 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/GadgetDataServiceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/AbstractGadgetDataServiceDAO.java similarity index 71% rename from components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOImpl.java rename to components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/AbstractGadgetDataServiceDAO.java index f6db11bc51b..bfc8af3f621 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOImpl.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/AbstractGadgetDataServiceDAO.java @@ -16,16 +16,13 @@ * under the License. */ -package org.wso2.carbon.device.mgt.analytics.dashboard.dao.impl; +package org.wso2.carbon.device.mgt.analytics.dashboard.dao; import org.wso2.carbon.context.PrivilegedCarbonContext; -import org.wso2.carbon.device.mgt.analytics.dashboard.dao.GadgetDataServiceDAO; -import org.wso2.carbon.device.mgt.analytics.dashboard.dao.GadgetDataServiceDAOFactory; import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DetailedDeviceEntry; import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DeviceCountByGroupEntry; import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.FilterSet; import org.wso2.carbon.device.mgt.analytics.dashboard.dao.exception.InvalidParameterValueException; -import org.wso2.carbon.device.mgt.common.PaginationResult; import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; import java.sql.Connection; @@ -37,7 +34,7 @@ import java.util.LinkedHashMap; import java.util.List; import java.util.Map; -public class GadgetDataServiceDAOImpl implements GadgetDataServiceDAO { +public abstract class AbstractGadgetDataServiceDAO implements GadgetDataServiceDAO { @Override public DeviceCountByGroupEntry getTotalDeviceCount() throws SQLException { @@ -246,66 +243,6 @@ public class GadgetDataServiceDAOImpl implements GadgetDataServiceDAO { } } - @Override - public PaginationResult getNonCompliantDeviceCountsByFeatures(int startIndex, int resultCount) - throws InvalidParameterValueException, SQLException { - - if (startIndex < 0) { - throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); - } - - if (resultCount < 5) { - throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); - } - - Connection con; - PreparedStatement stmt = null; - ResultSet rs = null; - int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); - List filteredNonCompliantDeviceCountsByFeatures = new ArrayList<>(); - int totalRecordsCount = 0; - try { - con = this.getConnection(); - String sql = "SELECT FEATURE_CODE, COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + - "WHERE TENANT_ID = ? GROUP BY FEATURE_CODE ORDER BY DEVICE_COUNT DESC LIMIT ?, ?"; - stmt = con.prepareStatement(sql); - stmt.setInt(1, tenantId); - stmt.setInt(2, startIndex); - stmt.setInt(3, resultCount); - - // executing query - rs = stmt.executeQuery(); - // fetching query results - DeviceCountByGroupEntry filteredNonCompliantDeviceCountByFeature; - while (rs.next()) { - filteredNonCompliantDeviceCountByFeature = new DeviceCountByGroupEntry(); - filteredNonCompliantDeviceCountByFeature.setGroup(rs.getString("FEATURE_CODE")); - filteredNonCompliantDeviceCountByFeature.setDisplayNameForGroup(rs.getString("FEATURE_CODE")); - filteredNonCompliantDeviceCountByFeature.setDeviceCount(rs.getInt("DEVICE_COUNT")); - filteredNonCompliantDeviceCountsByFeatures.add(filteredNonCompliantDeviceCountByFeature); - } - // fetching total records count - sql = "SELECT COUNT(FEATURE_CODE) AS NON_COMPLIANT_FEATURE_COUNT FROM " + - "(SELECT DISTINCT FEATURE_CODE FROM DEVICES_VIEW_2 WHERE TENANT_ID = ?) NON_COMPLIANT_FEATURE_CODE"; - - stmt = con.prepareStatement(sql); - stmt.setInt(1, tenantId); - - // executing query - rs = stmt.executeQuery(); - // fetching query results - while (rs.next()) { - totalRecordsCount = rs.getInt("NON_COMPLIANT_FEATURE_COUNT"); - } - } finally { - DeviceManagementDAOUtil.cleanupResources(stmt, rs); - } - PaginationResult paginationResult = new PaginationResult(); - paginationResult.setData(filteredNonCompliantDeviceCountsByFeatures); - paginationResult.setRecordsTotal(totalRecordsCount); - return paginationResult; - } - @Override public List getDeviceCountsByPlatforms(FilterSet filterSet) throws InvalidParameterValueException, SQLException { @@ -533,184 +470,6 @@ public class GadgetDataServiceDAOImpl implements GadgetDataServiceDAO { return filteredDeviceCountsByOwnershipTypes; } - @Override - public PaginationResult getDevicesWithDetails(FilterSet filterSet, int startIndex, int resultCount) - throws InvalidParameterValueException, SQLException { - - if (startIndex < 0) { - throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); - } - - if (resultCount < 5) { - throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); - } - - Map filters = this.extractDatabaseFiltersFromBean(filterSet); - - Connection con; - PreparedStatement stmt = null; - ResultSet rs = null; - int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); - List filteredDevicesWithDetails = new ArrayList<>(); - int totalRecordsCount = 0; - try { - con = this.getConnection(); - String sql, advancedSqlFiltering = ""; - // appending filters if exist, to support advanced filtering options - // [1] appending filter columns, if exist - if (filters != null && filters.size() > 0) { - for (String column : filters.keySet()) { - advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; - } - } - sql = "SELECT DEVICE_ID, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM DEVICES_VIEW_1 " + - "WHERE TENANT_ID = ? " + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC LIMIT ?, ?"; - stmt = con.prepareStatement(sql); - // [2] appending filter column values, if exist - stmt.setInt(1, tenantId); - if (filters != null && filters.values().size() > 0) { - int i = 2; - for (Object value : filters.values()) { - if (value instanceof Integer) { - stmt.setInt(i, (Integer) value); - } else if (value instanceof String) { - stmt.setString(i, (String) value); - } - i++; - } - stmt.setInt(i, startIndex); - stmt.setInt(++i, resultCount); - } else { - stmt.setInt(2, startIndex); - stmt.setInt(3, resultCount); - } - // executing query - rs = stmt.executeQuery(); - // fetching query results - DetailedDeviceEntry filteredDeviceWithDetails; - while (rs.next()) { - filteredDeviceWithDetails = new DetailedDeviceEntry(); - filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); - filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); - filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); - filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); - filteredDevicesWithDetails.add(filteredDeviceWithDetails); - } - - // fetching total records count - sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_1 WHERE TENANT_ID = ?"; - - stmt = con.prepareStatement(sql); - stmt.setInt(1, tenantId); - - // executing query - rs = stmt.executeQuery(); - // fetching query results - while (rs.next()) { - totalRecordsCount = rs.getInt("DEVICE_COUNT"); - } - } finally { - DeviceManagementDAOUtil.cleanupResources(stmt, rs); - } - PaginationResult paginationResult = new PaginationResult(); - paginationResult.setData(filteredDevicesWithDetails); - paginationResult.setRecordsTotal(totalRecordsCount); - return paginationResult; - } - - @Override - public PaginationResult getFeatureNonCompliantDevicesWithDetails(String nonCompliantFeatureCode, - FilterSet filterSet, int startIndex, int resultCount) - throws InvalidParameterValueException, SQLException { - - if (nonCompliantFeatureCode == null || "".equals(nonCompliantFeatureCode)) { - throw new InvalidParameterValueException("Non-compliant feature code should not be either null or empty."); - } - - if (startIndex < 0) { - throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); - } - - if (resultCount < 5) { - throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); - } - - Map filters = this.extractDatabaseFiltersFromBean(filterSet); - - Connection con; - PreparedStatement stmt = null; - ResultSet rs = null; - int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); - List filteredDevicesWithDetails = new ArrayList<>(); - int totalRecordsCount = 0; - try { - con = this.getConnection(); - String sql, advancedSqlFiltering = ""; - // appending filters if exist, to support advanced filtering options - // [1] appending filter columns, if exist - if (filters != null && filters.size() > 0) { - for (String column : filters.keySet()) { - advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; - } - } - sql = "SELECT DEVICE_ID, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM DEVICES_VIEW_2 " + - "WHERE TENANT_ID = ? AND FEATURE_CODE = ? " + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC LIMIT ?, ?"; - stmt = con.prepareStatement(sql); - // [2] appending filter column values, if exist - stmt.setInt(1, tenantId); - stmt.setString(2, nonCompliantFeatureCode); - if (filters != null && filters.values().size() > 0) { - int i = 3; - for (Object value : filters.values()) { - if (value instanceof Integer) { - stmt.setInt(i, (Integer) value); - } else if (value instanceof String) { - stmt.setString(i, (String) value); - } - i++; - } - stmt.setInt(i, startIndex); - stmt.setInt(++i, resultCount); - } else { - stmt.setInt(3, startIndex); - stmt.setInt(4, resultCount); - } - // executing query - rs = stmt.executeQuery(); - // fetching query results - DetailedDeviceEntry filteredDeviceWithDetails; - while (rs.next()) { - filteredDeviceWithDetails = new DetailedDeviceEntry(); - filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); - filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); - filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); - filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); - filteredDevicesWithDetails.add(filteredDeviceWithDetails); - } - - // fetching total records count - sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + - "WHERE TENANT_ID = ? AND FEATURE_CODE = ?"; - - stmt = con.prepareStatement(sql); - stmt.setInt(1, tenantId); - stmt.setString(2, nonCompliantFeatureCode); - - // executing query - rs = stmt.executeQuery(); - // fetching query results - while (rs.next()) { - totalRecordsCount = rs.getInt("DEVICE_COUNT"); - } - } finally { - DeviceManagementDAOUtil.cleanupResources(stmt, rs); - } - PaginationResult paginationResult = new PaginationResult(); - paginationResult.setData(filteredDevicesWithDetails); - paginationResult.setRecordsTotal(totalRecordsCount); - return paginationResult; - } - @Override public List getDevicesWithDetails(FilterSet filterSet) throws InvalidParameterValueException, SQLException { @@ -825,7 +584,7 @@ public class GadgetDataServiceDAOImpl implements GadgetDataServiceDAO { return filteredDevicesWithDetails; } - private Map extractDatabaseFiltersFromBean(FilterSet filterSet) + protected Map extractDatabaseFiltersFromBean(FilterSet filterSet) throws InvalidParameterValueException { if (filterSet == null) { return null; @@ -868,7 +627,7 @@ public class GadgetDataServiceDAOImpl implements GadgetDataServiceDAO { return filters; } - private Connection getConnection() throws SQLException { + protected Connection getConnection() throws SQLException { return GadgetDataServiceDAOFactory.getConnection(); } 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/GadgetDataServiceDAOConstants.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOConstants.java similarity index 87% rename from components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOConstants.java rename to components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOConstants.java index 9caad2f3a83..82ca1b95944 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GadgetDataServiceDAOConstants.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOConstants.java @@ -16,14 +16,14 @@ * under the License. */ -package org.wso2.carbon.device.mgt.analytics.dashboard.dao.impl; +package org.wso2.carbon.device.mgt.analytics.dashboard.dao; public final class GadgetDataServiceDAOConstants { public static class PotentialVulnerability { // These constants do not hold actual database values - // These are just logical values defined and used @ Gadget Data Service DAO Implementation layer + // These are just abstract values defined and used @ Gadget Data Service DAO Implementation layer public static final String NON_COMPLIANT = "NON_COMPLIANT"; public static final String UNMONITORED = "UNMONITORED"; diff --git a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOFactory.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOFactory.java index c5a6097f3fa..5ee595424ff 100644 --- a/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOFactory.java +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/GadgetDataServiceDAOFactory.java @@ -20,8 +20,12 @@ package org.wso2.carbon.device.mgt.analytics.dashboard.dao; import org.apache.commons.logging.Log; import org.apache.commons.logging.LogFactory; -import org.wso2.carbon.device.mgt.analytics.dashboard.dao.impl.GadgetDataServiceDAOImpl; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.impl.GenericGadgetDataServiceDAOImpl; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.impl.OracleGadgetDataServiceDAOImpl; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.impl.PostgreSQLGadgetDataServiceDAOImpl; +import org.wso2.carbon.device.mgt.common.DeviceManagementConstants; import org.wso2.carbon.device.mgt.common.IllegalTransactionStateException; +import org.wso2.carbon.device.mgt.common.UnsupportedDatabaseEngineException; 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; @@ -41,7 +45,23 @@ public class GadgetDataServiceDAOFactory { private static ThreadLocal currentConnection = new ThreadLocal<>(); public static GadgetDataServiceDAO getGadgetDataServiceDAO() { - return new GadgetDataServiceDAOImpl(); + if (databaseEngine != null) { + switch (databaseEngine) { + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_H2: + return new GenericGadgetDataServiceDAOImpl(); + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_MYSQL: + return new GenericGadgetDataServiceDAOImpl(); + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_MSSQL: + // to be added + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_POSTGRESQL: + return new PostgreSQLGadgetDataServiceDAOImpl(); + case DeviceManagementConstants.DataBaseTypes.DB_TYPE_ORACLE: + return new OracleGadgetDataServiceDAOImpl(); + default: + throw new UnsupportedDatabaseEngineException("Unsupported database engine : " + databaseEngine); + } + } + throw new IllegalStateException("Database engine has not initialized properly."); } public static void init(DataSourceConfig config) { 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 4f983591049..9ec776d2ef2 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 @@ -97,7 +97,7 @@ public class DeviceManagementDAOFactory { private static ThreadLocal currentConnection = new ThreadLocal(); public static DeviceDAO getDeviceDAO() { - if(databaseEngine != null) { + if (databaseEngine != null) { switch (databaseEngine) { case DeviceManagementConstants.DataBaseTypes.DB_TYPE_ORACLE: return new OracleDeviceDAOImpl(); @@ -112,7 +112,7 @@ public class DeviceManagementDAOFactory { throw new UnsupportedDatabaseEngineException("Unsupported database engine : " + databaseEngine); } } - throw new RuntimeException("Database engine has not initialized properly."); + throw new IllegalStateException("Database engine has not initialized properly."); } public static DeviceTypeDAO getDeviceTypeDAO() { From 4cabe359a0f2e6a4e677d9ad50e0e8a7f137acd8 Mon Sep 17 00:00:00 2001 From: dilanua Date: Tue, 10 May 2016 18:53:41 +0530 Subject: [PATCH 4/4] Adding h2, mysql, postgre-sql and oracle support to dashboard analytics feature --- .../impl/GenericGadgetDataServiceDAOImpl.java | 279 +++++++++++++++++ .../impl/OracleGadgetDataServiceDAOImpl.java | 281 ++++++++++++++++++ .../PostgreSQLGadgetDataServiceDAOImpl.java | 279 +++++++++++++++++ 3 files changed, 839 insertions(+) create mode 100644 components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GenericGadgetDataServiceDAOImpl.java create mode 100644 components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/OracleGadgetDataServiceDAOImpl.java create mode 100644 components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/PostgreSQLGadgetDataServiceDAOImpl.java 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/GenericGadgetDataServiceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GenericGadgetDataServiceDAOImpl.java new file mode 100644 index 00000000000..caa6f9bb252 --- /dev/null +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/GenericGadgetDataServiceDAOImpl.java @@ -0,0 +1,279 @@ +/* + * Copyright (c) 2016, 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.analytics.dashboard.dao.impl; + +import org.wso2.carbon.context.PrivilegedCarbonContext; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.AbstractGadgetDataServiceDAO; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DetailedDeviceEntry; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DeviceCountByGroupEntry; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.FilterSet; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.exception.InvalidParameterValueException; +import org.wso2.carbon.device.mgt.common.PaginationResult; +import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; + +import java.sql.Connection; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.util.ArrayList; +import java.util.List; +import java.util.Map; + +public class GenericGadgetDataServiceDAOImpl extends AbstractGadgetDataServiceDAO { + + @Override + public PaginationResult getNonCompliantDeviceCountsByFeatures(int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredNonCompliantDeviceCountsByFeatures = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql = "SELECT FEATURE_CODE, COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? GROUP BY FEATURE_CODE ORDER BY DEVICE_COUNT DESC LIMIT ?, ?"; + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + stmt.setInt(2, startIndex); + stmt.setInt(3, resultCount); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + DeviceCountByGroupEntry filteredNonCompliantDeviceCountByFeature; + while (rs.next()) { + filteredNonCompliantDeviceCountByFeature = new DeviceCountByGroupEntry(); + filteredNonCompliantDeviceCountByFeature.setGroup(rs.getString("FEATURE_CODE")); + filteredNonCompliantDeviceCountByFeature.setDisplayNameForGroup(rs.getString("FEATURE_CODE")); + filteredNonCompliantDeviceCountByFeature.setDeviceCount(rs.getInt("DEVICE_COUNT")); + filteredNonCompliantDeviceCountsByFeatures.add(filteredNonCompliantDeviceCountByFeature); + } + // fetching total records count + sql = "SELECT COUNT(FEATURE_CODE) AS NON_COMPLIANT_FEATURE_COUNT FROM " + + "(SELECT DISTINCT FEATURE_CODE FROM DEVICES_VIEW_2 WHERE TENANT_ID = ?) NON_COMPLIANT_FEATURE_CODE"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("NON_COMPLIANT_FEATURE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredNonCompliantDeviceCountsByFeatures); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + + @Override + public PaginationResult getDevicesWithDetails(FilterSet filterSet, int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Map filters = this.extractDatabaseFiltersFromBean(filterSet); + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredDevicesWithDetails = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql, advancedSqlFiltering = ""; + // appending filters if exist, to support advanced filtering options + // [1] appending filter columns, if exist + if (filters != null && filters.size() > 0) { + for (String column : filters.keySet()) { + advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; + } + } + sql = "SELECT DEVICE_ID, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM DEVICES_VIEW_1 " + + "WHERE TENANT_ID = ? " + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC LIMIT ?, ?"; + stmt = con.prepareStatement(sql); + // [2] appending filter column values, if exist + stmt.setInt(1, tenantId); + if (filters != null && filters.values().size() > 0) { + int i = 2; + for (Object value : filters.values()) { + if (value instanceof Integer) { + stmt.setInt(i, (Integer) value); + } else if (value instanceof String) { + stmt.setString(i, (String) value); + } + i++; + } + stmt.setInt(i, startIndex); + stmt.setInt(++i, resultCount); + } else { + stmt.setInt(2, startIndex); + stmt.setInt(3, resultCount); + } + // executing query + rs = stmt.executeQuery(); + // fetching query results + DetailedDeviceEntry filteredDeviceWithDetails; + while (rs.next()) { + filteredDeviceWithDetails = new DetailedDeviceEntry(); + filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); + filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); + filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); + filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); + filteredDevicesWithDetails.add(filteredDeviceWithDetails); + } + + // fetching total records count + sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_1 WHERE TENANT_ID = ?"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("DEVICE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredDevicesWithDetails); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + + @Override + public PaginationResult getFeatureNonCompliantDevicesWithDetails(String nonCompliantFeatureCode, + FilterSet filterSet, int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (nonCompliantFeatureCode == null || "".equals(nonCompliantFeatureCode)) { + throw new InvalidParameterValueException("Non-compliant feature code should not be either null or empty."); + } + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Map filters = this.extractDatabaseFiltersFromBean(filterSet); + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredDevicesWithDetails = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql, advancedSqlFiltering = ""; + // appending filters if exist, to support advanced filtering options + // [1] appending filter columns, if exist + if (filters != null && filters.size() > 0) { + for (String column : filters.keySet()) { + advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; + } + } + sql = "SELECT DEVICE_ID, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? AND FEATURE_CODE = ? " + advancedSqlFiltering + + "ORDER BY DEVICE_ID ASC LIMIT ?, ?"; + stmt = con.prepareStatement(sql); + // [2] appending filter column values, if exist + stmt.setInt(1, tenantId); + stmt.setString(2, nonCompliantFeatureCode); + if (filters != null && filters.values().size() > 0) { + int i = 3; + for (Object value : filters.values()) { + if (value instanceof Integer) { + stmt.setInt(i, (Integer) value); + } else if (value instanceof String) { + stmt.setString(i, (String) value); + } + i++; + } + stmt.setInt(i, startIndex); + stmt.setInt(++i, resultCount); + } else { + stmt.setInt(3, startIndex); + stmt.setInt(4, resultCount); + } + // executing query + rs = stmt.executeQuery(); + // fetching query results + DetailedDeviceEntry filteredDeviceWithDetails; + while (rs.next()) { + filteredDeviceWithDetails = new DetailedDeviceEntry(); + filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); + filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); + filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); + filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); + filteredDevicesWithDetails.add(filteredDeviceWithDetails); + } + + // fetching total records count + sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? AND FEATURE_CODE = ?"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + stmt.setString(2, nonCompliantFeatureCode); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("DEVICE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredDevicesWithDetails); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + +} 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 new file mode 100644 index 00000000000..b82ea38a307 --- /dev/null +++ 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 @@ -0,0 +1,281 @@ +/* + * Copyright (c) 2016, 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.analytics.dashboard.dao.impl; + +import org.wso2.carbon.context.PrivilegedCarbonContext; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.AbstractGadgetDataServiceDAO; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DetailedDeviceEntry; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DeviceCountByGroupEntry; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.FilterSet; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.exception.InvalidParameterValueException; +import org.wso2.carbon.device.mgt.common.PaginationResult; +import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; + +import java.sql.Connection; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.util.ArrayList; +import java.util.List; +import java.util.Map; + +public class OracleGadgetDataServiceDAOImpl extends AbstractGadgetDataServiceDAO { + + @Override + public PaginationResult getNonCompliantDeviceCountsByFeatures(int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredNonCompliantDeviceCountsByFeatures = new ArrayList<>(); + 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 DEVICES_VIEW_2 WHERE TENANT_ID = ? GROUP BY FEATURE_CODE ORDER BY " + + "DEVICE_COUNT DESC) rs) WHERE offset >= ? AND ROWNUM <= ?"; + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + stmt.setInt(2, startIndex); + stmt.setInt(3, resultCount); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + DeviceCountByGroupEntry filteredNonCompliantDeviceCountByFeature; + while (rs.next()) { + filteredNonCompliantDeviceCountByFeature = new DeviceCountByGroupEntry(); + filteredNonCompliantDeviceCountByFeature.setGroup(rs.getString("FEATURE_CODE")); + filteredNonCompliantDeviceCountByFeature.setDisplayNameForGroup(rs.getString("FEATURE_CODE")); + filteredNonCompliantDeviceCountByFeature.setDeviceCount(rs.getInt("DEVICE_COUNT")); + filteredNonCompliantDeviceCountsByFeatures.add(filteredNonCompliantDeviceCountByFeature); + } + // fetching total records count + sql = "SELECT COUNT(FEATURE_CODE) AS NON_COMPLIANT_FEATURE_COUNT FROM " + + "(SELECT DISTINCT FEATURE_CODE FROM DEVICES_VIEW_2 WHERE TENANT_ID = ?) NON_COMPLIANT_FEATURE_CODE"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("NON_COMPLIANT_FEATURE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredNonCompliantDeviceCountsByFeatures); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + + @Override + public PaginationResult getDevicesWithDetails(FilterSet filterSet, int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Map filters = this.extractDatabaseFiltersFromBean(filterSet); + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredDevicesWithDetails = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql, advancedSqlFiltering = ""; + // appending filters if exist, to support advanced filtering options + // [1] appending filter columns, if exist + if (filters != null && filters.size() > 0) { + for (String column : filters.keySet()) { + advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; + } + } + sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (SELECT DEVICE_ID, PLATFORM, OWNERSHIP, " + + "CONNECTIVITY_STATUS FROM DEVICES_VIEW_1 WHERE TENANT_ID = ? " + advancedSqlFiltering + + "ORDER BY DEVICE_ID ASC) rs) WHERE offset >= ? AND ROWNUM <= ?"; + stmt = con.prepareStatement(sql); + // [2] appending filter column values, if exist + stmt.setInt(1, tenantId); + if (filters != null && filters.values().size() > 0) { + int i = 2; + for (Object value : filters.values()) { + if (value instanceof Integer) { + stmt.setInt(i, (Integer) value); + } else if (value instanceof String) { + stmt.setString(i, (String) value); + } + i++; + } + stmt.setInt(i, startIndex); + stmt.setInt(++i, resultCount); + } else { + stmt.setInt(2, startIndex); + stmt.setInt(3, resultCount); + } + // executing query + rs = stmt.executeQuery(); + // fetching query results + DetailedDeviceEntry filteredDeviceWithDetails; + while (rs.next()) { + filteredDeviceWithDetails = new DetailedDeviceEntry(); + filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); + filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); + filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); + filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); + filteredDevicesWithDetails.add(filteredDeviceWithDetails); + } + + // fetching total records count + sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_1 WHERE TENANT_ID = ?"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("DEVICE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredDevicesWithDetails); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + + @Override + public PaginationResult getFeatureNonCompliantDevicesWithDetails(String nonCompliantFeatureCode, + FilterSet filterSet, int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (nonCompliantFeatureCode == null || "".equals(nonCompliantFeatureCode)) { + throw new InvalidParameterValueException("Non-compliant feature code should not be either null or empty."); + } + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Map filters = this.extractDatabaseFiltersFromBean(filterSet); + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredDevicesWithDetails = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql, advancedSqlFiltering = ""; + // appending filters if exist, to support advanced filtering options + // [1] appending filter columns, if exist + if (filters != null && filters.size() > 0) { + for (String column : filters.keySet()) { + advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; + } + } + sql = "SELECT * FROM (SELECT ROWNUM offset, rs.* FROM (SELECT DEVICE_ID, PLATFORM, OWNERSHIP, " + + "CONNECTIVITY_STATUS FROM DEVICES_VIEW_2 WHERE TENANT_ID = ? AND FEATURE_CODE = ? " + + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC) rs) WHERE offset >= ? AND ROWNUM <= ?"; + stmt = con.prepareStatement(sql); + // [2] appending filter column values, if exist + stmt.setInt(1, tenantId); + stmt.setString(2, nonCompliantFeatureCode); + if (filters != null && filters.values().size() > 0) { + int i = 3; + for (Object value : filters.values()) { + if (value instanceof Integer) { + stmt.setInt(i, (Integer) value); + } else if (value instanceof String) { + stmt.setString(i, (String) value); + } + i++; + } + stmt.setInt(i, startIndex); + stmt.setInt(++i, resultCount); + } else { + stmt.setInt(3, startIndex); + stmt.setInt(4, resultCount); + } + // executing query + rs = stmt.executeQuery(); + // fetching query results + DetailedDeviceEntry filteredDeviceWithDetails; + while (rs.next()) { + filteredDeviceWithDetails = new DetailedDeviceEntry(); + filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); + filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); + filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); + filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); + filteredDevicesWithDetails.add(filteredDeviceWithDetails); + } + + // fetching total records count + sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? AND FEATURE_CODE = ?"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + stmt.setString(2, nonCompliantFeatureCode); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("DEVICE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredDevicesWithDetails); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + +} 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/PostgreSQLGadgetDataServiceDAOImpl.java b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/PostgreSQLGadgetDataServiceDAOImpl.java new file mode 100644 index 00000000000..778f4b453e4 --- /dev/null +++ b/components/device-mgt/org.wso2.carbon.device.mgt.analytics.dashboard/src/main/java/org/wso2/carbon/device/mgt/analytics/dashboard/dao/impl/PostgreSQLGadgetDataServiceDAOImpl.java @@ -0,0 +1,279 @@ +/* + * Copyright (c) 2016, 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.analytics.dashboard.dao.impl; + +import org.wso2.carbon.context.PrivilegedCarbonContext; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.AbstractGadgetDataServiceDAO; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DetailedDeviceEntry; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.DeviceCountByGroupEntry; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.bean.FilterSet; +import org.wso2.carbon.device.mgt.analytics.dashboard.dao.exception.InvalidParameterValueException; +import org.wso2.carbon.device.mgt.common.PaginationResult; +import org.wso2.carbon.device.mgt.core.dao.util.DeviceManagementDAOUtil; + +import java.sql.Connection; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.util.ArrayList; +import java.util.List; +import java.util.Map; + +public class PostgreSQLGadgetDataServiceDAOImpl extends AbstractGadgetDataServiceDAO { + + @Override + public PaginationResult getNonCompliantDeviceCountsByFeatures(int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredNonCompliantDeviceCountsByFeatures = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql = "SELECT FEATURE_CODE, COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? GROUP BY FEATURE_CODE ORDER BY DEVICE_COUNT DESC OFFSET ? LIMIT ?"; + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + stmt.setInt(2, startIndex); + stmt.setInt(3, resultCount); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + DeviceCountByGroupEntry filteredNonCompliantDeviceCountByFeature; + while (rs.next()) { + filteredNonCompliantDeviceCountByFeature = new DeviceCountByGroupEntry(); + filteredNonCompliantDeviceCountByFeature.setGroup(rs.getString("FEATURE_CODE")); + filteredNonCompliantDeviceCountByFeature.setDisplayNameForGroup(rs.getString("FEATURE_CODE")); + filteredNonCompliantDeviceCountByFeature.setDeviceCount(rs.getInt("DEVICE_COUNT")); + filteredNonCompliantDeviceCountsByFeatures.add(filteredNonCompliantDeviceCountByFeature); + } + // fetching total records count + sql = "SELECT COUNT(FEATURE_CODE) AS NON_COMPLIANT_FEATURE_COUNT FROM " + + "(SELECT DISTINCT FEATURE_CODE FROM DEVICES_VIEW_2 WHERE TENANT_ID = ?) NON_COMPLIANT_FEATURE_CODE"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("NON_COMPLIANT_FEATURE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredNonCompliantDeviceCountsByFeatures); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + + @Override + public PaginationResult getDevicesWithDetails(FilterSet filterSet, int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Map filters = this.extractDatabaseFiltersFromBean(filterSet); + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredDevicesWithDetails = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql, advancedSqlFiltering = ""; + // appending filters if exist, to support advanced filtering options + // [1] appending filter columns, if exist + if (filters != null && filters.size() > 0) { + for (String column : filters.keySet()) { + advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; + } + } + sql = "SELECT DEVICE_ID, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM DEVICES_VIEW_1 " + + "WHERE TENANT_ID = ? " + advancedSqlFiltering + "ORDER BY DEVICE_ID ASC OFFSET ? LIMIT ?"; + stmt = con.prepareStatement(sql); + // [2] appending filter column values, if exist + stmt.setInt(1, tenantId); + if (filters != null && filters.values().size() > 0) { + int i = 2; + for (Object value : filters.values()) { + if (value instanceof Integer) { + stmt.setInt(i, (Integer) value); + } else if (value instanceof String) { + stmt.setString(i, (String) value); + } + i++; + } + stmt.setInt(i, startIndex); + stmt.setInt(++i, resultCount); + } else { + stmt.setInt(2, startIndex); + stmt.setInt(3, resultCount); + } + // executing query + rs = stmt.executeQuery(); + // fetching query results + DetailedDeviceEntry filteredDeviceWithDetails; + while (rs.next()) { + filteredDeviceWithDetails = new DetailedDeviceEntry(); + filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); + filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); + filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); + filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); + filteredDevicesWithDetails.add(filteredDeviceWithDetails); + } + + // fetching total records count + sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_1 WHERE TENANT_ID = ?"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("DEVICE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredDevicesWithDetails); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + + @Override + public PaginationResult getFeatureNonCompliantDevicesWithDetails(String nonCompliantFeatureCode, + FilterSet filterSet, int startIndex, int resultCount) + throws InvalidParameterValueException, SQLException { + + if (nonCompliantFeatureCode == null || "".equals(nonCompliantFeatureCode)) { + throw new InvalidParameterValueException("Non-compliant feature code should not be either null or empty."); + } + + if (startIndex < 0) { + throw new InvalidParameterValueException("Start index should be equal to 0 or greater than that."); + } + + if (resultCount < 5) { + throw new InvalidParameterValueException("Result count should be equal to 5 or greater than that."); + } + + Map filters = this.extractDatabaseFiltersFromBean(filterSet); + + Connection con; + PreparedStatement stmt = null; + ResultSet rs = null; + int tenantId = PrivilegedCarbonContext.getThreadLocalCarbonContext().getTenantId(); + List filteredDevicesWithDetails = new ArrayList<>(); + int totalRecordsCount = 0; + try { + con = this.getConnection(); + String sql, advancedSqlFiltering = ""; + // appending filters if exist, to support advanced filtering options + // [1] appending filter columns, if exist + if (filters != null && filters.size() > 0) { + for (String column : filters.keySet()) { + advancedSqlFiltering = advancedSqlFiltering + "AND " + column + " = ? "; + } + } + sql = "SELECT DEVICE_ID, PLATFORM, OWNERSHIP, CONNECTIVITY_STATUS FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? AND FEATURE_CODE = ? " + advancedSqlFiltering + + "ORDER BY DEVICE_ID ASC OFFSET ? LIMIT ?"; + stmt = con.prepareStatement(sql); + // [2] appending filter column values, if exist + stmt.setInt(1, tenantId); + stmt.setString(2, nonCompliantFeatureCode); + if (filters != null && filters.values().size() > 0) { + int i = 3; + for (Object value : filters.values()) { + if (value instanceof Integer) { + stmt.setInt(i, (Integer) value); + } else if (value instanceof String) { + stmt.setString(i, (String) value); + } + i++; + } + stmt.setInt(i, startIndex); + stmt.setInt(++i, resultCount); + } else { + stmt.setInt(3, startIndex); + stmt.setInt(4, resultCount); + } + // executing query + rs = stmt.executeQuery(); + // fetching query results + DetailedDeviceEntry filteredDeviceWithDetails; + while (rs.next()) { + filteredDeviceWithDetails = new DetailedDeviceEntry(); + filteredDeviceWithDetails.setDeviceId(rs.getInt("DEVICE_ID")); + filteredDeviceWithDetails.setPlatform(rs.getString("PLATFORM")); + filteredDeviceWithDetails.setOwnershipType(rs.getString("OWNERSHIP")); + filteredDeviceWithDetails.setConnectivityStatus(rs.getString("CONNECTIVITY_STATUS")); + filteredDevicesWithDetails.add(filteredDeviceWithDetails); + } + + // fetching total records count + sql = "SELECT COUNT(DEVICE_ID) AS DEVICE_COUNT FROM DEVICES_VIEW_2 " + + "WHERE TENANT_ID = ? AND FEATURE_CODE = ?"; + + stmt = con.prepareStatement(sql); + stmt.setInt(1, tenantId); + stmt.setString(2, nonCompliantFeatureCode); + + // executing query + rs = stmt.executeQuery(); + // fetching query results + while (rs.next()) { + totalRecordsCount = rs.getInt("DEVICE_COUNT"); + } + } finally { + DeviceManagementDAOUtil.cleanupResources(stmt, rs); + } + PaginationResult paginationResult = new PaginationResult(); + paginationResult.setData(filteredDevicesWithDetails); + paginationResult.setRecordsTotal(totalRecordsCount); + return paginationResult; + } + +}