From a950a11031fced7ec7191c0d2d7a176ba72a0d2a Mon Sep 17 00:00:00 2001
From: Heike Reinken <reinken@ub.uni-leipzig.de>
Date: Fri, 25 Oct 2019 12:23:25 +0200
Subject: [PATCH] refs #16251 [master-v5] Common script to migrate VUFIND1 data
 to VUFIND5 * Note: * Before runnning this current script please check if
 there is the necessity to run database specific adaption scripts apart from
 the common way to ensure that the current script will work properly. *
 Currently there is the need for the Adlr database to run the script
 migrateData_Vufind1ToVufind5_First_Adlr.sql stored in folder
 module/fid_adlr/sql/migrations/mysql * The script has to be executed within a
 mysql session on the related database.

---
 .../migrateData_Vufind1ToVufind5_Common.sql   | 318 ++++++++++++++++++
 1 file changed, 318 insertions(+)
 create mode 100644 module/finc/sql/migrations/mysql/migrateData_Vufind1ToVufind5_Common.sql

diff --git a/module/finc/sql/migrations/mysql/migrateData_Vufind1ToVufind5_Common.sql b/module/finc/sql/migrations/mysql/migrateData_Vufind1ToVufind5_Common.sql
new file mode 100644
index 00000000000..9ceed22977c
--- /dev/null
+++ b/module/finc/sql/migrations/mysql/migrateData_Vufind1ToVufind5_Common.sql
@@ -0,0 +1,318 @@
+-- Transform VUFIND1 data tables into the structures of the vufind2 resp. VUFIND5 tables, #16251, HR
+
+-- Part "Common": Common structure of a VUFIND1 database
+
+-- Please note:
+-- There also exists the script "migrateData_Vufind1ToVufind5_First_Adlr.sql" in /module/fid_adlr/sql/migrations/mysql.
+-- It contains the handling of the Adlr specific structure which has to be done before running the current Common script when using an vufind1 Adlr database.
+-- First run the Additional_Adlr part if you use the vufind1 Adlr database, then run the common part. 
+
+-- Written for mysql statements. It should be compatible with MariaDB statements.
+
+-- Run the following table changes on a dump of a VUFIND1 database (e.g. "2019-03-31-vufind_adlr-mysql.sql").
+
+-- Example for import data statements:
+-- The dump is imported into database "vufind" by running the following command within a Terminal Window:
+--     sudo mysql -h localhost -u root -p -vvf vufind < 2019-03-31-vufind_adlr-mysql.sql
+
+-- Example for running the script:
+-- Within a mysql session type
+--     source migrateDataToVufind5_First_Adlr.sql
+--        - only necessary for an Adlr database dump
+--        - otherwise this common script would fail
+--        - for other databases with additinal structure features write a new script for the special things
+--     source migrateDataToVufind5_Common.sql
+
+-- Example for export data statements to a dump within a Terminal Window:
+--    sudo mysqldump --opt -Q -u root -p -h localhost vufind > 2019-10-25-vufind_adlr-migration-mysql.sql
+
+
+start transaction;
+begin;
+
+ 
+-- Table "user"
+select 'USER table';
+
+-- Apply column modifications  
+
+ALTER TABLE user
+  MODIFY COLUMN username varchar(255),
+  MODIFY COLUMN email varchar(255),
+  MODIFY COLUMN cat_password varchar(70),
+  MODIFY COLUMN created datetime NOT NULL DEFAULT '2000-01-01 00:00:00';
+  
+-- Add missing columns
+
+ALTER TABLE user
+  ADD COLUMN pass_hash varchar(60) DEFAULT NULL,
+  ADD COLUMN cat_id varchar(255),
+  ADD COLUMN cat_pass_enc varchar(255) DEFAULT NULL,
+  ADD COLUMN verify_hash varchar(42) NOT NULL DEFAULT '',
+  ADD COLUMN last_login timestamp NOT NULL DEFAULT '2000-01-01 00:00:00',
+  ADD COLUMN auth_method varchar(50) DEFAULT NULL;
+
+-- Drop columns
+
+ALTER TABLE user
+  DROP COLUMN username_id;           
+  
+-- Apply constraint modifications  
+
+ALTER TABLE user
+  DROP INDEX user_id_key;
+
+ALTER TABLE user
+  ADD UNIQUE(username),
+  ADD UNIQUE(cat_id); 
+
+-- Set chracter set to utf8  
+
+ALTER TABLE user
+  CONVERT TO CHARACTER SET utf8;
+
+  
+-- Table "resource"
+select 'RESURCE table';
+
+
+-- Add missing columns
+
+ALTER TABLE resource
+  ADD COLUMN author varchar(255) DEFAULT NULL,
+  ADD COLUMN year mediumint(6) DEFAULT NULL,
+  ADD COLUMN extra_metadata mediumtext DEFAULT NULL;
+
+-- Apply column modifications  
+
+ALTER TABLE resource
+  MODIFY COLUMN record_id varchar(255) NOT NULL DEFAULT '',
+  MODIFY COLUMN title varchar(255) NOT NULL DEFAULT '',
+  MODIFY COLUMN source varchar(50) NOT NULL DEFAULT 'Solr';
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE resource
+  CONVERT TO CHARACTER SET utf8;
+
+
+-- Table "comments"
+select 'COMMENTS table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE comments
+  MODIFY COLUMN user_id int(11) DEFAULT NULL,
+  MODIFY COLUMN created datetime NOT NULL DEFAULT '2000-01-01 00:00:00';
+  
+-- Apply constraint modifications  
+
+ALTER TABLE comments
+  DROP FOREIGN KEY comments_ibfk_1;
+
+ALTER TABLE comments
+   ADD CONSTRAINT comments_ibfk_1 FOREIGN KEY (user_id) REFERENCES user(id) ON DELETE SET NULL;
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE comments
+  CONVERT TO CHARACTER SET utf8;
+ 
+
+-- Table "change_tracker"
+select 'CHANGE_TRACKER table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE change_tracker
+  MODIFY COLUMN id varchar(120) NOT NULL,
+  MODIFY COLUMN first_indexed datetime DEFAULT NULL,
+  MODIFY COLUMN last_indexed datetime DEFAULT NULL,
+  MODIFY COLUMN last_record_change datetime DEFAULT NULL,
+  MODIFY COLUMN deleted datetime DEFAULT NULL;
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE change_tracker
+  CONVERT TO CHARACTER SET utf8;
+
+
+-- Table "oai_resumption"
+select 'OAI_RESUMPTION table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE oai_resumption
+  MODIFY COLUMN expires datetime NOT NULL DEFAULT '2000-01-01 00:00:00';
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE oai_resumption
+  CONVERT TO CHARACTER SET utf8;
+
+
+-- Table "resource_tags"
+select 'RESOURCE_TAGS table';
+
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE resource_tags
+  CONVERT TO CHARACTER SET utf8;
+
+
+-- Table "search"
+select 'SEARCH table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE search
+  MODIFY COLUMN session_id varchar(128) DEFAULT NULL,
+  MODIFY COLUMN created datetime NOT NULL DEFAULT '2000-01-01 00:00:00';
+  
+-- Add missing columns
+
+ALTER TABLE search
+  ADD COLUMN checksum int(11) DEFAULT NULL;
+
+-- Apply constraint modifications  
+
+ALTER TABLE search
+   DROP INDEX session_id;
+   
+ALTER TABLE search
+  ADD UNIQUE(session_id); 
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE search
+  CONVERT TO CHARACTER SET utf8;
+
+  
+-- Table "session"
+select 'SESSION table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE session
+  MODIFY COLUMN session_id varchar(128) DEFAULT NULL,
+  MODIFY COLUMN data mediumtext,
+  MODIFY COLUMN created datetime NOT NULL DEFAULT '2000-01-01 00:00:00';
+  
+-- Apply constraint modifications  
+
+ALTER TABLE session
+   DROP INDEX last_used;
+   
+ALTER TABLE session
+  ADD UNIQUE(last_used); 
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE session
+  CONVERT TO CHARACTER SET utf8;
+
+  
+-- Table "tags"
+select 'TAGS table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE tags
+  MODIFY COLUMN tag varchar(64) NOT NULL DEFAULT '';
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE tags
+  CONVERT TO CHARACTER SET utf8;
+   
+ 
+-- Table "user_list"
+select 'USER_LIST table';
+
+
+-- Apply column modifications  
+
+ALTER TABLE user_list
+  MODIFY COLUMN created datetime NOT NULL DEFAULT '2000-01-01 00:00:00';
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE user_list
+  CONVERT TO CHARACTER SET utf8;
+
+   
+-- Table "user_resource"
+select 'USER_RESOURCE table';
+
+  
+-- Apply constraint modifications  
+
+ALTER TABLE user_resource
+   DROP FOREIGN KEY user_resource_ibfk_3,
+   DROP FOREIGN KEY user_resource_ibfk_4;
+  
+-- Set chracter set to utf8  
+
+ALTER TABLE user_resource
+  CONVERT TO CHARACTER SET utf8;
+   
+   
+select 'create new tables';
+
+-- Create the new tables of VUFIND5 not being in VUFIND1  
+  
+-- Table "external_session"
+
+CREATE TABLE external_session (
+  id int(11) NOT NULL AUTO_INCREMENT,
+  session_id varchar(128) NOT NULL,
+  external_session_id varchar(255) NOT NULL,
+  created datetime NOT NULL DEFAULT '2000-01-01 00:00:00',
+  PRIMARY KEY (id),
+  UNIQUE KEY session_id (session_id),
+  KEY external_session_id (external_session_id)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE utf8_bin;
+
+
+-- Table "user_card"
+
+CREATE TABLE user_card (
+  id int(11) NOT NULL AUTO_INCREMENT,
+  user_id int(11) NOT NULL,
+  card_name varchar(255) NOT NULL DEFAULT '',
+  cat_username varchar(50) NOT NULL DEFAULT '',
+  cat_password varchar(70) DEFAULT NULL,
+  cat_pass_enc varchar(255) DEFAULT NULL,
+  home_library varchar(100) NOT NULL DEFAULT '',
+  created datetime NOT NULL DEFAULT '2000-01-01 00:00:00',
+  saved timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+  PRIMARY KEY (id),
+  KEY user_id (user_id),
+  KEY user_card_cat_username (cat_username),
+  CONSTRAINT user_card_ibfk_1 FOREIGN KEY (user_id) REFERENCES user (id) ON DELETE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+
+-- Table "record"
+
+CREATE TABLE record (
+  id int(11) NOT NULL AUTO_INCREMENT,
+  record_id varchar(255) DEFAULT NULL,
+  source varchar(50) DEFAULT NULL,
+  version varchar(20) NOT NULL,
+  data longtext DEFAULT NULL,
+  updated datetime NOT NULL DEFAULT '2000-01-01 00:00:00',
+  PRIMARY KEY (id),
+  UNIQUE KEY record_id_source (record_id, source)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+    
+
+
+commit;
-- 
GitLab