From 4efcbf12f6241ead1abcb7711943566cd285b082 Mon Sep 17 00:00:00 2001 From: geethkokila Date: Mon, 3 Sep 2018 13:28:04 +0530 Subject: [PATCH] Add DB migration scripts for EMM 2.1.0 to IoT 3.3.1 Adding the migration scripts which are required by many customers --- modules/distribution/src/assembly/bin.xml | 6 + .../android-migration.sql | 7 + .../cdm-migration.sql | 239 ++++++++++++++++++ .../ios-migration.sql | 75 ++++++ 4 files changed, 327 insertions(+) create mode 100644 modules/migration/migration-emm_2.1.0-to-iot_3.3.1/android-migration.sql create mode 100644 modules/migration/migration-emm_2.1.0-to-iot_3.3.1/cdm-migration.sql create mode 100644 modules/migration/migration-emm_2.1.0-to-iot_3.3.1/ios-migration.sql diff --git a/modules/distribution/src/assembly/bin.xml b/modules/distribution/src/assembly/bin.xml index 7e1639c0..80a6852c 100755 --- a/modules/distribution/src/assembly/bin.xml +++ b/modules/distribution/src/assembly/bin.xml @@ -690,6 +690,12 @@ ${project.artifactId}-${pom.version}/wso2/tools/identity-anonymization-tool/conf/sql/apim + + + ../migration + ${project.artifactId}-${pom.version}/dbscripts + + diff --git a/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/android-migration.sql b/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/android-migration.sql new file mode 100644 index 00000000..1ba2aeb0 --- /dev/null +++ b/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/android-migration.sql @@ -0,0 +1,7 @@ +ALTER TABLE AD_DEVICE +CHANGE COLUMN GCM_TOKEN FCM_TOKEN VARCHAR(1000) NULL DEFAULT NULL; + +-- Run the following only if the both EMM 2.1.0 and IoT 3.3.1 has to run simultaneously. + +ALTER TABLE AD_DEVICE +ADD COLUMN GCM_TOKEN VARCHAR(1000) NULL AFTER OS_BUILD_DATE; diff --git a/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/cdm-migration.sql b/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/cdm-migration.sql new file mode 100644 index 00000000..5012472d --- /dev/null +++ b/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/cdm-migration.sql @@ -0,0 +1,239 @@ +ALTER TABLE DM_PROFILE +DROP FOREIGN KEY DM_PROFILE_DEVICE_TYPE; + +ALTER TABLE DM_DEVICE_TYPE_POLICY +DROP FOREIGN KEY FK_DEVICE_TYPE_POLICY_DEVICE_TYPE; + + +ALTER TABLE DM_DEVICE_TYPE +ADD COLUMN DEVICE_TYPE_META VARCHAR(20000) NULL AFTER NAME, +ADD COLUMN LAST_UPDATED_TIMESTAMP TIMESTAMP NULL AFTER DEVICE_TYPE_META; + + +CREATE INDEX IDX_DEVICE_TYPE_PROVIDER ON DM_DEVICE_TYPE (NAME, PROVIDER_TENANT_ID); +CREATE INDEX IDX_DEVICE_TYPE_DEVICE_NAME ON DM_DEVICE_TYPE(ID, NAME); + + +CREATE TABLE IF NOT EXISTS DM_GROUP ( + ID INTEGER AUTO_INCREMENT NOT NULL, + GROUP_NAME VARCHAR(100) DEFAULT NULL, + DESCRIPTION TEXT DEFAULT NULL, + OWNER VARCHAR(45) DEFAULT NULL, + TENANT_ID INTEGER DEFAULT 0, + PRIMARY KEY (ID) +) + ENGINE = InnoDB; + +CREATE TABLE IF NOT EXISTS DM_ROLE_GROUP_MAP ( + ID INTEGER AUTO_INCREMENT NOT NULL, + GROUP_ID INTEGER DEFAULT NULL, + ROLE VARCHAR(45) DEFAULT NULL, + TENANT_ID INTEGER DEFAULT 0, + PRIMARY KEY (ID), + CONSTRAINT DM_ROLE_GROUP_MAP_DM_GROUP2 FOREIGN KEY (GROUP_ID) + REFERENCES DM_GROUP (ID) + ON DELETE CASCADE + ON UPDATE CASCADE +) + ENGINE = InnoDB; + + +CREATE INDEX IDX_DM_DEVICE_TYPE_ID_DEVICE_IDENTIFICATION ON DM_DEVICE(TENANT_ID, DEVICE_TYPE_ID,DEVICE_IDENTIFICATION); + +CREATE TABLE IF NOT EXISTS DM_DEVICE_PROPERTIES ( + DEVICE_TYPE_NAME VARCHAR(300) NOT NULL, + DEVICE_IDENTIFICATION VARCHAR(300) NOT NULL, + PROPERTY_NAME VARCHAR(100) DEFAULT 0, + PROPERTY_VALUE VARCHAR(100) DEFAULT NULL, + TENANT_ID VARCHAR(100), + PRIMARY KEY (DEVICE_TYPE_NAME, DEVICE_IDENTIFICATION, PROPERTY_NAME, TENANT_ID) +)ENGINE = InnoDB; + +CREATE TABLE IF NOT EXISTS DM_DEVICE_GROUP_MAP ( + ID INTEGER AUTO_INCREMENT NOT NULL, + DEVICE_ID INTEGER DEFAULT NULL, + GROUP_ID INTEGER DEFAULT NULL, + TENANT_ID INTEGER DEFAULT 0, + PRIMARY KEY (ID), + CONSTRAINT fk_DM_DEVICE_GROUP_MAP_DM_DEVICE2 FOREIGN KEY (DEVICE_ID) + REFERENCES DM_DEVICE (ID) + ON DELETE CASCADE + ON UPDATE CASCADE , + CONSTRAINT fk_DM_DEVICE_GROUP_MAP_DM_GROUP2 FOREIGN KEY (GROUP_ID) + REFERENCES DM_GROUP (ID) + ON DELETE CASCADE + ON UPDATE CASCADE +) + ENGINE = InnoDB; + +ALTER TABLE DM_OPERATION +CHANGE COLUMN INITIATED_BY INITIATED_BY VARCHAR(100) NULL DEFAULT NULL; + + +CREATE INDEX IDX_ENROLMENT_DEVICE_ID_TENANT_ID_STATUS ON DM_ENROLMENT(DEVICE_ID, TENANT_ID, STATUS); + +ALTER TABLE DM_ENROLMENT_OP_MAPPING +ADD COLUMN PUSH_NOTIFICATION_STATUS VARCHAR(50) NULL AFTER STATUS; + +CREATE INDEX IDX_EN_OP_MAPPING_EN_ID_STATUS ON DM_ENROLMENT_OP_MAPPING(ENROLMENT_ID, STATUS); + +ALTER TABLE DM_DEVICE_APPLICATION_MAPPING +ADD COLUMN ENROLMENT_ID INT(11) NULL AFTER DEVICE_ID, +ADD COLUMN APP_PROPERTIES BLOB NULL AFTER TENANT_ID, +ADD COLUMN MEMORY_USAGE INT(11) NULL AFTER APP_PROPERTIES, +ADD COLUMN IS_ACTIVE TINYINT NULL AFTER MEMORY_USAGE; + +SET SQL_SAFE_UPDATES = 0; + +UPDATE DM_DEVICE_APPLICATION_MAPPING dam, + DM_ENROLMENT de, + DM_APPLICATION da +SET + dam.ENROLMENT_ID = de.ID, + dam.MEMORY_USAGE = da.MEMORY_USAGE, + dam.APP_PROPERTIES = da.APP_PROPERTIES, + dam.IS_ACTIVE = da.IS_ACTIVE +WHERE + dam.APPLICATION_ID = da.ID + AND dam.DEVICE_ID = de.DEVICE_ID + AND de.STATUS = 'ACTIVE'; + +SET SQL_SAFE_UPDATES = 1; + + +ALTER TABLE DM_DEVICE_APPLICATION_MAPPING +CHANGE COLUMN IS_ACTIVE IS_ACTIVE TINYINT(4) NOT NULL , +ADD INDEX FK_DM_APP_MAP_DM_ENROL_idx (ENROLMENT_ID ASC); +ALTER TABLE DM_DEVICE_APPLICATION_MAPPING +ADD CONSTRAINT FK_DM_APP_MAP_DM_ENROL + FOREIGN KEY (ENROLMENT_ID) + REFERENCES DM_ENROLMENT (ID) + ON DELETE NO ACTION + ON UPDATE NO ACTION; + + +ALTER TABLE DM_DEVICE_GROUP_POLICY +DROP FOREIGN KEY FK_DM_DEVICE_GROUP_DM_POLICY, +DROP FOREIGN KEY FK_DM_DEVICE_GROUP_POLICY; +ALTER TABLE DM_DEVICE_GROUP_POLICY +ADD CONSTRAINT FK_DM_DEVICE_GROUP_DM_POLICY + FOREIGN KEY (POLICY_ID) + REFERENCES DM_POLICY (ID) + ON DELETE CASCADE + ON UPDATE CASCADE, +ADD CONSTRAINT FK_DM_DEVICE_GROUP_POLICY + FOREIGN KEY (DEVICE_GROUP_ID) + REFERENCES DM_GROUP (ID) + ON DELETE CASCADE + ON UPDATE CASCADE; + + +ALTER TABLE DM_NOTIFICATION +DROP FOREIGN KEY fk_dm_operation_notification; +ALTER TABLE DM_NOTIFICATION +CHANGE COLUMN OPERATION_ID OPERATION_ID INT(11) NULL , +ADD COLUMN LAST_UPDATED_TIMESTAMP TIMESTAMP NULL AFTER DESCRIPTION; + + +ALTER TABLE DM_NOTIFICATION +CHANGE COLUMN LAST_UPDATED_TIMESTAMP LAST_UPDATED_TIMESTAMP TIMESTAMP NOT NULL ; + + +ALTER TABLE DM_DEVICE_INFO +ADD COLUMN ENROLMENT_ID INT(11) NULL AFTER DEVICE_ID; + +SET SQL_SAFE_UPDATES = 0; + + +UPDATE DM_DEVICE_INFO di, + DM_ENROLMENT de +SET + di.ENROLMENT_ID = de.ID +WHERE + di.DEVICE_ID = de.DEVICE_ID + AND de.STATUS = 'ACTIVE'; + +SET SQL_SAFE_UPDATES = 1; + +ALTER TABLE DM_DEVICE_INFO +CHANGE COLUMN ENROLMENT_ID ENROLMENT_ID INT(11) NOT NULL, +ADD INDEX DM_DEVICE_LOCATION_DM_ENROLLMENT_idx (ENROLMENT_ID ASC); +ALTER TABLE DM_DEVICE_INFO +ADD CONSTRAINT DM_DEVICE_LOCATION_DM_ENROLLMENT + FOREIGN KEY (ENROLMENT_ID) + REFERENCES DM_ENROLMENT (ID) + ON DELETE NO ACTION + ON UPDATE NO ACTION; + + +ALTER TABLE DM_DEVICE_LOCATION +CHANGE COLUMN STREET1 STREET1 VARCHAR(255) NULL DEFAULT NULL , +CHANGE COLUMN STREET2 STREET2 VARCHAR(255) NULL DEFAULT NULL , +ADD COLUMN ENROLMENT_ID INT(11) NULL AFTER DEVICE_ID, +ADD COLUMN GEO_HASH VARCHAR(45) NULL AFTER UPDATE_TIMESTAMP, +ADD INDEX DM_DEVICE_LOCATION_GEO_hashx (GEO_HASH ASC); + + +SET SQL_SAFE_UPDATES = 0; + + +UPDATE DM_DEVICE_LOCATION di, + DM_ENROLMENT de +SET + di.ENROLMENT_ID = de.ID +WHERE + di.DEVICE_ID = de.DEVICE_ID + AND de.STATUS = 'ACTIVE'; + +SET SQL_SAFE_UPDATES = 1; + +ALTER TABLE DM_DEVICE_LOCATION +CHANGE COLUMN ENROLMENT_ID ENROLMENT_ID INT(11) NOT NULL , +ADD INDEX DM_DEVICE_LOCATION_DM_ENROLLMENT_idx (ENROLMENT_ID ASC); +ALTER TABLE DM_DEVICE_LOCATION +ADD CONSTRAINT FK_DM_DEVICE_LOCATION_DM_ENROLLMENT + FOREIGN KEY (ENROLMENT_ID) + REFERENCES DM_ENROLMENT (ID) + ON DELETE NO ACTION + ON UPDATE NO ACTION; + + +ALTER TABLE DM_DEVICE_DETAIL +CHANGE COLUMN CONNECTION_TYPE CONNECTION_TYPE VARCHAR(50) NULL DEFAULT NULL , +ADD COLUMN ENROLMENT_ID INT(11) NULL AFTER DEVICE_ID; + + +SET SQL_SAFE_UPDATES = 0; + + +UPDATE DM_DEVICE_DETAIL di, + DM_ENROLMENT de +SET + di.ENROLMENT_ID = de.ID +WHERE + di.DEVICE_ID = de.DEVICE_ID + AND de.STATUS = 'ACTIVE'; + +SET SQL_SAFE_UPDATES = 1; + +ALTER TABLE DM_DEVICE_DETAIL +CHANGE COLUMN ENROLMENT_ID ENROLMENT_ID INT(11) NOT NULL , +ADD INDEX FK_DM_ENROLMENT_DEVICE_DETAILS_idx (ENROLMENT_ID ASC); +ALTER TABLE DM_DEVICE_DETAIL +ADD CONSTRAINT FK_DM_ENROLMENT_DEVICE_DETAILS + FOREIGN KEY (ENROLMENT_ID) + REFERENCES DM_ENROLMENT (ID) + ON DELETE NO ACTION + ON UPDATE NO ACTION; + + + +-- TEMP TABLE REQUIRED FOR DATA ARCHIVAL JOB +CREATE TABLE IF NOT EXISTS DM_ARCHIVED_OPERATIONS ( + ID INTEGER NOT NULL, + CREATED_TIMESTAMP TIMESTAMP NOT NULL, + PRIMARY KEY (ID) +)ENGINE = InnoDB; + + + diff --git a/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/ios-migration.sql b/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/ios-migration.sql new file mode 100644 index 00000000..af596147 --- /dev/null +++ b/modules/migration/migration-emm_2.1.0-to-iot_3.3.1/ios-migration.sql @@ -0,0 +1,75 @@ +ALTER TABLE IOS_DEVICE +CHANGE COLUMN UNLOCK_TOKEN UNLOCK_TOKEN VARCHAR(5000) NULL DEFAULT NULL; + +-- ----------------------------------------------------- +-- Table IOS_DEVICE_PROFILE +-- ----------------------------------------------------- +CREATE TABLE IF NOT EXISTS IOS_DEVICE_PROFILE ( + ID INT NOT NULL AUTO_INCREMENT, + OPERATION_ID VARCHAR(10) NOT NULL, + OPERATION_CODE VARCHAR(1000) NULL, + PROFILE_ID VARCHAR(1000) NULL, + DEVICE_IDENTIFICATION VARCHAR(300) DEFAULT NULL, + PROPERTIES TEXT DEFAULT NULL, + PRIMARY KEY (ID) +); + +-- ----------------------------------------------------- +-- Table IOS_ENROLLMENT_TOKEN +-- ----------------------------------------------------- +CREATE TABLE IF NOT EXISTS IOS_ENROLLMENT_TOKEN ( + TENANT_DOMAIN VARCHAR(255) NOT NULL, + CHALLENGE_TOKEN VARCHAR(45) NOT NULL, + DEVICE_ID VARCHAR(45) DEFAULT NULL, + ACCESS_TOKEN VARCHAR(100) NOT NULL, + REFRESH_TOKEN VARCHAR(100) NOT NULL, + USERNAME VARCHAR(255) NOT NULL, + CLIENT_CREDENTIALS VARCHAR(255) NOT NULL, + AGENT_AVAILABLE VARCHAR(10) NOT NULL, + UNIQUE (TENANT_DOMAIN, CHALLENGE_TOKEN), + PRIMARY KEY (CHALLENGE_TOKEN) +) ENGINE = InnoDB; + +-- ----------------------------------------------------- +-- Table IOS_DEP_PROFILE +-- ----------------------------------------------------- +CREATE TABLE IOS_DEP_PROFILE ( + ID INT NOT NULL AUTO_INCREMENT, + UUID VARCHAR(100) DEFAULT NULL, + PROFILE_NAME VARCHAR(200) DEFAULT NULL, + TENANT_DOMAIN VARCHAR(255) NOT NULL, + PROFILE_CONTENT Text DEFAULT NULL, + UNIQUE (UUID), + PRIMARY KEY (ID) +); + +-- ----------------------------------------------------- +-- Table IOS_PRE_ENROLLED_DEVICE +-- ----------------------------------------------------- +CREATE TABLE IOS_PRE_ENROLLED_DEVICE ( + ID INT NOT NULL AUTO_INCREMENT, + SERIAL VARCHAR(45) DEFAULT NULL, + DEVICE_IDENTIFIER VARCHAR(45) DEFAULT NULL, + USERNAME VARCHAR(255), + TENANT_DOMAIN VARCHAR(255) NOT NULL, + STATUS VARCHAR(100) DEFAULT NULL, + DEP_PROFILE_ID INT DEFAULT NULL, + PROFILE_ASSIGN_TIME TIMESTAMP NULL, + PROFILE_PUSH_TIME TIMESTAMP NULL, + DEVICE_ASSIGNED_TIME TIMESTAMP NULL, + DEVICE_ASSIGNED_BY VARCHAR(100) DEFAULT NULL, + NEED_BASIC_AUTH INT DEFAULT 0, + IS_AGENT_REQUIRED INT DEFAULT 0, + OS VARCHAR(45) DEFAULT NULL, + DEVICE_FAMILY VARCHAR(45) DEFAULT NULL, + DEVICE_MODEL VARCHAR(45) DEFAULT NULL, + DESCRIPTION VARCHAR(200) DEFAULT NULL, + COLOR VARCHAR(200) DEFAULT NULL, + UNIQUE (SERIAL), + PRIMARY KEY (ID), + CONSTRAINT fk_IOS_PRE_ENROLLED_DEVICE_IOS_DEP_PROFILE + FOREIGN KEY (DEP_PROFILE_ID) + REFERENCES IOS_DEP_PROFILE (ID) + ON DELETE NO ACTION + ON UPDATE NO ACTION +); \ No newline at end of file