Code development platform for open source projects from the European Union institutions

Skip to content
Snippets Groups Projects
Commit 7ae43566 authored by Joze RIHTARSIC's avatar Joze RIHTARSIC
Browse files

Pull request #156: [EDELIVERY-13993] create update database scripts

Merge in EDELIVERY/smp from EDELIVERY-13993-prepare-db-migration-script-for-domismp-5.1-rc to development

* commit '85489d94':
  [EDELIVERY-13993] prepare-db-migration-script-for-domismp-5.1-rc
  [EDELIVERY-13993] create update database scripts
parents 2f60183b 85489d94
Branches EDELIVERY-12897-upgrade-libraries-and-plugins
No related tags found
No related merge requests found
Pipeline #211379 failed
-- drop the added indexes
ALTER TABLE SMP_DOCUMENT DROP CONSTRAINT FKbytp2kp8g3pj8qfp1g6a2g7p;
ALTER TABLE SMP_DOCUMENT_PROPERTY DROP CONSTRAINT FKfag3795e9mrvfvesd00yis9yh;
ALTER TABLE SMP_DOCUMENT_PROPERTY_AUD DROP CONSTRAINT FK81057kcrugb1cfm0io5vkxtin;
ALTER TABLE SMP_DOCUMENT_VERSION_EVENT DROP CONSTRAINT FK6es2svpoxyrnt1h05c9junmdn;
ALTER TABLE SMP_DOMAIN_CONFIGURATION DROP CONSTRAINT FK4303vstoigqtmeo3t2i034gm3;
ALTER TABLE SMP_DOMAIN_CONFIGURATION_AUD DROP CONSTRAINT FKkelcga805bleh5x256hy5e1xb;
-- Drop added columns
ALTER TABLE SMP_CREDENTIAL DROP COLUMN RESET_EXPIRE_ON;
ALTER TABLE SMP_CREDENTIAL DROP COLUMN RESET_TOKEN;
ALTER TABLE SMP_CREDENTIAL_AUD DROP COLUMN RESET_EXPIRE_ON;
ALTER TABLE SMP_CREDENTIAL_AUD DROP COLUMN RESET_TOKEN;
ALTER TABLE SMP_DOCUMENT DROP COLUMN REF_DOCUMENT_URL;
ALTER TABLE SMP_DOCUMENT DROP COLUMN SHARING_ENABLED;
ALTER TABLE SMP_DOCUMENT DROP COLUMN FK_REF_DOCUMENT_ID;
ALTER TABLE SMP_DOCUMENT_AUD DROP COLUMN REF_DOCUMENT_URL;
ALTER TABLE SMP_DOCUMENT_AUD DROP COLUMN SHARING_ENABLED;
ALTER TABLE SMP_DOCUMENT_AUD DROP COLUMN FK_REF_DOCUMENT_ID;
ALTER TABLE SMP_DOCUMENT_VERSION DROP COLUMN STATUS;
ALTER TABLE SMP_DOCUMENT_VERSION_AUD DROP COLUMN STATUS;
ALTER TABLE SMP_RESOURCE DROP COLUMN REVIEW_ENABLED;
ALTER TABLE SMP_RESOURCE_AUD DROP COLUMN REVIEW_ENABLED;
ALTER TABLE SMP_RESOURCE_MEMBER DROP COLUMN PERMISSION_REVIEW;
ALTER TABLE SMP_RESOURCE_MEMBER_AUD DROP COLUMN PERMISSION_REVIEW;
-- Drop created tables
DROP TABLE IF EXISTS SMP_DOCUMENT_PROPERTY;
DROP TABLE IF EXISTS SMP_DOCUMENT_PROPERTY_AUD;
DROP TABLE IF EXISTS SMP_DOCUMENT_VERSION_EVENT;
DROP TABLE IF EXISTS SMP_DOMAIN_CONFIGURATION;
DROP TABLE IF EXISTS SMP_DOMAIN_CONFIGURATION_AUD;
-- update existing tables with new columns
ALTER TABLE SMP_CREDENTIAL
ADD RESET_EXPIRE_ON datetime comment 'Date time when reset token will expire',
ADD RESET_TOKEN varchar(256) CHARACTER SET utf8 COLLATE utf8_bin comment 'Reset token for credential reset';
ALTER TABLE SMP_CREDENTIAL_AUD
ADD RESET_EXPIRE_ON datetime,
ADD RESET_TOKEN varchar(256) CHARACTER SET utf8 COLLATE utf8_bin;
ALTER TABLE SMP_DOCUMENT
ADD REF_DOCUMENT_URL varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
ADD SHARING_ENABLED bit,
ADD FK_REF_DOCUMENT_ID bigint;
ALTER TABLE SMP_DOCUMENT_AUD
ADD REF_DOCUMENT_URL varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
ADD SHARING_ENABLED bit,
ADD FK_REF_DOCUMENT_ID bigint;
ALTER TABLE SMP_DOCUMENT_VERSION
ADD STATUS varchar(255) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT 'RETIRED';
ALTER TABLE SMP_DOCUMENT_VERSION_AUD
ADD STATUS varchar(255) CHARACTER SET utf8 COLLATE utf8_bin;
ALTER TABLE SMP_RESOURCE
ADD REVIEW_ENABLED bit;
ALTER TABLE SMP_RESOURCE_AUD
ADD REVIEW_ENABLED bit;
ALTER TABLE SMP_RESOURCE_MEMBER
ADD PERMISSION_REVIEW bit comment 'User permission to review the resource document';
ALTER TABLE SMP_RESOURCE_MEMBER_AUD
ADD PERMISSION_REVIEW bit;
-- Create new tables
create table SMP_DOCUMENT_PROPERTY (
ID bigint not null auto_increment comment 'Unique document property id',
CREATED_ON datetime not null,
LAST_UPDATED_ON datetime not null,
DESCRIPTION varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin comment 'Property description',
PROPERTY_NAME varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
PROPERTY_TYPE varchar(64) CHARACTER SET utf8 COLLATE utf8_bin,
PROPERTY_VALUE varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
FK_DOCUMENT_ID bigint,
primary key (ID)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_DOCUMENT_PROPERTY_AUD (
ID bigint not null,
REV bigint not null,
REVTYPE tinyint,
CREATED_ON datetime,
LAST_UPDATED_ON datetime,
DESCRIPTION varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin,
PROPERTY_NAME varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
PROPERTY_TYPE varchar(64) CHARACTER SET utf8 COLLATE utf8_bin,
PROPERTY_VALUE varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
FK_DOCUMENT_ID bigint,
primary key (ID, REV)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_DOCUMENT_VERSION_EVENT (
ID bigint not null auto_increment comment 'Unique document version event identifier',
CREATED_ON datetime not null,
LAST_UPDATED_ON datetime not null,
DETAILS varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin comment 'Details of the event',
EVENT_ON datetime comment 'Date time of the event',
EVENT_SOURCE varchar(255) CHARACTER SET utf8 COLLATE utf8_bin not null comment 'Event source UI, API',
EVENT_TYPE varchar(255) CHARACTER SET utf8 COLLATE utf8_bin not null comment 'Document version event type',
EVENT_STATUS varchar(255) CHARACTER SET utf8 COLLATE utf8_bin not null comment 'Document version event type',
EVENT_BY_USERNAME varchar(64) CHARACTER SET utf8 COLLATE utf8_bin comment 'username identifier of the user who triggered the event',
FK_DOCUMENT_VERSION_ID bigint,
primary key (ID)
) comment='Document version Events.' ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_DOMAIN_CONFIGURATION (
ID bigint not null auto_increment comment 'Unique domain configuration id',
CREATED_ON datetime not null,
LAST_UPDATED_ON datetime not null,
DESCRIPTION varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin comment 'Property description',
PROPERTY_NAME varchar(512) CHARACTER SET utf8 COLLATE utf8_bin not null comment 'Property name/key',
SYSTEM_DEFAULT bit not null comment 'Use system default value',
PROPERTY_VALUE varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin comment 'Property value',
FK_DOMAIN_ID bigint not null,
primary key (ID)
) comment='SMP domain configuration' ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_DOMAIN_CONFIGURATION_AUD (
ID bigint not null,
REV bigint not null,
REVTYPE tinyint,
CREATED_ON datetime,
LAST_UPDATED_ON datetime,
DESCRIPTION varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin,
PROPERTY_NAME varchar(512) CHARACTER SET utf8 COLLATE utf8_bin,
SYSTEM_DEFAULT bit,
PROPERTY_VALUE varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin,
FK_DOMAIN_ID bigint,
primary key (ID, REV)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
-- create constraints and indexes
alter table SMP_DOCUMENT_PROPERTY
add constraint SMP_DOC_PROP_IDX unique (FK_DOCUMENT_ID, PROPERTY_NAME);
create index SMP_DOCVEREVNT_DOCVER_IDX on SMP_DOCUMENT_VERSION_EVENT (FK_DOCUMENT_VERSION_ID);
alter table SMP_DOMAIN_CONFIGURATION
add constraint SMP_DOMAIN_CONF_IDX unique (ID, PROPERTY_NAME, FK_DOMAIN_ID);
alter table SMP_DOCUMENT
add constraint FKbytp2kp8g3pj8qfp1g6a2g7p
foreign key (FK_REF_DOCUMENT_ID)
references SMP_DOCUMENT (ID);
alter table SMP_DOCUMENT_PROPERTY
add constraint FKfag3795e9mrvfvesd00yis9yh
foreign key (FK_DOCUMENT_ID)
references SMP_DOCUMENT (ID);
alter table SMP_DOCUMENT_PROPERTY_AUD
add constraint FK81057kcrugb1cfm0io5vkxtin
foreign key (REV)
references SMP_REV_INFO (id);
alter table SMP_DOCUMENT_VERSION_EVENT
add constraint FK6es2svpoxyrnt1h05c9junmdn
foreign key (FK_DOCUMENT_VERSION_ID)
references SMP_DOCUMENT_VERSION (ID);
alter table SMP_DOMAIN_CONFIGURATION
add constraint FK4303vstoigqtmeo3t2i034gm3
foreign key (FK_DOMAIN_ID)
references SMP_DOMAIN (ID);
alter table SMP_DOMAIN_CONFIGURATION_AUD
add constraint FKkelcga805bleh5x256hy5e1xb
foreign key (REV)
references SMP_REV_INFO (id);
-- ----------------------------------------------
-- update SMP_DOCUMENT_VERSION STATUS to RETIRED and current versions to PUBLISHED AND set it to NOT NULL
UPDATE SMP_DOCUMENT_VERSION DV
JOIN SMP_DOCUMENT DOC
ON DOC.ID = DV.FK_DOCUMENT_ID AND DOC.CURRENT_VERSION = DV.VERSION
SET STATUS = 'PUBLISHED';
commit;
-- Rollback for sequence creation
drop sequence SMP_DOC_PROP_SEQ;
drop sequence SMP_DOCVER_EVENT_SEQ;
drop sequence SMP_DOMAIN_CONF_SEQ;
-- Rollback for table alterations
ALTER TABLE SMP_CREDENTIAL DROP COLUMN RESET_EXPIRE_ON;
ALTER TABLE SMP_CREDENTIAL DROP COLUMN RESET_TOKEN;
ALTER TABLE SMP_CREDENTIAL_AUD DROP COLUMN RESET_EXPIRE_ON;
ALTER TABLE SMP_CREDENTIAL_AUD DROP COLUMN RESET_TOKEN;
ALTER TABLE SMP_DOCUMENT DROP COLUMN REF_DOCUMENT_URL;
ALTER TABLE SMP_DOCUMENT DROP COLUMN SHARING_ENABLED;
ALTER TABLE SMP_DOCUMENT DROP COLUMN FK_REF_DOCUMENT_ID;
ALTER TABLE SMP_DOCUMENT_AUD DROP COLUMN REF_DOCUMENT_URL;
ALTER TABLE SMP_DOCUMENT_AUD DROP COLUMN SHARING_ENABLED;
ALTER TABLE SMP_DOCUMENT_AUD DROP COLUMN FK_REF_DOCUMENT_ID;
ALTER TABLE SMP_DOCUMENT_VERSION DROP COLUMN STATUS;
ALTER TABLE SMP_DOCUMENT_VERSION_AUD DROP COLUMN STATUS;
ALTER TABLE SMP_RESOURCE DROP COLUMN REVIEW_ENABLED;
ALTER TABLE SMP_RESOURCE_AUD DROP COLUMN REVIEW_ENABLED;
ALTER TABLE SMP_RESOURCE_MEMBER DROP COLUMN PERMISSION_REVIEW;
ALTER TABLE SMP_RESOURCE_MEMBER_AUD DROP COLUMN PERMISSION_REVIEW;
-- Rollback for constraints and indexes
ALTER TABLE SMP_DOCUMENT_PROPERTY DROP CONSTRAINT SMP_DOC_PROP_IDX;
DROP INDEX SMP_DOCVEREVNT_DOCVER_IDX;
ALTER TABLE SMP_DOMAIN_CONFIGURATION DROP CONSTRAINT SMP_DOMAIN_CONF_IDX;
-- Rollback for table creation
drop table SMP_DOCUMENT_PROPERTY;
drop table SMP_DOCUMENT_PROPERTY_AUD;
drop table SMP_DOCUMENT_VERSION_EVENT;
drop table SMP_DOMAIN_CONFIGURATION;
drop table SMP_DOMAIN_CONFIGURATION_AUD;
create sequence SMP_DOC_PROP_SEQ start with 1 increment by 1;
create sequence SMP_DOCVER_EVENT_SEQ start with 1 increment by 1;
create sequence SMP_DOMAIN_CONF_SEQ start with 1 increment by 1;
ALTER TABLE SMP_CREDENTIAL ADD RESET_EXPIRE_ON timestamp;
ALTER TABLE SMP_CREDENTIAL ADD RESET_TOKEN varchar2(256 char);
comment on column SMP_CREDENTIAL.RESET_EXPIRE_ON is
'Date time when reset token will expire';
comment on column SMP_CREDENTIAL.RESET_TOKEN is
'Reset token for credential reset';
ALTER TABLE SMP_CREDENTIAL_AUD ADD RESET_EXPIRE_ON timestamp;
ALTER TABLE SMP_CREDENTIAL_AUD ADD RESET_TOKEN varchar2(256 char);
ALTER TABLE SMP_DOCUMENT ADD REF_DOCUMENT_URL varchar2(1024 char);
ALTER TABLE SMP_DOCUMENT ADD SHARING_ENABLED number(1,0);
ALTER TABLE SMP_DOCUMENT ADD FK_REF_DOCUMENT_ID number(19,0);
ALTER TABLE SMP_DOCUMENT_AUD ADD REF_DOCUMENT_URL varchar2(1024 char);
ALTER TABLE SMP_DOCUMENT_AUD ADD SHARING_ENABLED number(1,0);
ALTER TABLE SMP_DOCUMENT_AUD ADD FK_REF_DOCUMENT_ID number(19,0);
ALTER TABLE SMP_RESOURCE ADD REVIEW_ENABLED number(1,0);
ALTER TABLE SMP_RESOURCE_AUD ADD REVIEW_ENABLED number(1,0);
ALTER TABLE SMP_RESOURCE_MEMBER ADD PERMISSION_REVIEW number(1,0);
comment on column SMP_RESOURCE_MEMBER.PERMISSION_REVIEW is
'User permission to review the resource document';
ALTER TABLE SMP_RESOURCE_MEMBER_AUD ADD PERMISSION_REVIEW number(1,0);
create table SMP_DOCUMENT_PROPERTY (
ID number(19,0) not null,
CREATED_ON timestamp not null,
LAST_UPDATED_ON timestamp not null,
DESCRIPTION varchar2(4000 char),
PROPERTY_NAME varchar2(255 char),
PROPERTY_TYPE varchar2(64 char),
PROPERTY_VALUE varchar2(1024 char),
FK_DOCUMENT_ID number(19,0),
primary key (ID)
);
comment on column SMP_DOCUMENT_PROPERTY.ID is
'Unique document property id';
comment on column SMP_DOCUMENT_PROPERTY.DESCRIPTION is
'Property description';
create table SMP_DOCUMENT_PROPERTY_AUD (
ID number(19,0) not null,
REV number(19,0) not null,
REVTYPE number(3,0),
CREATED_ON timestamp,
LAST_UPDATED_ON timestamp,
DESCRIPTION varchar2(4000 char),
PROPERTY_NAME varchar2(255 char),
PROPERTY_TYPE varchar2(64 char),
PROPERTY_VALUE varchar2(1024 char),
FK_DOCUMENT_ID number(19,0),
primary key (ID, REV)
);
ALTER TABLE SMP_DOCUMENT_VERSION ADD STATUS varchar2(255 char) default 'RETIRED' not null;
comment on column SMP_DOCUMENT_VERSION.STATUS is
'Document version status';
ALTER TABLE SMP_DOCUMENT_VERSION_AUD ADD STATUS varchar2(255 char);
create table SMP_DOCUMENT_VERSION_EVENT (
ID number(19,0) not null,
CREATED_ON timestamp not null,
LAST_UPDATED_ON timestamp not null,
DETAILS varchar2(1024 char),
EVENT_ON timestamp,
EVENT_SOURCE varchar2(255 char) not null,
EVENT_TYPE varchar2(255 char) not null,
EVENT_STATUS varchar2(255 char) not null,
EVENT_BY_USERNAME varchar2(64 char),
FK_DOCUMENT_VERSION_ID number(19,0),
primary key (ID)
);
comment on table SMP_DOCUMENT_VERSION_EVENT is
'Document version Events.';
comment on column SMP_DOCUMENT_VERSION_EVENT.ID is
'Unique document version event identifier';
comment on column SMP_DOCUMENT_VERSION_EVENT.DETAILS is
'Details of the event';
comment on column SMP_DOCUMENT_VERSION_EVENT.EVENT_ON is
'Date time of the event';
comment on column SMP_DOCUMENT_VERSION_EVENT.EVENT_SOURCE is
'Event source UI, API';
comment on column SMP_DOCUMENT_VERSION_EVENT.EVENT_TYPE is
'Document version event type';
comment on column SMP_DOCUMENT_VERSION_EVENT.EVENT_STATUS is
'Document version event type';
comment on column SMP_DOCUMENT_VERSION_EVENT.EVENT_BY_USERNAME is
'username identifier of the user who triggered the event';
create table SMP_DOMAIN_CONFIGURATION (
ID number(19,0) not null,
CREATED_ON timestamp not null,
LAST_UPDATED_ON timestamp not null,
DESCRIPTION varchar2(4000 char),
PROPERTY_NAME varchar2(512 char) not null,
SYSTEM_DEFAULT number(1,0) not null,
PROPERTY_VALUE varchar2(4000 char),
FK_DOMAIN_ID number(19,0) not null,
primary key (ID)
);
comment on table SMP_DOMAIN_CONFIGURATION is
'SMP domain configuration';
comment on column SMP_DOMAIN_CONFIGURATION.ID is
'Unique domain configuration id';
comment on column SMP_DOMAIN_CONFIGURATION.DESCRIPTION is
'Property description';
comment on column SMP_DOMAIN_CONFIGURATION.PROPERTY_NAME is
'Property name/key';
comment on column SMP_DOMAIN_CONFIGURATION.SYSTEM_DEFAULT is
'Use system default value';
comment on column SMP_DOMAIN_CONFIGURATION.PROPERTY_VALUE is
'Property value';
create table SMP_DOMAIN_CONFIGURATION_AUD (
ID number(19,0) not null,
REV number(19,0) not null,
REVTYPE number(3,0),
CREATED_ON timestamp,
LAST_UPDATED_ON timestamp,
DESCRIPTION varchar2(4000 char),
PROPERTY_NAME varchar2(512 char),
SYSTEM_DEFAULT number(1,0),
PROPERTY_VALUE varchar2(4000 char),
FK_DOMAIN_ID number(19,0),
primary key (ID, REV)
);
-- create constraints and indexes
alter table SMP_DOCUMENT_PROPERTY
add constraint SMP_DOC_PROP_IDX unique (FK_DOCUMENT_ID, PROPERTY_NAME);
create index SMP_DOCVEREVNT_DOCVER_IDX on SMP_DOCUMENT_VERSION_EVENT (FK_DOCUMENT_VERSION_ID);
alter table SMP_DOMAIN_CONFIGURATION
add constraint SMP_DOMAIN_CONF_IDX unique (ID, PROPERTY_NAME, FK_DOMAIN_ID);
alter table SMP_DOCUMENT
add constraint FKbytp2kp8g3pj8qfp1g6a2g7p
foreign key (FK_REF_DOCUMENT_ID)
references SMP_DOCUMENT;
alter table SMP_DOCUMENT_PROPERTY
add constraint FKfag3795e9mrvfvesd00yis9yh
foreign key (FK_DOCUMENT_ID)
references SMP_DOCUMENT;
alter table SMP_DOCUMENT_PROPERTY_AUD
add constraint FK81057kcrugb1cfm0io5vkxtin
foreign key (REV)
references SMP_REV_INFO;
alter table SMP_DOCUMENT_VERSION_EVENT
add constraint FK6es2svpoxyrnt1h05c9junmdn
foreign key (FK_DOCUMENT_VERSION_ID)
references SMP_DOCUMENT_VERSION;
alter table SMP_DOMAIN_CONFIGURATION
add constraint FK4303vstoigqtmeo3t2i034gm3
foreign key (FK_DOMAIN_ID)
references SMP_DOMAIN;
alter table SMP_DOMAIN_CONFIGURATION_AUD
add constraint FKkelcga805bleh5x256hy5e1xb
foreign key (REV)
references SMP_REV_INFO;
-- ----------------------------------------------
-- update SMP_DOCUMENT_VERSION STATUS to RETIRED and current versions to PUBLISHED AND set it to NOT NULL
UPDATE SMP_DOCUMENT_VERSION DV
SET STATUS = 'PUBLISHED'
where EXISTS (SELECT DOC.id from SMP_DOCUMENT DOC where DOC.ID = DV.FK_DOCUMENT_ID
AND DOC.CURRENT_VERSION = DV.VERSION );
commit;
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment