Skip to content

Commit

Permalink
BZ-272120 - SQL upgrade scripts - changing SessionInfo primary key
Browse files Browse the repository at this point in the history
column data type fails
 - updates based on #318
  • Loading branch information
krisv committed Oct 28, 2015
1 parent 4b9cf01 commit b5b410e
Show file tree
Hide file tree
Showing 11 changed files with 391 additions and 165 deletions.
105 changes: 72 additions & 33 deletions jbpm-installer/db/upgrade-scripts/db2/bpms-6.0-to-6.1.sql
@@ -1,6 +1,15 @@
--#SET TERMINATOR @
--This value should be changed, use the same user that BPMS is using to access the DB2
SET CURRENT SCHEMA BPMS@

-- to execute this script open connect in the DB2 console: db2 connect to BPMS
-- Then perform this command: db2 -tf bpms-6.0-to-6.1.sql

-- update context mapping info table with owner id (deployment id) for per process instance strategies
alter table ContextMappingInfo add OWNER_ID varchar(255);
update ContextMappingInfo set OWNER_ID = (select externalId from ProcessInstanceLog where processInstanceId = cast(CONTEXT_ID as bigint));

alter table ContextMappingInfo add OWNER_ID varchar(255)@
update ContextMappingInfo set OWNER_ID = (select externalId from ProcessInstanceLog where processInstanceId = cast(CONTEXT_ID as bigint))@


create table AuditTaskImpl (
id bigint generated by default as identity,
Expand All @@ -19,21 +28,46 @@ create table AuditTaskImpl (
processSessionId integer not null,
status varchar(255),
taskId bigint,
primary key (id));

alter table SessionInfo alter column id set data type bigint;
alter table AuditTaskImpl alter column processSessionId set data type bigint;
alter table AuditTaskImpl alter column activationTime set data type timestamp;
alter table AuditTaskImpl alter column createdOn set data type timestamp;
alter table AuditTaskImpl alter column dueDate set data type timestamp;
alter table ContextMappingInfo alter column KSESSION_ID set data type bigint;
alter table Task alter column processSessionId set data type bigint;

reorg table SessionInfo;
reorg table AuditTaskImpl;
reorg table ContextMappingInfo;
reorg table Task;
reorg table TaskEvent;
primary key (id))@

CREATE OR REPLACE PROCEDURE UPDATE_IDENTITY()
MODIFIES SQL DATA
BEGIN
DECLARE counter INTEGER;
DECLARE queryDrop VARCHAR(255);
DECLARE queryAlterSessionInfo VARCHAR(255);
DECLARE queryGenerateIdentity VARCHAR(255);
SET (counter) = (SELECT MAX(id) AS id FROM SessionInfo);
SET queryDrop = ('ALTER TABLE SessionInfo ALTER COLUMN id DROP IDENTITY');
EXECUTE IMMEDIATE queryDrop;
SET queryAlterSessionInfo = ('ALTER TABLE SessionInfo ALTER COLUMN id SET DATA TYPE BIGINT');
EXECUTE IMMEDIATE queryAlterSessionInfo;
SET queryGenerateIdentity = ('ALTER TABLE SessionInfo ALTER COLUMN id SET GENERATED ALWAYS AS IDENTITY (start with '|| counter ||')');
EXECUTE IMMEDIATE queryGenerateIdentity;
END
@

call UPDATE_IDENTITY()@
DROP PROCEDURE UPDATE_IDENTITY@
Call SYSPROC.ADMIN_CMD('reorg table SessionInfo')@
Call SYSPROC.ADMIN_CMD('runstats on table SessionInfo and indexes all')@


alter table AuditTaskImpl alter column processSessionId set data type bigint@
alter table AuditTaskImpl alter column activationTime set data type timestamp@
alter table AuditTaskImpl alter column createdOn set data type timestamp@
alter table ContextMappingInfo alter column KSESSION_ID set data type bigint@
alter table Task alter column processSessionId set data type bigint@

-- the following statement works in the SQL clients like Squirrel and db2' console, Note: When using db2 console it is necessary to use SCHEMA.TABLENAME
-- Call SYSPROC.ADMIN_CMD('reorg table SessionInfo')
-- Call SYSPROC.ADMIN_CMD('reorg table AuditTaskImpl')
-- Call SYSPROC.ADMIN_CMD('reorg table ContextMappingInfo')
-- Call SYSPROC.ADMIN_CMD('reorg table Task')
-- Call SYSPROC.ADMIN_CMD('reorg table TaskEvent')
-- it should be executed after to reorg the tables
Call SYSPROC.ADMIN_CMD('reorg table AuditTaskImpl')@
alter table AuditTaskImpl alter column dueDate set data type timestamp@

create table DeploymentStore (
id bigint generated by default as identity,
Expand All @@ -43,26 +77,31 @@ create table DeploymentStore (
state integer,
updateDate timestamp,
primary key (id)
);
)@

create unique index UK_DeploymentStore_1 on DeploymentStore (DEPLOYMENT_ID);

alter table ProcessInstanceLog add processInstanceDescription varchar(255);
alter table RequestInfo add owner varchar(255);
alter table Task add description varchar(255);
alter table Task add name varchar(255);
alter table Task add subject varchar(255);
create unique index UK_DeploymentStore_1 on DeploymentStore (DEPLOYMENT_ID)@

alter table ProcessInstanceLog add processInstanceDescription varchar(255)@
alter table RequestInfo add owner varchar(255)@
alter table Task add description varchar(255)@
alter table Task add name varchar(255)@
alter table Task add subject varchar(255)@


-- update all tasks with its name, subject and description
update Task t set name = (select shortText from I18NText where Task_Names_Id = t.id);
update Task t set subject = (select shortText from I18NText where Task_Subjects_Id = t.id);
update Task t set description = (select shortText from I18NText where Task_Descriptions_Id = t.id);
Call SYSPROC.ADMIN_CMD('reorg table Task')@
update Task t set name = (select shortText from I18NText where Task_Names_Id = t.id)@
update Task t set subject = (select shortText from I18NText where Task_Subjects_Id = t.id)@
update Task t set description = (select shortText from I18NText where Task_Descriptions_Id = t.id)@

-- It is necessary to reorg again to work
Call SYSPROC.ADMIN_CMD('reorg table AuditTaskImpl')@
INSERT INTO AuditTaskImpl (activationTime, actualOwner, createdBy, createdOn, deploymentId, description, dueDate, name, parentId, priority, processId, processInstanceId, processSessionId, status, taskId)
SELECT activationTime, actualOwner_id, createdBy_id, createdOn, deploymentId, description, expirationTime, name, parentId, priority,processId, processInstanceId, processSessionId, status, id
FROM Task;
SELECT activationTime, actualOwner_id, createdBy_id, createdOn, deploymentId, description, expirationTime, name, parentId, priority,processId, processInstanceId, processSessionId, status, id FROM Task@


alter table TaskEvent add workItemId bigint;
alter table TaskEvent add processInstanceId bigint;
update TaskEvent t set workItemId = (select workItemId from Task where id = t.taskId);
update TaskEvent t set processInstanceId = (select processInstanceId from Task where id = t.taskId);
alter table TaskEvent add workItemId bigint@
alter table TaskEvent add processInstanceId bigint@
update TaskEvent t set workItemId = (select workItemId from Task where id = t.taskId)@
update TaskEvent t set processInstanceId = (select processInstanceId from Task where id = t.taskId)@
120 changes: 91 additions & 29 deletions jbpm-installer/db/upgrade-scripts/db2/jbpm-6.1-to-6.2.sql
@@ -1,16 +1,73 @@
alter table SessionInfo alter column id set data type bigint;
alter table AuditTaskImpl alter column processSessionId set data type bigint;
alter table AuditTaskImpl alter column activationTime set data type timestamp;
alter table AuditTaskImpl alter column createdOn set data type timestamp;
alter table AuditTaskImpl alter column dueDate set data type timestamp;
alter table ContextMappingInfo alter column KSESSION_ID set data type bigint;
alter table Task alter column processSessionId set data type bigint;

reorg table SessionInfo;
reorg table AuditTaskImpl;
reorg table ContextMappingInfo;
reorg table Task;
reorg table TaskEvent;
--#SET TERMINATOR @
--This value should be changed, use the same user that BPMS is using to access the DB2
SET CURRENT SCHEMA BPMS@

-- to execute this script open connect in the DB2 console: db2 connect to BPMS
-- Then perform this command: db2 -tf jbpm-6.1-to-6.2.sql

-- update context mapping info table with owner id (deployment id) for per process instance strategies

alter table ContextMappingInfo add OWNER_ID varchar(255)@
update ContextMappingInfo set OWNER_ID = (select externalId from ProcessInstanceLog where processInstanceId = cast(CONTEXT_ID as bigint))@


create table AuditTaskImpl (
id bigint generated by default as identity,
activationTime date,
actualOwner varchar(255),
createdBy varchar(255),
createdOn date,
deploymentId varchar(255),
description varchar(255),
dueDate date,
name varchar(255),
parentId bigint not null,
priority integer not null,
processId varchar(255),
processInstanceId bigint not null,
processSessionId integer not null,
status varchar(255),
taskId bigint,
primary key (id))@

CREATE OR REPLACE PROCEDURE UPDATE_IDENTITY()
MODIFIES SQL DATA
BEGIN
DECLARE counter INTEGER;
DECLARE queryDrop VARCHAR(255);
DECLARE queryAlterSessionInfo VARCHAR(255);
DECLARE queryGenerateIdentity VARCHAR(255);
SET (counter) = (SELECT MAX(id) AS id FROM SessionInfo);
SET queryDrop = ('ALTER TABLE SessionInfo ALTER COLUMN id DROP IDENTITY');
EXECUTE IMMEDIATE queryDrop;
SET queryAlterSessionInfo = ('ALTER TABLE SessionInfo ALTER COLUMN id SET DATA TYPE BIGINT');
EXECUTE IMMEDIATE queryAlterSessionInfo;
SET queryGenerateIdentity = ('ALTER TABLE SessionInfo ALTER COLUMN id SET GENERATED ALWAYS AS IDENTITY (start with '|| counter ||')');
EXECUTE IMMEDIATE queryGenerateIdentity;
END
@

call UPDATE_IDENTITY()@
DROP PROCEDURE UPDATE_IDENTITY@
Call SYSPROC.ADMIN_CMD('reorg table SessionInfo')@
Call SYSPROC.ADMIN_CMD('runstats on table SessionInfo and indexes all')@


alter table AuditTaskImpl alter column processSessionId set data type bigint@
alter table AuditTaskImpl alter column activationTime set data type timestamp@
alter table AuditTaskImpl alter column createdOn set data type timestamp@
alter table ContextMappingInfo alter column KSESSION_ID set data type bigint@
alter table Task alter column processSessionId set data type bigint@

-- the following statement works in the SQL clients like Squirrel and db2' console, Note: When using db2 console it is necessary to use SCHEMA.TABLENAME
-- Call SYSPROC.ADMIN_CMD('reorg table SessionInfo')
-- Call SYSPROC.ADMIN_CMD('reorg table AuditTaskImpl')
-- Call SYSPROC.ADMIN_CMD('reorg table ContextMappingInfo')
-- Call SYSPROC.ADMIN_CMD('reorg table Task')
-- Call SYSPROC.ADMIN_CMD('reorg table TaskEvent')
-- it should be executed after to reorg the tables
Call SYSPROC.ADMIN_CMD('reorg table AuditTaskImpl')@
alter table AuditTaskImpl alter column dueDate set data type timestamp@

create table DeploymentStore (
id bigint generated by default as identity,
Expand All @@ -20,26 +77,31 @@ create table DeploymentStore (
state integer,
updateDate timestamp,
primary key (id)
);
)@

create unique index UK_DeploymentStore_1 on DeploymentStore (DEPLOYMENT_ID);

alter table ProcessInstanceLog add processInstanceDescription varchar(255);
alter table RequestInfo add owner varchar(255);
alter table Task add description varchar(255);
alter table Task add name varchar(255);
alter table Task add subject varchar(255);
create unique index UK_DeploymentStore_1 on DeploymentStore (DEPLOYMENT_ID)@

alter table ProcessInstanceLog add processInstanceDescription varchar(255)@
alter table RequestInfo add owner varchar(255)@
alter table Task add description varchar(255)@
alter table Task add name varchar(255)@
alter table Task add subject varchar(255)@


-- update all tasks with its name, subject and description
update Task t set name = (select shortText from I18NText where Task_Names_Id = t.id);
update Task t set subject = (select shortText from I18NText where Task_Subjects_Id = t.id);
update Task t set description = (select shortText from I18NText where Task_Descriptions_Id = t.id);
Call SYSPROC.ADMIN_CMD('reorg table Task')@
update Task t set name = (select shortText from I18NText where Task_Names_Id = t.id)@
update Task t set subject = (select shortText from I18NText where Task_Subjects_Id = t.id)@
update Task t set description = (select shortText from I18NText where Task_Descriptions_Id = t.id)@

-- It is necessary to reorg again to work
Call SYSPROC.ADMIN_CMD('reorg table AuditTaskImpl')@
INSERT INTO AuditTaskImpl (activationTime, actualOwner, createdBy, createdOn, deploymentId, description, dueDate, name, parentId, priority, processId, processInstanceId, processSessionId, status, taskId)
SELECT activationTime, actualOwner_id, createdBy_id, createdOn, deploymentId, description, expirationTime, name, parentId, priority,processId, processInstanceId, processSessionId, status, id
FROM Task;
SELECT activationTime, actualOwner_id, createdBy_id, createdOn, deploymentId, description, expirationTime, name, parentId, priority,processId, processInstanceId, processSessionId, status, id FROM Task@


alter table TaskEvent add workItemId bigint;
alter table TaskEvent add processInstanceId bigint;
update TaskEvent t set workItemId = (select workItemId from Task where id = t.taskId);
update TaskEvent t set processInstanceId = (select processInstanceId from Task where id = t.taskId);
alter table TaskEvent add workItemId bigint@
alter table TaskEvent add processInstanceId bigint@
update TaskEvent t set workItemId = (select workItemId from Task where id = t.taskId)@
update TaskEvent t set processInstanceId = (select processInstanceId from Task where id = t.taskId)@
42 changes: 36 additions & 6 deletions jbpm-installer/db/upgrade-scripts/sqlserver/bpms-6.0-to-6.1.sql
Expand Up @@ -21,7 +21,37 @@ create table AuditTaskImpl (
taskId numeric(19,0),
primary key (id));

ALTER TABLE SessionInfo ALTER COLUMN id numeric(19,0);
-- If exist drop the procedure 'alter_table_session_info'
IF EXISTS (SELECT * FROM sys.objects WHERE type ='P' AND name = 'alter_table_session_info')
DROP PROCEDURE alter_table_session_info
-- Creating the procedure to delete the constraint from SessionInfo table
GO
CREATE PROCEDURE alter_table_session_info
AS
DECLARE @const_name VARCHAR(255)
DECLARE @sqlDroppingConstraint VARCHAR(255)
DECLARE @sqlAlterTableSessionInfo VARCHAR(255)
DECLARE @sqlRecriateConstraint VARCHAR(255)

SELECT @const_name = (SELECT CONSTRAINT_NAME from INFORMATION_SCHEMA.TABLE_CONSTRAINTS where TABLE_NAME='SessionInfo')
BEGIN
SELECT @sqlDroppingConstraint = 'ALTER TABLE SessionInfo DROP CONSTRAINT ' + @const_name
EXEC (@sqlDroppingConstraint)

SELECT @sqlAlterTableSessionInfo = 'ALTER TABLE SessionInfo ALTER COLUMN id numeric(19,0)'
EXEC (@sqlAlterTableSessionInfo)

SELECT @sqlRecriateConstraint = 'ALTER TABLE SessionInfo ADD CONSTRAINT ' + @const_name + ' PRIMARY KEY CLUSTERED ([id] ASC)'
EXEC (@sqlRecriateConstraint)
END
GO
-- Executing the procedure
EXECUTE alter_table_session_info
-- Deleting the procedure to clean it from database
DROP PROCEDURE alter_table_session_info
-- Recriating the Index
ALTER INDEX ALL ON SessionInfo REORGANIZE;

ALTER TABLE AuditTaskImpl ALTER COLUMN processSessionId numeric(19,0);
ALTER TABLE AuditTaskImpl ALTER COLUMN activationTime datetime;
ALTER TABLE AuditTaskImpl ALTER COLUMN createdOn datetime;
Expand All @@ -48,15 +78,15 @@ ALTER TABLE Task ADD name varchar(255);
ALTER TABLE Task ADD subject varchar(255);

-- update all tasks with its name, subject and description
UPDATE Task t SET name = (SELECT shortText FROM I18NText WHERE Task_Names_Id = t.id);
UPDATE Task t SET subject = (SELECT shortText FROM I18NText WHERE Task_Subjects_Id = t.id);
UPDATE Task t SET description = (SELECT shortText FROM I18NText WHERE Task_Descriptions_Id = t.id);
UPDATE Task SET name = (SELECT shortText FROM I18NText WHERE I18NText.Task_Names_Id = Task.id);
UPDATE Task SET subject = (SELECT shortText FROM I18NText WHERE I18NText.Task_Subjects_Id = Task.id);
UPDATE Task SET description = (SELECT shortText FROM I18NText WHERE I18NText.Task_Descriptions_Id = Task.id);

INSERT INTO AuditTaskImpl (activationTime, actualOwner, createdBy, createdOn, deploymentId, description, dueDate, name, parentId, priority, processId, processInstanceId, processSessionId, status, taskId)
SELECT activationTime, actualOwner_id, createdBy_id, createdOn, deploymentId, description, expirationTime, name, parentId, priority,processId, processInstanceId, processSessionId, status, id
FROM Task;

ALTER TABLE TaskEvent ADD workItemId numeric(19,0);
ALTER TABLE TaskEvent ADD processInstanceId numeric(19,0);
UPDATE TaskEvent t SET workItemId = (SELECT workItemId FROM Task WHERE id = t.taskId);
UPDATE TaskEvent t SET processInstanceId = (SELECT processInstanceId FROM Task WHERE id = t.taskId);
UPDATE TaskEvent SET workItemId = (SELECT workItemId FROM Task WHERE Task.id = TaskEvent.taskId);
UPDATE TaskEvent SET processInstanceId = (SELECT processInstanceId FROM Task WHERE Task.id = TaskEvent.taskId);
Expand Up @@ -2,6 +2,6 @@ ALTER TABLE ProcessInstanceLog ADD correlationKey varchar(255);
ALTER TABLE TaskEvent ADD message varchar(255);

ALTER TABLE AuditTaskImpl ADD workItemId numeric(19,0);
UPDATE AuditTaskImpl a SET workItemId = (SELECT workItemId FROM Task WHERE id = a.taskId);
UPDATE AuditTaskImpl SET workItemId = (SELECT workItemId FROM Task WHERE Task.id = AuditTaskImpl.taskId);

create index IDX_PInstLog_correlation on ProcessInstanceLog(correlationKey);

0 comments on commit b5b410e

Please sign in to comment.