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

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

Pull request #216: Feature/EDELIVERY-9302 migration scripts

Merge in EDELIVERY/smp from feature/EDELIVERY-9302-migration-scripts to development

* commit '1b1e3dc1e189a736de879263893995464be4542c':
  update oracle migration script
  add migration scripts
parents 9f4dd05b f3364ff6
No related branches found
No related tags found
No related merge requests found
-- set usernames for empty "users"
UPDATE SMP_USER set USERNAME ='USERNAME_' | SMP_USER.ID where USERNAME IS NULL;
commit;
create table SMP_ALERT (
ID bigint not null auto_increment comment 'Unique alert id',
CREATED_ON datetime not null,
LAST_UPDATED_ON datetime not null,
ALERT_LEVEL varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
ALERT_STATUS varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
ALERT_STATUS_DESC varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
ALERT_TYPE varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
MAIL_SUBJECT varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
MAIL_TO varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
PROCESSED_TIME datetime,
REPORTING_TIME datetime,
FOR_USERNAME varchar(256) CHARACTER SET utf8 COLLATE utf8_bin,
primary key (ID)
) comment='SMP alerts' ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_ALERT_AUD (
ID bigint not null,
REV bigint not null,
REVTYPE tinyint,
CREATED_ON datetime,
LAST_UPDATED_ON datetime,
ALERT_LEVEL varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
ALERT_STATUS varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
ALERT_STATUS_DESC varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
ALERT_TYPE varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
MAIL_SUBJECT varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
MAIL_TO varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
PROCESSED_TIME datetime,
REPORTING_TIME datetime,
FOR_USERNAME varchar(256) CHARACTER SET utf8 COLLATE utf8_bin,
primary key (ID, REV)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_ALERT_PROPERTY (
ID bigint not null auto_increment comment 'Unique alert property id',
CREATED_ON datetime not null,
LAST_UPDATED_ON datetime not null,
PROPERTY varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
VALUE varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
FK_ALERT_ID bigint,
primary key (ID)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
create table SMP_ALERT_PROPERTY_AUD (
ID bigint not null,
REV bigint not null,
REVTYPE tinyint,
CREATED_ON datetime,
LAST_UPDATED_ON datetime,
PROPERTY varchar(255) CHARACTER SET utf8 COLLATE utf8_bin,
VALUE varchar(1024) CHARACTER SET utf8 COLLATE utf8_bin,
FK_ALERT_ID bigint,
primary key (ID, REV)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
ALTER TABLE SMP_CERTIFICATE ADD EXPIRE_LAST_ALERT_ON datetime comment 'Generated last expire alert';
ALTER TABLE SMP_CERTIFICATE_AUD ADD EXPIRE_LAST_ALERT_ON datetime comment 'Generated last expire alert';
create table SMP_CONFIGURATION_AUD (
PROPERTY varchar(512) CHARACTER SET utf8 COLLATE utf8_bin not null,
REV bigint not null,
REVTYPE tinyint,
CREATED_ON datetime,
LAST_UPDATED_ON datetime,
DESCRIPTION varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin,
VALUE varchar(4000) CHARACTER SET utf8 COLLATE utf8_bin,
primary key (PROPERTY, REV)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
ALTER TABLE SMP_USER MODIFY USERNAME varchar(256) CHARACTER SET utf8 COLLATE utf8_bin not null comment 'Unique username identifier. The Username must not be null';
ALTER TABLE SMP_USER ADD ACCESS_TOKEN varchar(256) CHARACTER SET utf8 COLLATE utf8_bin comment 'BCrypted personal access token';
ALTER TABLE SMP_USER ADD ACCESS_TOKEN_LAST_ALERT_ON datetime comment 'Generated last access token expire alert';
ALTER TABLE SMP_USER ADD ACCESS_TOKEN_EXPIRE_ON datetime comment 'Date when personal access token will expire';
ALTER TABLE SMP_USER ADD ACCESS_TOKEN_GENERATED_ON datetime comment 'Date when personal access token was generated';
ALTER TABLE SMP_USER ADD ACCESS_TOKEN_ID varchar(256) CHARACTER SET utf8 COLLATE utf8_bin comment 'Personal access token id';
ALTER TABLE SMP_USER ADD LAST_FAILED_LOGIN_ON datetime comment 'Last failed login attempt';
ALTER TABLE SMP_USER ADD AT_LAST_FAILED_LOGIN_ON datetime comment 'Last failed token login attempt';
ALTER TABLE SMP_USER ADD PASSWORD_LAST_ALERT_ON datetime comment 'Generated last password expire alert';
ALTER TABLE SMP_USER ADD PASSWORD_EXPIRE_ON datetime comment 'Date when password will expire';
ALTER TABLE SMP_USER ADD LOGIN_FAILURE_COUNT integer comment 'Sequential login failure count';
ALTER TABLE SMP_USER ADD AT_LOGIN_FAILURE_COUNT integer comment 'Sequential token login failure count';
ALTER TABLE SMP_USER_AUD ADD ACCESS_TOKEN varchar(256) CHARACTER SET utf8 COLLATE utf8_bin comment 'BCrypted personal access token';
ALTER TABLE SMP_USER_AUD ADD ACCESS_TOKEN_LAST_ALERT_ON datetime comment 'Generated last access token expire alert';
ALTER TABLE SMP_USER_AUD ADD ACCESS_TOKEN_EXPIRE_ON datetime comment 'Date when personal access token will expire';
ALTER TABLE SMP_USER_AUD ADD ACCESS_TOKEN_GENERATED_ON datetime comment 'Date when personal access token was generated';
ALTER TABLE SMP_USER_AUD ADD ACCESS_TOKEN_ID varchar(256) CHARACTER SET utf8 COLLATE utf8_bin comment 'Personal access token id';
ALTER TABLE SMP_USER_AUD ADD LAST_FAILED_LOGIN_ON datetime comment 'Last failed login attempt';
ALTER TABLE SMP_USER_AUD ADD AT_LAST_FAILED_LOGIN_ON datetime comment 'Last failed token login attempt';
ALTER TABLE SMP_USER_AUD ADD PASSWORD_LAST_ALERT_ON datetime comment 'Generated last password expire alert';
ALTER TABLE SMP_USER_AUD ADD PASSWORD_EXPIRE_ON datetime comment 'Date when password will expire';
ALTER TABLE SMP_USER_AUD ADD LOGIN_FAILURE_COUNT integer comment 'Sequential login failure count';
ALTER TABLE SMP_USER_AUD ADD AT_LOGIN_FAILURE_COUNT integer comment 'Sequential token login failure count';
alter table SMP_USER
add constraint UK_tk9bjsmd2mevgt3b997i6pl27 unique (ACCESS_TOKEN_ID);
alter table SMP_ALERT_AUD
add constraint FKrw0qnto448ojlirpfmfntd8v2
foreign key (REV)
references SMP_REV_INFO (id);
alter table SMP_ALERT_PROPERTY
add constraint FK15r37w3r5ty5f6074ykr2o4i6
foreign key (FK_ALERT_ID)
references SMP_ALERT (ID);
alter table SMP_ALERT_PROPERTY_AUD
add constraint FKod33qjx87ih1a0skxl2sgddar
foreign key (REV)
references SMP_REV_INFO (id);
alter table SMP_CONFIGURATION_AUD
add constraint FKd4yhbdlusovfbdti1fjkuxp9m
foreign key (REV)
references SMP_REV_INFO (id);
SET FOREIGN_KEY_CHECKS = 0;
ALTER TABLE SMP_REV_INFO MODIFY COLUMN id bigint not null auto_increment;
ALTER TABLE SMP_SERVICE_GROUP MODIFY COLUMN ID bigint not null auto_increment comment 'Unique ServiceGroup id';
ALTER TABLE SMP_SERVICE_GROUP_DOMAIN MODIFY COLUMN ID bigint not null auto_increment;
ALTER TABLE SMP_SERVICE_METADATA MODIFY COLUMN ID bigint not null auto_increment comment 'Shared primary key with master table SMP_SERVICE_METADATA';
ALTER TABLE SMP_USER MODIFY COLUMN ID bigint not null auto_increment comment 'Unique user id';
SET FOREIGN_KEY_CHECKS = 1;
-- drop sequence tables , because the are not needed anymore!
drop table SMP_DOMAIN_SEQ;
drop table SMP_REVISION_SEQ;
drop table SMP_SERVICE_GROUP_DOMAIN_SEQ;
drop table SMP_SERVICE_GROUP_SEQ;
drop table SMP_SERVICE_METADATA_SEQ;
drop table SMP_USER_SEQ;
-- set init back-compatible credentials to access tokens
UPDATE SMP_USER set ACCESS_TOKEN_ID = SMP_USER.USERNAME, ACCESS_TOKEN=SMP_USER.PASSWORD;
commit;
\ No newline at end of file
CREATE SEQUENCE smp_alert_prop_seq START WITH 1 INCREMENT BY 1;
CREATE SEQUENCE smp_alert_seq START WITH 1 INCREMENT BY 1;
-- set usernames for empty "users"
UPDATE smp_user
SET
username = 'USERNAME_'
|| lpad(smp_user.id,3,'0')
WHERE
username IS NULL;
COMMIT;
-- create new alert table
CREATE TABLE smp_alert (
id NUMBER(19,0) NOT NULL,
created_on TIMESTAMP NOT NULL,
last_updated_on TIMESTAMP NOT NULL,
alert_level VARCHAR2(255 CHAR),
alert_status VARCHAR2(255 CHAR),
alert_status_desc VARCHAR2(1024 CHAR),
alert_type VARCHAR2(255 CHAR),
mail_subject VARCHAR2(1024 CHAR),
mail_to VARCHAR2(1024 CHAR),
processed_time TIMESTAMP,
reporting_time TIMESTAMP,
for_username VARCHAR2(256 CHAR),
PRIMARY KEY ( id )
);
COMMENT ON TABLE smp_alert IS
'SMP alerts';
COMMENT ON COLUMN smp_alert.id IS
'Unique alert id';
CREATE TABLE smp_alert_aud (
id NUMBER(19,0) NOT NULL,
rev NUMBER(19,0) NOT NULL,
revtype NUMBER(3,0),
created_on TIMESTAMP,
last_updated_on TIMESTAMP,
alert_level VARCHAR2(255 CHAR),
alert_status VARCHAR2(255 CHAR),
alert_status_desc VARCHAR2(1024 CHAR),
alert_type VARCHAR2(255 CHAR),
mail_subject VARCHAR2(1024 CHAR),
mail_to VARCHAR2(1024 CHAR),
processed_time TIMESTAMP,
reporting_time TIMESTAMP,
for_username VARCHAR2(256 CHAR),
PRIMARY KEY ( id,
rev )
);
CREATE TABLE smp_alert_property (
id NUMBER(19,0) NOT NULL,
created_on TIMESTAMP NOT NULL,
last_updated_on TIMESTAMP NOT NULL,
property VARCHAR2(255 CHAR),
value VARCHAR2(1024 CHAR),
fk_alert_id NUMBER(19,0),
PRIMARY KEY ( id )
);
COMMENT ON COLUMN smp_alert_property.id IS
'Unique alert property id';
CREATE TABLE smp_alert_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,
property VARCHAR2(255 CHAR),
value VARCHAR2(1024 CHAR),
fk_alert_id NUMBER(19,0),
PRIMARY KEY ( id,
rev )
);
-- update certificate table
ALTER TABLE smp_certificate ADD expire_last_alert_on TIMESTAMP;
ALTER TABLE smp_certificate_aud ADD expire_last_alert_on TIMESTAMP;
COMMENT ON COLUMN smp_certificate.expire_last_alert_on IS
'Generated last expire alert';
-- add audit table for configuration
CREATE TABLE smp_configuration_aud (
property VARCHAR2(512 CHAR) NOT NULL,
rev NUMBER(19,0) NOT NULL,
revtype NUMBER(3,0),
created_on TIMESTAMP,
last_updated_on TIMESTAMP,
description VARCHAR2(4000 CHAR),
value VARCHAR2(4000 CHAR),
PRIMARY KEY ( property,
rev )
);
-- set option that service group scheme can be also null
ALTER TABLE smp_service_group MODIFY (
participant_scheme NULL
);
-- modify user table
ALTER TABLE smp_user MODIFY (
username NOT NULL
);
ALTER TABLE smp_user ADD access_token VARCHAR2(256 CHAR);
ALTER TABLE smp_user ADD access_token_last_alert_on TIMESTAMP;
ALTER TABLE smp_user ADD access_token_expire_on TIMESTAMP;
ALTER TABLE smp_user ADD access_token_generated_on TIMESTAMP;
ALTER TABLE smp_user ADD access_token_id VARCHAR2(256 CHAR);
ALTER TABLE smp_user ADD last_failed_login_on TIMESTAMP;
ALTER TABLE smp_user ADD at_last_failed_login_on TIMESTAMP;
ALTER TABLE smp_user ADD password_last_alert_on TIMESTAMP;
ALTER TABLE smp_user ADD password_expire_on TIMESTAMP;
ALTER TABLE smp_user ADD login_failure_count NUMBER(10,0);
ALTER TABLE smp_user ADD at_login_failure_count NUMBER(10,0);
ALTER TABLE smp_user_aud ADD access_token VARCHAR2(256 CHAR);
ALTER TABLE smp_user_aud ADD access_token_last_alert_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD access_token_expire_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD access_token_generated_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD access_token_id VARCHAR2(256 CHAR);
ALTER TABLE smp_user_aud ADD last_failed_login_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD at_last_failed_login_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD password_last_alert_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD password_expire_on TIMESTAMP;
ALTER TABLE smp_user_aud ADD login_failure_count NUMBER(10,0);
ALTER TABLE smp_user_aud ADD at_login_failure_count NUMBER(10,0);
COMMENT ON COLUMN smp_user.access_token IS
'BCrypted personal access token';
COMMENT ON COLUMN smp_user.access_token_last_alert_on IS
'Generated last access token expire alert';
COMMENT ON COLUMN smp_user.access_token_expire_on IS
'Date when personal access token will expire';
COMMENT ON COLUMN smp_user.access_token_generated_on IS
'Date when personal access token was generated';
COMMENT ON COLUMN smp_user.access_token_id IS
'Personal access token id';
COMMENT ON COLUMN smp_user.last_failed_login_on IS
'Last failed login attempt';
COMMENT ON COLUMN smp_user.at_last_failed_login_on IS
'Last failed token login attempt';
COMMENT ON COLUMN smp_user.password_last_alert_on IS
'Generated last password expire alert';
COMMENT ON COLUMN smp_user.password_expire_on IS
'Date when password will expire';
COMMENT ON COLUMN smp_user.login_failure_count IS
'Sequential login failure count';
COMMENT ON COLUMN smp_user.at_login_failure_count IS
'Sequential token login failure count';
ALTER TABLE smp_user ADD CONSTRAINT uk_tk9bjsmd2mevgt3b997i6pl27 UNIQUE ( access_token_id );
ALTER TABLE smp_alert_aud ADD CONSTRAINT fkrw0qnto448ojlirpfmfntd8v2 FOREIGN KEY ( rev )
REFERENCES smp_rev_info;
ALTER TABLE smp_alert_property ADD CONSTRAINT fk15r37w3r5ty5f6074ykr2o4i6 FOREIGN KEY ( fk_alert_id )
REFERENCES smp_alert;
ALTER TABLE smp_alert_property_aud ADD CONSTRAINT fkod33qjx87ih1a0skxl2sgddar FOREIGN KEY ( rev )
REFERENCES smp_rev_info;
ALTER TABLE smp_configuration_aud ADD CONSTRAINT fkd4yhbdlusovfbdti1fjkuxp9m FOREIGN KEY ( rev )
REFERENCES smp_rev_info;
-- set init back-compatible credentials to access tokens
UPDATE smp_user
SET
access_token_id = smp_user.username,
access_token = smp_user.password;
COMMIT;
\ No newline at end of file
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