H2 migration scripts from DSpace 1.2 -> 4.0

This commit is contained in:
Tim Donohue
2014-10-21 21:32:37 +00:00
parent 9dc5a5290b
commit e164e4f79a
12 changed files with 1499 additions and 783 deletions

View File

@@ -11,9 +11,21 @@ when the `DatabaseManager` initializes itself (see `initializeDatabase()` method
The H2 migrations in this directory are *based on* the Oracle Migrations
(`[src]/dspace/etc/migrations/oracle/*.sql`), but with some modifications in
order to be valid in H2. For reference see the [H2 SQL Grammar](http://www.h2database.com/html/grammar.html).
order to be valid in H2.
## More Information
## Oracle vs H2 script differences
One of the primary differences between the Oracle scripts and these H2 ones
is in the syntax of the `ALTER TABLE` command. Unfortunately, H2's syntax for
that command differs greatly from Oracle (and PostgreSQL as well).
Most of the remainder of the scripts contain the exact Oracle syntax (which is
usually valid in H2). But, to you can always `diff` scripts of the same name
for further syntax differences.
For additional info see the [H2 SQL Grammar](http://www.h2database.com/html/grammar.html).
## More Information on Flyway
The SQL scripts in this directory are H2-specific database migrations. They are
used to automatically upgrade your DSpace database using [Flyway](http://flywaydb.org/).

View File

@@ -0,0 +1,562 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
CREATE SEQUENCE bitstreamformatregistry_seq;
CREATE SEQUENCE fileextension_seq;
CREATE SEQUENCE bitstream_seq;
CREATE SEQUENCE eperson_seq;
CREATE SEQUENCE epersongroup_seq START WITH 2; -- we reserve 0 and 1
CREATE SEQUENCE item_seq;
CREATE SEQUENCE bundle_seq;
CREATE SEQUENCE item2bundle_seq;
CREATE SEQUENCE bundle2bitstream_seq;
CREATE SEQUENCE dctyperegistry_seq;
CREATE SEQUENCE dcvalue_seq;
CREATE SEQUENCE community_seq;
CREATE SEQUENCE collection_seq;
CREATE SEQUENCE community2community_seq;
CREATE SEQUENCE community2collection_seq;
CREATE SEQUENCE collection2item_seq;
CREATE SEQUENCE resourcepolicy_seq;
CREATE SEQUENCE epersongroup2eperson_seq;
CREATE SEQUENCE handle_seq;
CREATE SEQUENCE workspaceitem_seq;
CREATE SEQUENCE workflowitem_seq;
CREATE SEQUENCE tasklistitem_seq;
CREATE SEQUENCE registrationdata_seq;
CREATE SEQUENCE subscription_seq;
CREATE SEQUENCE history_seq;
CREATE SEQUENCE historystate_seq;
CREATE SEQUENCE communities2item_seq;
CREATE SEQUENCE itemsbyauthor_seq;
CREATE SEQUENCE itemsbytitle_seq;
CREATE SEQUENCE itemsbydate_seq;
CREATE SEQUENCE itemsbydateaccessioned_seq;
-------------------------------------------------------
-- BitstreamFormatRegistry table
-------------------------------------------------------
CREATE TABLE BitstreamFormatRegistry
(
bitstream_format_id INTEGER PRIMARY KEY,
mimetype VARCHAR2(48),
short_description VARCHAR2(128) UNIQUE,
description VARCHAR2(2000),
support_level INTEGER,
-- Identifies internal types
internal NUMBER(1)
);
-------------------------------------------------------
-- FileExtension table
-------------------------------------------------------
CREATE TABLE FileExtension
(
file_extension_id INTEGER PRIMARY KEY,
bitstream_format_id INTEGER REFERENCES BitstreamFormatRegistry(bitstream_format_id),
extension VARCHAR2(16)
);
-------------------------------------------------------
-- Bitstream table
-------------------------------------------------------
CREATE TABLE Bitstream
(
bitstream_id INTEGER PRIMARY KEY,
bitstream_format_id INTEGER REFERENCES BitstreamFormatRegistry(bitstream_format_id),
name VARCHAR2(256),
size_bytes INTEGER,
checksum VARCHAR2(64),
checksum_algorithm VARCHAR2(32),
description VARCHAR2(2000),
user_format_description VARCHAR2(2000),
source VARCHAR2(256),
internal_id VARCHAR2(256),
deleted NUMBER(1),
store_number INTEGER,
sequence_id INTEGER
);
-------------------------------------------------------
-- EPerson table
-------------------------------------------------------
CREATE TABLE EPerson
(
eperson_id INTEGER PRIMARY KEY,
email VARCHAR2(64) UNIQUE,
password VARCHAR2(64),
firstname VARCHAR2(64),
lastname VARCHAR2(64),
can_log_in NUMBER(1),
require_certificate NUMBER(1),
self_registered NUMBER(1),
last_active TIMESTAMP,
sub_frequency INTEGER,
phone VARCHAR2(32)
);
-- index by email
CREATE INDEX eperson_email_idx ON EPerson(email);
-------------------------------------------------------
-- EPersonGroup table
-------------------------------------------------------
CREATE TABLE EPersonGroup
(
eperson_group_id INTEGER PRIMARY KEY,
name VARCHAR2(256) UNIQUE
);
-------------------------------------------------------
-- Item table
-------------------------------------------------------
CREATE TABLE Item
(
item_id INTEGER PRIMARY KEY,
submitter_id INTEGER REFERENCES EPerson(eperson_id),
in_archive NUMBER(1),
withdrawn NUMBER(1),
last_modified TIMESTAMP,
owning_collection INTEGER
);
-------------------------------------------------------
-- Bundle table
-------------------------------------------------------
CREATE TABLE Bundle
(
bundle_id INTEGER PRIMARY KEY,
mets_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
name VARCHAR2(16), -- ORIGINAL | THUMBNAIL | TEXT
primary_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id)
);
-------------------------------------------------------
-- Item2Bundle table
-------------------------------------------------------
CREATE TABLE Item2Bundle
(
id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
bundle_id INTEGER REFERENCES Bundle(bundle_id)
);
-- index by item_id
CREATE INDEX item2bundle_item_idx on Item2Bundle(item_id);
-------------------------------------------------------
-- Bundle2Bitstream table
-------------------------------------------------------
CREATE TABLE Bundle2Bitstream
(
id INTEGER PRIMARY KEY,
bundle_id INTEGER REFERENCES Bundle(bundle_id),
bitstream_id INTEGER REFERENCES Bitstream(bitstream_id)
);
-- index by bundle_id
CREATE INDEX bundle2bitstream_bundle_idx ON Bundle2Bitstream(bundle_id);
-------------------------------------------------------
-- DCTypeRegistry table
-------------------------------------------------------
CREATE TABLE DCTypeRegistry
(
dc_type_id INTEGER PRIMARY KEY,
element VARCHAR2(64),
qualifier VARCHAR2(64),
scope_note VARCHAR2(2000),
UNIQUE(element, qualifier)
);
-------------------------------------------------------
-- DCValue table
-------------------------------------------------------
CREATE TABLE DCValue
(
dc_value_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
dc_type_id INTEGER REFERENCES DCTypeRegistry(dc_type_id),
text_value VARCHAR2(2000),
text_lang VARCHAR2(24),
place INTEGER,
source_id INTEGER
);
-- An index for item_id - almost all access is based on
-- instantiating the item object, which grabs all dcvalues
-- related to that item
CREATE INDEX dcvalue_item_idx on DCValue(item_id);
-------------------------------------------------------
-- Community table
-------------------------------------------------------
CREATE TABLE Community
(
community_id INTEGER PRIMARY KEY,
name VARCHAR2(128) UNIQUE,
short_description VARCHAR2(512),
introductory_text VARCHAR2(2000),
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
copyright_text VARCHAR2(2000),
side_bar_text VARCHAR2(2000)
);
-------------------------------------------------------
-- Collection table
-------------------------------------------------------
CREATE TABLE Collection
(
collection_id INTEGER PRIMARY KEY,
name VARCHAR2(128),
short_description VARCHAR2(512),
introductory_text VARCHAR2(2000),
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
template_item_id INTEGER REFERENCES Item(item_id),
provenance_description VARCHAR2(2000),
license VARCHAR2(2000),
copyright_text VARCHAR2(2000),
side_bar_text VARCHAR2(2000),
workflow_step_1 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
workflow_step_2 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
workflow_step_3 INTEGER REFERENCES EPersonGroup( eperson_group_id )
);
-------------------------------------------------------
-- Community2Community table
-------------------------------------------------------
CREATE TABLE Community2Community
(
id INTEGER PRIMARY KEY,
parent_comm_id INTEGER REFERENCES Community(community_id),
child_comm_id INTEGER REFERENCES Community(community_id)
);
-------------------------------------------------------
-- Community2Collection table
-------------------------------------------------------
CREATE TABLE Community2Collection
(
id INTEGER PRIMARY KEY,
community_id INTEGER REFERENCES Community(community_id),
collection_id INTEGER REFERENCES Collection(collection_id)
);
-------------------------------------------------------
-- Collection2Item table
-------------------------------------------------------
CREATE TABLE Collection2Item
(
id INTEGER PRIMARY KEY,
collection_id INTEGER REFERENCES Collection(collection_id),
item_id INTEGER REFERENCES Item(item_id)
);
-- index by collection_id
CREATE INDEX collection2item_collection_idx ON Collection2Item(collection_id);
-------------------------------------------------------
-- ResourcePolicy table
-------------------------------------------------------
CREATE TABLE ResourcePolicy
(
policy_id INTEGER PRIMARY KEY,
resource_type_id INTEGER,
resource_id INTEGER,
action_id INTEGER,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
epersongroup_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
start_date DATE,
end_date DATE
);
-- index by resource_type,resource_id - all queries by
-- authorization manager are select type=x, id=y, action=z
CREATE INDEX resourcepolicy_type_id_idx ON ResourcePolicy(resource_type_id,resource_id);
-------------------------------------------------------
-- EPersonGroup2EPerson table
-------------------------------------------------------
CREATE TABLE EPersonGroup2EPerson
(
id INTEGER PRIMARY KEY,
eperson_group_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
eperson_id INTEGER REFERENCES EPerson(eperson_id)
);
-- Index by group ID (used heavily by AuthorizeManager)
CREATE INDEX epersongroup2eperson_group_idx on EPersonGroup2EPerson(eperson_group_id);
-------------------------------------------------------
-- Handle table
-------------------------------------------------------
CREATE TABLE Handle
(
handle_id INTEGER PRIMARY KEY,
handle VARCHAR2(256) UNIQUE,
resource_type_id INTEGER,
resource_id INTEGER
);
-- index by handle, commonly looked up
CREATE INDEX handle_handle_idx ON Handle(handle);
-------------------------------------------------------
-- WorkspaceItem table
-------------------------------------------------------
CREATE TABLE WorkspaceItem
(
workspace_item_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
collection_id INTEGER REFERENCES Collection(collection_id),
-- Answers to questions on first page of submit UI
multiple_titles NUMBER(1), -- boolean
published_before NUMBER(1),
multiple_files NUMBER(1),
-- How for the user has got in the submit process
stage_reached INTEGER
);
-------------------------------------------------------
-- WorkflowItem table
-------------------------------------------------------
CREATE TABLE WorkflowItem
(
workflow_id INTEGER PRIMARY KEY,
item_id INTEGER UNIQUE REFERENCES Item(item_id),
collection_id INTEGER REFERENCES Collection(collection_id),
state INTEGER,
owner INTEGER REFERENCES EPerson(eperson_id),
-- Answers to questions on first page of submit UI
multiple_titles NUMBER(1),
published_before NUMBER(1),
multiple_files NUMBER(1)
-- Note: stage reached not applicable here - people involved in workflow
-- can always jump around submission UI
);
-------------------------------------------------------
-- TasklistItem table
-------------------------------------------------------
CREATE TABLE TasklistItem
(
tasklist_id INTEGER PRIMARY KEY,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
workflow_id INTEGER REFERENCES WorkflowItem(workflow_id)
);
-------------------------------------------------------
-- RegistrationData table
-------------------------------------------------------
CREATE TABLE RegistrationData
(
registrationdata_id INTEGER PRIMARY KEY,
email VARCHAR2(64) UNIQUE,
token VARCHAR2(48),
expires TIMESTAMP
);
-------------------------------------------------------
-- Subscription table
-------------------------------------------------------
CREATE TABLE Subscription
(
subscription_id INTEGER PRIMARY KEY,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
collection_id INTEGER REFERENCES Collection(collection_id)
);
-------------------------------------------------------
-- History table
-------------------------------------------------------
CREATE TABLE History
(
history_id INTEGER PRIMARY KEY,
-- When it was stored
creation_date TIMESTAMP,
-- A checksum to keep INTEGERizations from being stored more than once
checksum VARCHAR2(32) UNIQUE
);
-------------------------------------------------------
-- HistoryState table
-------------------------------------------------------
CREATE TABLE HistoryState
(
history_state_id INTEGER PRIMARY KEY,
object_id VARCHAR2(64)
);
------------------------------------------------------------
-- Browse subsystem tables and views
------------------------------------------------------------
-------------------------------------------------------
-- Communities2Item table
-------------------------------------------------------
CREATE TABLE Communities2Item
(
id INTEGER PRIMARY KEY,
community_id INTEGER REFERENCES Community(community_id),
item_id INTEGER REFERENCES Item(item_id)
);
-------------------------------------------------------
-- Community2Item view
------------------------------------------------------
CREATE VIEW Community2Item as
SELECT Community2Collection.community_id, Collection2Item.item_id
FROM Community2Collection, Collection2Item
WHERE Collection2Item.collection_id = Community2Collection.collection_id
;
-------------------------------------------------------
-- ItemsByAuthor table
-------------------------------------------------------
CREATE TABLE ItemsByAuthor
(
items_by_author_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
author VARCHAR2(2000),
sort_author VARCHAR2(2000)
);
-- index by sort_author, of course!
CREATE INDEX sort_author_idx on ItemsByAuthor(sort_author);
-------------------------------------------------------
-- CollectionItemsByAuthor view
-------------------------------------------------------
CREATE VIEW CollectionItemsByAuthor as
SELECT Collection2Item.collection_id, ItemsByAuthor.*
FROM ItemsByAuthor, Collection2Item
WHERE ItemsByAuthor.item_id = Collection2Item.item_id
;
-------------------------------------------------------
-- CommunityItemsByAuthor view
-------------------------------------------------------
CREATE VIEW CommunityItemsByAuthor as
SELECT Communities2Item.community_id, ItemsByAuthor.*
FROM ItemsByAuthor, Communities2Item
WHERE ItemsByAuthor.item_id = Communities2Item.item_id
;
----------------------------------------
-- ItemsByTitle table
----------------------------------------
CREATE TABLE ItemsByTitle
(
items_by_title_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
title VARCHAR2(2000),
sort_title VARCHAR2(2000)
);
-- index by the sort_title
CREATE INDEX sort_title_idx on ItemsByTitle(sort_title);
-------------------------------------------------------
-- CollectionItemsByTitle view
-------------------------------------------------------
CREATE VIEW CollectionItemsByTitle as
SELECT Collection2Item.collection_id, ItemsByTitle.*
FROM ItemsByTitle, Collection2Item
WHERE ItemsByTitle.item_id = Collection2Item.item_id
;
-------------------------------------------------------
-- CommunityItemsByTitle view
-------------------------------------------------------
CREATE VIEW CommunityItemsByTitle as
SELECT Communities2Item.community_id, ItemsByTitle.*
FROM ItemsByTitle, Communities2Item
WHERE ItemsByTitle.item_id = Communities2Item.item_id
;
-------------------------------------------------------
-- ItemsByDate table
-------------------------------------------------------
CREATE TABLE ItemsByDate
(
items_by_date_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
date_issued VARCHAR2(2000)
);
-- sort by date
CREATE INDEX date_issued_idx on ItemsByDate(date_issued);
-------------------------------------------------------
-- CollectionItemsByDate view
-------------------------------------------------------
CREATE VIEW CollectionItemsByDate as
SELECT Collection2Item.collection_id, ItemsByDate.*
FROM ItemsByDate, Collection2Item
WHERE ItemsByDate.item_id = Collection2Item.item_id
;
-------------------------------------------------------
-- CommunityItemsByDate view
-------------------------------------------------------
CREATE VIEW CommunityItemsByDate as
SELECT Communities2Item.community_id, ItemsByDate.*
FROM ItemsByDate, Communities2Item
WHERE ItemsByDate.item_id = Communities2Item.item_id
;
-------------------------------------------------------
-- ItemsByDateAccessioned table
-------------------------------------------------------
CREATE TABLE ItemsByDateAccessioned
(
items_by_date_accessioned_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
date_accessioned VARCHAR2(2000)
);
-------------------------------------------------------
-- CollectionItemsByDateAccession view
-------------------------------------------------------
CREATE VIEW CollectionItemsByDateAccession as
SELECT Collection2Item.collection_id, ItemsByDateAccessioned.*
FROM ItemsByDateAccessioned, Collection2Item
WHERE ItemsByDateAccessioned.item_id = Collection2Item.item_id
;
-------------------------------------------------------
-- CommunityItemsByDateAccession view
-------------------------------------------------------
CREATE VIEW CommunityItemsByDateAccession as
SELECT Communities2Item.community_id, ItemsByDateAccessioned.*
FROM ItemsByDateAccessioned, Communities2Item
WHERE ItemsByDateAccessioned.item_id = Communities2Item.item_id
;
-------------------------------------------------------
-- Create 'special' groups, for anonymous access
-- and administrators
-------------------------------------------------------
-- We don't use getnextid() for 'anonymous' since the sequences start at '1'
INSERT INTO epersongroup VALUES(0, 'Anonymous');
INSERT INTO epersongroup VALUES(1, 'Administrator');

View File

@@ -0,0 +1,58 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
CREATE SEQUENCE epersongroup2workspaceitem_seq;
-------------------------------------------------------------------------------
-- create the new EPersonGroup2WorkspaceItem table
-------------------------------------------------------------------------------
CREATE TABLE EPersonGroup2WorkspaceItem
(
id INTEGER PRIMARY KEY,
eperson_group_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
workspace_item_id INTEGER REFERENCES WorkspaceItem(workspace_item_id)
);
-------------------------------------------------------------------------------
-- modification to collection table to support being able to change the
-- submitter and collection admin group names
-------------------------------------------------------------------------------
ALTER TABLE collection ADD COLUMN submitter INTEGER;
ALTER TABLE collection ADD CONSTRAINT submitter_eperson_group FOREIGN KEY (submitter) REFERENCES EPersonGroup(eperson_group_id);
ALTER TABLE collection ADD COLUMN admin INTEGER;
ALTER TABLE collection ADD CONSTRAINT admin_eperson_group FOREIGN KEY (admin) REFERENCES EPersonGroup(eperson_group_id);
ALTER TABLE eperson ADD COLUMN netid VARCHAR2(64);
ALTER TABLE eperson ADD CONSTRAINT netid_unique UNIQUE (netid);
-------------------------------------------------------------------------------
-- Additional indices for performance
-------------------------------------------------------------------------------
-- index by resource id and resource type id
CREATE INDEX handle_resource_id_and_type_idx ON handle(resource_id, resource_type_id);
-- Indexing browse tables update/re-index performance
CREATE INDEX Communities2Item_item_id_idx ON Communities2Item( item_id );
CREATE INDEX ItemsByAuthor_item_id_idx ON ItemsByAuthor(item_id);
CREATE INDEX ItemsByTitle_item_id_idx ON ItemsByTitle(item_id);
CREATE INDEX ItemsByDate_item_id_idx ON ItemsByDate(item_id);
CREATE INDEX ItemsByDateAccessioned_item_id_idx ON ItemsByDateAccessioned(item_id);
-- Improve mapping tables
CREATE INDEX Community2Collection_community_id_idx ON Community2Collection(community_id);
CREATE INDEX Community2Collection_collection_id_idx ON Community2Collection(collection_id);
CREATE INDEX Collection2Item_item_id_idx ON Collection2Item( item_id );

View File

@@ -0,0 +1,131 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
---------------------------------------
-- Update MetadataValue to include CLOB
---------------------------------------
CREATE TABLE MetadataValueTemp
(
metadata_value_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
metadata_field_id INTEGER REFERENCES MetadataFieldRegistry(metadata_field_id),
text_value CLOB,
text_lang VARCHAR(64),
place INTEGER
);
INSERT INTO MetadataValueTemp
SELECT * FROM MetadataValue;
DROP VIEW dcvalue;
DROP TABLE MetadataValue;
ALTER TABLE MetadataValueTemp RENAME TO MetadataValue;
CREATE VIEW dcvalue AS
SELECT MetadataValue.metadata_value_id AS "dc_value_id", MetadataValue.item_id,
MetadataValue.metadata_field_id AS "dc_type_id", MetadataValue.text_value,
MetadataValue.text_lang, MetadataValue.place
FROM MetadataValue, MetadataFieldRegistry
WHERE MetadataValue.metadata_field_id = MetadataFieldRegistry.metadata_field_id
AND MetadataFieldRegistry.metadata_schema_id = 1;
CREATE INDEX metadatavalue_item_idx ON MetadataValue(item_id);
CREATE INDEX metadatavalue_item_idx2 ON MetadataValue(item_id,metadata_field_id);
------------------------------------
-- Update Community to include CLOBs
------------------------------------
CREATE TABLE CommunityTemp
(
community_id INTEGER PRIMARY KEY,
name VARCHAR2(128),
short_description VARCHAR2(512),
introductory_text CLOB,
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
copyright_text CLOB,
side_bar_text VARCHAR2(2000)
);
INSERT INTO CommunityTemp
SELECT * FROM Community;
DROP TABLE Community CASCADE CONSTRAINTS;
ALTER TABLE CommunityTemp RENAME TO Community;
ALTER TABLE Community2Community ADD CONSTRAINT fk_c2c_parent
FOREIGN KEY (parent_comm_id)
REFERENCES Community (community_id);
ALTER TABLE Community2Community ADD CONSTRAINT fk_c2c_child
FOREIGN KEY (child_comm_id)
REFERENCES Community (community_id);
ALTER TABLE Community2Collection ADD CONSTRAINT fk_c2c_community
FOREIGN KEY (community_id)
REFERENCES Community (community_id);
ALTER TABLE Communities2Item ADD CONSTRAINT fk_c2i_community
FOREIGN KEY (community_id)
REFERENCES Community (community_id);
-------------------------------------
-- Update Collection to include CLOBs
-------------------------------------
CREATE TABLE CollectionTemp
(
collection_id INTEGER PRIMARY KEY,
name VARCHAR2(128),
short_description VARCHAR2(512),
introductory_text CLOB,
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
template_item_id INTEGER REFERENCES Item(item_id),
provenance_description VARCHAR2(2000),
license CLOB,
copyright_text CLOB,
side_bar_text VARCHAR2(2000),
workflow_step_1 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
workflow_step_2 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
workflow_step_3 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
submitter INTEGER REFERENCES EPersonGroup( eperson_group_id ),
admin INTEGER REFERENCES EPersonGroup( eperson_group_id )
);
INSERT INTO CollectionTemp
SELECT * FROM Collection;
DROP TABLE Collection CASCADE CONSTRAINTS;
ALTER TABLE CollectionTemp RENAME TO Collection;
ALTER TABLE Community2Collection ADD CONSTRAINT fk_c2c_collection
FOREIGN KEY (collection_id)
REFERENCES Collection (collection_id);
ALTER TABLE Collection2Item ADD CONSTRAINT fk_c2i_collection
FOREIGN KEY (collection_id)
REFERENCES Collection (collection_id);
ALTER TABLE WorkspaceItem ADD CONSTRAINT fk_wsi_collection
FOREIGN KEY (collection_id)
REFERENCES Collection (collection_id);
ALTER TABLE WorkflowItem ADD CONSTRAINT fk_wfi_collection
FOREIGN KEY (collection_id)
REFERENCES Collection (collection_id);
ALTER TABLE Subscription ADD CONSTRAINT fk_subs_collection
FOREIGN KEY (collection_id)
REFERENCES Collection (collection_id);

View File

@@ -0,0 +1,332 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
-------------------------------------------------------------------------------
-- Sequences for Group within Group feature
-------------------------------------------------------------------------------
CREATE SEQUENCE group2group_seq;
CREATE SEQUENCE group2groupcache_seq;
------------------------------------------------------
-- Group2Group table, records group membership in other groups
------------------------------------------------------
CREATE TABLE Group2Group
(
id INTEGER PRIMARY KEY,
parent_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
child_id INTEGER REFERENCES EPersonGroup(eperson_group_id)
);
------------------------------------------------------
-- Group2GroupCache table, is the 'unwound' hierarchy in
-- Group2Group. It explicitly names every parent child
-- relationship, even with nested groups. For example,
-- If Group2Group lists B is a child of A and C is a child of B,
-- this table will have entries for parent(A,B), and parent(B,C)
-- AND parent(A,C) so that all of the child groups of A can be
-- looked up in a single simple query
------------------------------------------------------
CREATE TABLE Group2GroupCache
(
id INTEGER PRIMARY KEY,
parent_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
child_id INTEGER REFERENCES EPersonGroup(eperson_group_id)
);
-------------------------------------------------------
-- New Metadata Tables and Sequences
-------------------------------------------------------
-- metadatafieldregistry #1 is reserved for DC
CREATE SEQUENCE metadataschemaregistry_seq START WITH 2;
CREATE SEQUENCE metadatafieldregistry_seq;
CREATE SEQUENCE metadatavalue_seq;
-- MetadataSchemaRegistry table
CREATE TABLE MetadataSchemaRegistry
(
metadata_schema_id INTEGER PRIMARY KEY,
namespace VARCHAR(256) UNIQUE,
short_id VARCHAR(32)
);
-- MetadataFieldRegistry table
CREATE TABLE MetadataFieldRegistry
(
metadata_field_id INTEGER PRIMARY KEY,
metadata_schema_id INTEGER NOT NULL REFERENCES MetadataSchemaRegistry(metadata_schema_id),
element VARCHAR(64),
qualifier VARCHAR(64),
scope_note VARCHAR2(2000)
);
-- MetadataValue table
CREATE TABLE MetadataValue
(
metadata_value_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
metadata_field_id INTEGER REFERENCES MetadataFieldRegistry(metadata_field_id),
text_value VARCHAR2(2000),
text_lang VARCHAR(24),
place INTEGER
);
-- Create the DC schema
INSERT INTO MetadataSchemaRegistry VALUES (1,'http://dublincore.org/documents/dcmi-terms/','dc');
-- Migrate the existing DCTypes into the new metadata field registry
INSERT INTO MetadataFieldRegistry
(metadata_schema_id, metadata_field_id, element, qualifier, scope_note)
SELECT '1' AS metadata_schema_id, dc_type_id, element,
qualifier, scope_note FROM dctyperegistry;
-- Copy the DCValues into the new MetadataValue table
INSERT INTO MetadataValue (item_id, metadata_field_id, text_value, text_lang, place)
SELECT item_id, dc_type_id, text_value, text_lang, place FROM dcvalue;
DROP TABLE dcvalue;
CREATE VIEW dcvalue AS
SELECT MetadataValue.metadata_value_id AS "dc_value_id", MetadataValue.item_id,
MetadataValue.metadata_field_id AS "dc_type_id", MetadataValue.text_value,
MetadataValue.text_lang, MetadataValue.place
FROM MetadataValue, MetadataFieldRegistry
WHERE MetadataValue.metadata_field_id = MetadataFieldRegistry.metadata_field_id
AND MetadataFieldRegistry.metadata_schema_id = 1;
-- CANNOT EASILY RESET SEQUENCES IN H2
-- @updateseq.sql metadatafieldregistry_seq metadatafieldregistry metadata_field_id;
-- @updateseq.sql metadatavalue_seq metadatavalue metadata_value_id;
-- @updateseq.sql metadataschemaregistry_seq metadataschemaregistry metadata_schema_id;
DROP TABLE dctyperegistry;
-- create indexes for the metadata tables
CREATE INDEX metadatavalue_item_idx ON MetadataValue(item_id);
CREATE INDEX metadatavalue_item_idx2 ON MetadataValue(item_id,metadata_field_id);
CREATE INDEX metadatafield_schema_idx ON MetadataFieldRegistry(metadata_schema_id);
-------------------------------------------------------
-- Create the checksum checker tables
-------------------------------------------------------
-- list of the possible results as determined
-- by the system or an administrator
CREATE TABLE checksum_results
(
result_code VARCHAR(64) PRIMARY KEY,
result_description VARCHAR2(2000)
);
-- This table has a one-to-one relationship
-- with the bitstream table. A row will be inserted
-- every time a row is inserted into the bitstream table, and
-- that row will be updated every time the checksum is
-- re-calculated.
CREATE TABLE most_recent_checksum
(
bitstream_id INTEGER PRIMARY KEY,
to_be_processed NUMBER(1) NOT NULL,
expected_checksum VARCHAR(64) NOT NULL,
current_checksum VARCHAR(64) NOT NULL,
last_process_start_date TIMESTAMP NOT NULL,
last_process_end_date TIMESTAMP NOT NULL,
checksum_algorithm VARCHAR(64) NOT NULL,
matched_prev_checksum NUMBER(1) NOT NULL,
result VARCHAR(64) REFERENCES checksum_results(result_code)
);
-- A row will be inserted into this table every
-- time a checksum is re-calculated.
CREATE SEQUENCE checksum_history_seq;
CREATE TABLE checksum_history
(
check_id INTEGER PRIMARY KEY,
bitstream_id INTEGER,
process_start_date TIMESTAMP,
process_end_date TIMESTAMP,
checksum_expected VARCHAR(64),
checksum_calculated VARCHAR(64),
result VARCHAR(64) REFERENCES checksum_results(result_code)
);
-- this will insert into the result code
-- the initial results
insert into checksum_results
values
(
'INVALID_HISTORY',
'Install of the cheksum checking code do not consider this history as valid'
);
insert into checksum_results
values
(
'BITSTREAM_NOT_FOUND',
'The bitstream could not be found'
);
insert into checksum_results
values
(
'CHECKSUM_MATCH',
'Current checksum matched previous checksum'
);
insert into checksum_results
values
(
'CHECKSUM_NO_MATCH',
'Current checksum does not match previous checksum'
);
insert into checksum_results
values
(
'CHECKSUM_PREV_NOT_FOUND',
'Previous checksum was not found: no comparison possible'
);
insert into checksum_results
values
(
'BITSTREAM_INFO_NOT_FOUND',
'Bitstream info not found'
);
insert into checksum_results
values
(
'CHECKSUM_ALGORITHM_INVALID',
'Invalid checksum algorithm'
);
insert into checksum_results
values
(
'BITSTREAM_NOT_PROCESSED',
'Bitstream marked to_be_processed=false'
);
insert into checksum_results
values
(
'BITSTREAM_MARKED_DELETED',
'Bitstream marked deleted in bitstream table'
);
-- this will insert into the most recent checksum
-- on install all existing bitstreams
-- setting all bitstreams already set as
-- deleted to not be processed
insert into most_recent_checksum
(
bitstream_id,
to_be_processed,
expected_checksum,
current_checksum,
last_process_start_date,
last_process_end_date,
checksum_algorithm,
matched_prev_checksum
)
select
bitstream.bitstream_id,
'1',
CASE WHEN bitstream.checksum IS NULL THEN '' ELSE bitstream.checksum END,
CASE WHEN bitstream.checksum IS NULL THEN '' ELSE bitstream.checksum END,
FORMATDATETIME(NOW(),'DD-MM-RRRR HH24:MI:SS'),
FORMATDATETIME(NOW(),'DD-MM-RRRR HH24:MI:SS'),
CASE WHEN bitstream.checksum_algorithm IS NULL THEN 'MD5' ELSE bitstream.checksum_algorithm END,
'1'
from bitstream;
-- Update all the deleted checksums
-- to not be checked
-- because they have since been
-- deleted from the system
update most_recent_checksum
set to_be_processed = 0
where most_recent_checksum.bitstream_id in (
select bitstream_id
from bitstream where deleted = '1' );
-- this will insert into history table
-- for the initial start
-- we want to tell the users to disregard the initial
-- inserts into the checksum history table
insert into checksum_history
(
bitstream_id,
process_start_date,
process_end_date,
checksum_expected,
checksum_calculated
)
select most_recent_checksum.bitstream_id,
most_recent_checksum.last_process_end_date,
FORMATDATETIME(NOW(),'DD-MM-RRRR HH24:MI:SS'),
most_recent_checksum.expected_checksum,
most_recent_checksum.expected_checksum
FROM most_recent_checksum;
-- update the history to indicate that this was
-- the first time the software was installed
update checksum_history
set result = 'INVALID_HISTORY';
-------------------------------------------------------
-- Table and views for 'browse by subject' functionality
-------------------------------------------------------
CREATE SEQUENCE itemsbysubject_seq;
-------------------------------------------------------
-- ItemsBySubject table
-------------------------------------------------------
CREATE TABLE ItemsBySubject
(
items_by_subject_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
subject VARCHAR2(2000),
sort_subject VARCHAR2(2000)
);
-- index by sort_subject
CREATE INDEX sort_subject_idx on ItemsBySubject(sort_subject);
-------------------------------------------------------
-- CollectionItemsBySubject view
-------------------------------------------------------
CREATE VIEW CollectionItemsBySubject as
SELECT Collection2Item.collection_id, ItemsBySubject.*
FROM ItemsBySubject, Collection2Item
WHERE ItemsBySubject.item_id = Collection2Item.item_id
;
-------------------------------------------------------
-- CommunityItemsBySubject view
-------------------------------------------------------
CREATE VIEW CommunityItemsBySubject as
SELECT Communities2Item.community_id, ItemsBySubject.*
FROM ItemsBySubject, Communities2Item
WHERE ItemsBySubject.item_id = Communities2Item.item_id
;

View File

@@ -0,0 +1,139 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
-- Remove NOT NULL restrictions from the checksum columns of most_recent_checksum
ALTER TABLE most_recent_checksum MODIFY expected_checksum null;
ALTER TABLE most_recent_checksum MODIFY current_checksum null;
------------------------------------------------------
-- New Column language language in EPerson
------------------------------------------------------
alter table eperson ADD language VARCHAR2(64);
update eperson set language = 'en';
-- totally unused column
alter table bundle drop column mets_bitstream_id;
-------------------------------------------------------------------------------
-- Necessary for Configurable Submission functionality:
-- Modification to workspaceitem table to support keeping track
-- of the last page reached within a step in the Configurable Submission Process
-------------------------------------------------------------------------------
ALTER TABLE workspaceitem ADD page_reached INTEGER;
-------------------------------------------------------------------------
-- Increase the mimetype field size to support larger types, such as the
-- new Word 2007 mimetypes.
-------------------------------------------------------------------------
ALTER TABLE BitstreamFormatRegistry ALTER COLUMN mimetype VARCHAR(256);
-------------------------------------------------------------------------
-- Tables to manage cache of item counts for communities and collections
-------------------------------------------------------------------------
CREATE TABLE collection_item_count (
collection_id INTEGER PRIMARY KEY REFERENCES collection(collection_id),
count INTEGER
);
CREATE TABLE community_item_count (
community_id INTEGER PRIMARY KEY REFERENCES community(community_id),
count INTEGER
);
------------------------------------------------------------------
-- Remove sequences and tables of the old browse system
------------------------------------------------------------------
DROP SEQUENCE itemsbyauthor_seq;
DROP SEQUENCE itemsbytitle_seq;
DROP SEQUENCE itemsbydate_seq;
DROP SEQUENCE itemsbydateaccessioned_seq;
DROP SEQUENCE itemsbysubject_seq;
DROP TABLE ItemsByAuthor CASCADE CONSTRAINTS;
DROP TABLE ItemsByTitle CASCADE CONSTRAINTS;
DROP TABLE ItemsByDate CASCADE CONSTRAINTS;
DROP TABLE ItemsByDateAccessioned CASCADE CONSTRAINTS;
DROP TABLE ItemsBySubject CASCADE CONSTRAINTS;
DROP TABLE History CASCADE CONSTRAINTS;
DROP TABLE HistoryState CASCADE CONSTRAINTS;
----------------------------------------------------------------
-- Add indexes for foreign key columns
----------------------------------------------------------------
CREATE INDEX fe_bitstream_fk_idx ON FileExtension(bitstream_format_id);
CREATE INDEX bit_bitstream_fk_idx ON Bitstream(bitstream_format_id);
CREATE INDEX g2g_parent_fk_idx ON Group2Group(parent_id);
CREATE INDEX g2g_child_fk_idx ON Group2Group(child_id);
-- CREATE INDEX g2gc_parent_fk_idx ON Group2Group(parent_id);
-- CREATE INDEX g2gc_child_fk_idx ON Group2Group(child_id);
CREATE INDEX item_submitter_fk_idx ON Item(submitter_id);
CREATE INDEX bundle_primary_fk_idx ON Bundle(primary_bitstream_id);
CREATE INDEX item2bundle_bundle_fk_idx ON Item2Bundle(bundle_id);
CREATE INDEX bundle2bits_bitstream_fk_idx ON Bundle2Bitstream(bitstream_id);
CREATE INDEX metadatavalue_field_fk_idx ON MetadataValue(metadata_field_id);
CREATE INDEX community_logo_fk_idx ON Community(logo_bitstream_id);
CREATE INDEX collection_logo_fk_idx ON Collection(logo_bitstream_id);
CREATE INDEX collection_template_fk_idx ON Collection(template_item_id);
CREATE INDEX collection_workflow1_fk_idx ON Collection(workflow_step_1);
CREATE INDEX collection_workflow2_fk_idx ON Collection(workflow_step_2);
CREATE INDEX collection_workflow3_fk_idx ON Collection(workflow_step_3);
CREATE INDEX collection_submitter_fk_idx ON Collection(submitter);
CREATE INDEX collection_admin_fk_idx ON Collection(admin);
CREATE INDEX com2com_parent_fk_idx ON Community2Community(parent_comm_id);
CREATE INDEX com2com_child_fk_idx ON Community2Community(child_comm_id);
CREATE INDEX rp_eperson_fk_idx ON ResourcePolicy(eperson_id);
CREATE INDEX rp_epersongroup_fk_idx ON ResourcePolicy(epersongroup_id);
CREATE INDEX epg2ep_eperson_fk_idx ON EPersonGroup2EPerson(eperson_id);
CREATE INDEX workspace_item_fk_idx ON WorkspaceItem(item_id);
CREATE INDEX workspace_coll_fk_idx ON WorkspaceItem(collection_id);
-- CREATE INDEX workflow_item_fk_idx ON WorkflowItem(item_id);
CREATE INDEX workflow_coll_fk_idx ON WorkflowItem(collection_id);
CREATE INDEX workflow_owner_fk_idx ON WorkflowItem(owner);
CREATE INDEX tasklist_eperson_fk_idx ON TasklistItem(eperson_id);
CREATE INDEX tasklist_workflow_fk_idx ON TasklistItem(workflow_id);
CREATE INDEX subs_eperson_fk_idx ON Subscription(eperson_id);
CREATE INDEX subs_collection_fk_idx ON Subscription(collection_id);
CREATE INDEX epg2wi_group_fk_idx ON epersongroup2workspaceitem(eperson_group_id);
CREATE INDEX epg2wi_workspace_fk_idx ON epersongroup2workspaceitem(workspace_item_id);
CREATE INDEX Comm2Item_community_fk_idx ON Communities2Item( community_id );
CREATE INDEX mrc_result_fk_idx ON most_recent_checksum( result );
CREATE INDEX ch_result_fk_idx ON checksum_history( result );

View File

@@ -0,0 +1,91 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
------------------------------------------------------------------
-- New Column for Community Admin - Delegated Admin patch (DS-228)
------------------------------------------------------------------
ALTER TABLE community ADD COLUMN admin INTEGER;
ALTER TABLE community ADD CONSTRAINT community_admin_fk FOREIGN KEY (admin) REFERENCES epersongroup ( eperson_group_id );
CREATE INDEX community_admin_fk_idx ON Community(admin);
-------------------------------------------------------------------------
-- DS-236 schema changes for Authority Control of Metadata Values
-------------------------------------------------------------------------
ALTER TABLE MetadataValue ADD COLUMN authority VARCHAR(100);
ALTER TABLE MetadataValue ADD COLUMN confidence INTEGER DEFAULT -1;
--------------------------------------------------------------------------
-- DS-295 CC License being assigned incorrect Mime Type during submission.
--------------------------------------------------------------------------
UPDATE bitstream SET bitstream_format_id =
(SELECT bitstream_format_id FROM bitstreamformatregistry WHERE short_description = 'CC License')
WHERE name = 'license_text' AND source = 'org.dspace.license.CreativeCommons';
UPDATE bitstream SET bitstream_format_id =
(SELECT bitstream_format_id FROM bitstreamformatregistry WHERE short_description = 'RDF XML')
WHERE name = 'license_rdf' AND source = 'org.dspace.license.CreativeCommons';
-------------------------------------------------------------------------
-- DS-260 Cleanup of Owning collection column for template item created
-- with the JSPUI after the collection creation
-------------------------------------------------------------------------
UPDATE item SET owning_collection = null WHERE item_id IN
(SELECT template_item_id FROM collection WHERE template_item_id IS NOT null);
-- Recreate restraints with a know name and deferrable option!
-- (The previous version of these constraints is dropped by org.dspace.storage.rdbms.migration.V1_5_9__Drop_constraint_for_DSpace_1_6_schema)
ALTER TABLE community2collection ADD CONSTRAINT comm2coll_collection_fk FOREIGN KEY (collection_id) REFERENCES collection DEFERRABLE;
ALTER TABLE community2community ADD CONSTRAINT com2com_child_fk FOREIGN KEY (child_comm_id) REFERENCES community DEFERRABLE;
ALTER TABLE collection2item ADD CONSTRAINT coll2item_item_fk FOREIGN KEY (item_id) REFERENCES item DEFERRABLE;
------------------------------------------------------------------
-- New tables /sequences for the harvester functionality (DS-289)
------------------------------------------------------------------
CREATE SEQUENCE harvested_collection_seq;
CREATE SEQUENCE harvested_item_seq;
-------------------------------------------------------
-- Create the harvest settings table
-------------------------------------------------------
-- Values used by the OAIHarvester to harvest a collection
-- HarvestInstance is the DAO class for this table
CREATE TABLE harvested_collection
(
collection_id INTEGER REFERENCES collection(collection_id) ON DELETE CASCADE,
harvest_type INTEGER,
oai_source VARCHAR(256),
oai_set_id VARCHAR(256),
harvest_message VARCHAR2(512),
metadata_config_id VARCHAR(256),
harvest_status INTEGER,
harvest_start_time TIMESTAMP,
last_harvested TIMESTAMP,
id INTEGER PRIMARY KEY
);
CREATE INDEX harvested_collection_fk_idx ON harvested_collection(collection_id);
CREATE TABLE harvested_item
(
item_id INTEGER REFERENCES item(item_id) ON DELETE CASCADE,
last_harvested TIMESTAMP,
oai_id VARCHAR(64),
id INTEGER PRIMARY KEY
);
CREATE INDEX harvested_item_fk_idx ON harvested_item(item_id);

View File

@@ -0,0 +1,18 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
------------------------------------------------------------------
-- Remove unused / obsolete sequence 'dctyperegistry_seq' (DS-729)
------------------------------------------------------------------
DROP SEQUENCE dctyperegistry_seq;

View File

@@ -0,0 +1,21 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
-------------------------------------------
-- New column for bitstream order DS-749 --
-------------------------------------------
ALTER TABLE bundle2bitstream ADD COLUMN bitstream_order INTEGER;
--Place the sequence id's in the order
UPDATE bundle2bitstream SET bitstream_order=(SELECT sequence_id FROM bitstream WHERE bitstream.bitstream_id=bundle2bitstream.bitstream_id);

View File

@@ -0,0 +1,47 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
ALTER TABLE resourcepolicy ADD COLUMN rpname VARCHAR2(30);
ALTER TABLE resourcepolicy ADD COLUMN rptype VARCHAR2(30);
ALTER TABLE resourcepolicy ADD COLUMN rpdescription VARCHAR2(100);
ALTER TABLE item ADD COLUMN discoverable NUMBER(1);
CREATE TABLE versionhistory
(
versionhistory_id INTEGER NOT NULL PRIMARY KEY
);
CREATE TABLE versionitem
(
versionitem_id INTEGER NOT NULL PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
version_number INTEGER,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
version_date TIMESTAMP,
version_summary VARCHAR2(255),
versionhistory_id INTEGER REFERENCES VersionHistory(versionhistory_id)
);
CREATE SEQUENCE versionitem_seq;
CREATE SEQUENCE versionhistory_seq;
-------------------------------------------
-- New columns and longer hash for salted password hashing DS-861 --
-------------------------------------------
ALTER TABLE EPerson ALTER COLUMN password VARCHAR(128);
ALTER TABLE EPerson ADD COLUMN salt VARCHAR(32);
ALTER TABLE EPerson ADD COLUMN digest_algorithm VARCHAR(16);

View File

@@ -1,781 +0,0 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
------------------------------------------------------------------
-- DSpace v4.0 H2 schema
--
-- This file is used as-is to initialize a database. Therefore,
-- table and view definitions must be ordered correctly.
--
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
CREATE SEQUENCE bitstreamformatregistry_seq;
CREATE SEQUENCE fileextension_seq;
CREATE SEQUENCE bitstream_seq;
CREATE SEQUENCE eperson_seq;
CREATE SEQUENCE epersongroup_seq START WITH 2;
-- we reserve 0 and 1
CREATE SEQUENCE item_seq;
CREATE SEQUENCE bundle_seq;
CREATE SEQUENCE item2bundle_seq;
CREATE SEQUENCE bundle2bitstream_seq;
CREATE SEQUENCE dcvalue_seq;
CREATE SEQUENCE community_seq;
CREATE SEQUENCE collection_seq;
CREATE SEQUENCE community2community_seq;
CREATE SEQUENCE community2collection_seq;
CREATE SEQUENCE collection2item_seq;
CREATE SEQUENCE resourcepolicy_seq;
CREATE SEQUENCE epersongroup2eperson_seq;
CREATE SEQUENCE handle_seq;
CREATE SEQUENCE doi_seq;
CREATE SEQUENCE workspaceitem_seq;
CREATE SEQUENCE workflowitem_seq;
CREATE SEQUENCE tasklistitem_seq;
CREATE SEQUENCE registrationdata_seq;
CREATE SEQUENCE subscription_seq;
CREATE SEQUENCE communities2item_seq;
CREATE SEQUENCE epersongroup2workspaceitem_seq;
CREATE SEQUENCE metadataschemaregistry_seq START WITH 2;
-- 1 is reserved for Dublin Core
CREATE SEQUENCE metadatafieldregistry_seq;
CREATE SEQUENCE metadatavalue_seq;
CREATE SEQUENCE group2group_seq;
CREATE SEQUENCE group2groupcache_seq;
CREATE SEQUENCE harvested_collection_seq;
CREATE SEQUENCE harvested_item_seq;
CREATE SEQUENCE versionitem_seq;
CREATE SEQUENCE versionhistory_seq;
CREATE SEQUENCE webapp_seq;
CREATE SEQUENCE requestitem_seq;
-------------------------------------------------------
-- BitstreamFormatRegistry table
-------------------------------------------------------
CREATE TABLE BitstreamFormatRegistry
(
bitstream_format_id INTEGER PRIMARY KEY,
mimetype VARCHAR2(256),
short_description VARCHAR2(128) UNIQUE,
description VARCHAR2(2000),
support_level INTEGER,
-- Identifies internal types
internal NUMBER(1)
);
-------------------------------------------------------
-- FileExtension table
-------------------------------------------------------
CREATE TABLE FileExtension
(
file_extension_id INTEGER PRIMARY KEY,
bitstream_format_id INTEGER REFERENCES BitstreamFormatRegistry(bitstream_format_id),
extension VARCHAR2(16)
);
CREATE INDEX fe_bitstream_fk_idx ON FileExtension(bitstream_format_id);
-------------------------------------------------------
-- Bitstream table
-------------------------------------------------------
CREATE TABLE Bitstream
(
bitstream_id INTEGER PRIMARY KEY,
bitstream_format_id INTEGER REFERENCES BitstreamFormatRegistry(bitstream_format_id),
name VARCHAR2(256),
size_bytes INTEGER,
checksum VARCHAR2(64),
checksum_algorithm VARCHAR2(32),
description VARCHAR2(2000),
user_format_description VARCHAR2(2000),
source VARCHAR2(256),
internal_id VARCHAR2(256),
deleted NUMBER(1),
store_number INTEGER,
sequence_id INTEGER
);
CREATE INDEX bit_bitstream_fk_idx ON Bitstream(bitstream_format_id);
-------------------------------------------------------
-- EPerson table
-------------------------------------------------------
CREATE TABLE EPerson
(
eperson_id INTEGER PRIMARY KEY,
email VARCHAR2(64) UNIQUE,
password VARCHAR2(128),
salt VARCHAR2(32),
digest_algorithm VARCHAR2(16),
firstname VARCHAR2(64),
lastname VARCHAR2(64),
can_log_in NUMBER(1),
require_certificate NUMBER(1),
self_registered NUMBER(1),
last_active TIMESTAMP,
sub_frequency INTEGER,
phone VARCHAR2(32),
netid VARCHAR2(64) UNIQUE,
language VARCHAR2(64)
);
-------------------------------------------------------
-- EPersonGroup table
-------------------------------------------------------
CREATE TABLE EPersonGroup
(
eperson_group_id INTEGER PRIMARY KEY,
name VARCHAR2(256) UNIQUE
);
------------------------------------------------------
-- Group2Group table, records group membership in other groups
------------------------------------------------------
CREATE TABLE Group2Group
(
id INTEGER PRIMARY KEY,
parent_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
child_id INTEGER REFERENCES EPersonGroup(eperson_group_id)
);
CREATE INDEX g2g_parent_fk_idx ON Group2Group(parent_id);
CREATE INDEX g2g_child_fk_idx ON Group2Group(child_id);
------------------------------------------------------
-- Group2GroupCache table, is the 'unwound' hierarchy in
-- Group2Group. It explicitly names every parent child
-- relationship, even with nested groups. For example,
-- If Group2Group lists B is a child of A and C is a child of B,
-- this table will have entries for parent(A,B), and parent(B,C)
-- AND parent(A,C) so that all of the child groups of A can be
-- looked up in a single simple query
------------------------------------------------------
CREATE TABLE Group2GroupCache
(
id INTEGER PRIMARY KEY,
parent_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
child_id INTEGER REFERENCES EPersonGroup(eperson_group_id)
);
CREATE INDEX g2gc_parent_fk_idx ON Group2GroupCache(parent_id);
CREATE INDEX g2gc_child_fk_idx ON Group2GroupCache(child_id);
-------------------------------------------------------
-- Item table
-------------------------------------------------------
CREATE TABLE Item
(
item_id INTEGER PRIMARY KEY,
submitter_id INTEGER REFERENCES EPerson(eperson_id),
in_archive NUMBER(1),
withdrawn NUMBER(1),
discoverable NUMBER(1),
last_modified TIMESTAMP,
owning_collection INTEGER
);
CREATE INDEX item_submitter_fk_idx ON Item(submitter_id);
-------------------------------------------------------
-- Bundle table
-------------------------------------------------------
CREATE TABLE Bundle
(
bundle_id INTEGER PRIMARY KEY,
name VARCHAR2(16), -- ORIGINAL | THUMBNAIL | TEXT
primary_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id)
);
CREATE INDEX bundle_primary_fk_idx ON Bundle(primary_bitstream_id);
-------------------------------------------------------
-- Item2Bundle table
-------------------------------------------------------
CREATE TABLE Item2Bundle
(
id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
bundle_id INTEGER REFERENCES Bundle(bundle_id)
);
-- index by item_id
CREATE INDEX item2bundle_item_idx on Item2Bundle(item_id);
CREATE INDEX item2bundle_bundle_fk_idx ON Item2Bundle(bundle_id);
-------------------------------------------------------
-- Bundle2Bitstream table
-------------------------------------------------------
CREATE TABLE Bundle2Bitstream
(
id INTEGER PRIMARY KEY,
bundle_id INTEGER REFERENCES Bundle(bundle_id),
bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
bitstream_order INTEGER
);
-- index by bundle_id
CREATE INDEX bundle2bitstream_bundle_idx ON Bundle2Bitstream(bundle_id);
CREATE INDEX bundle2bits_bitstream_fk_idx ON Bundle2Bitstream(bitstream_id);
-------------------------------------------------------
-- Metadata Tables and Sequences
-------------------------------------------------------
CREATE TABLE MetadataSchemaRegistry
(
metadata_schema_id INTEGER PRIMARY KEY,
namespace VARCHAR(256) UNIQUE,
short_id VARCHAR(32) UNIQUE
);
CREATE TABLE MetadataFieldRegistry
(
metadata_field_id INTEGER PRIMARY KEY,
metadata_schema_id INTEGER NOT NULL REFERENCES MetadataSchemaRegistry(metadata_schema_id),
element VARCHAR(64),
qualifier VARCHAR(64),
scope_note VARCHAR2(2000)
);
CREATE TABLE MetadataValue
(
metadata_value_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
metadata_field_id INTEGER REFERENCES MetadataFieldRegistry(metadata_field_id),
text_value CLOB,
text_lang VARCHAR(24),
place INTEGER,
authority VARCHAR(100),
confidence INTEGER DEFAULT -1
);
-- Create the DC schema
INSERT INTO MetadataSchemaRegistry VALUES (1,'http://dublincore.org/documents/dcmi-terms/','dc');
-- Create a dcvalue view for backwards compatibilty
CREATE VIEW dcvalue AS
SELECT MetadataValue.metadata_value_id AS "dc_value_id", MetadataValue.item_id,
MetadataValue.metadata_field_id AS "dc_type_id", MetadataValue.text_value,
MetadataValue.text_lang, MetadataValue.place
FROM MetadataValue, MetadataFieldRegistry
WHERE MetadataValue.metadata_field_id = MetadataFieldRegistry.metadata_field_id
AND MetadataFieldRegistry.metadata_schema_id = 1;
-- An index for item_id - almost all access is based on
-- instantiating the item object, which grabs all values
-- related to that item
CREATE INDEX metadatavalue_item_idx ON MetadataValue(item_id);
CREATE INDEX metadatavalue_item_idx2 ON MetadataValue(item_id,metadata_field_id);
CREATE INDEX metadatavalue_field_fk_idx ON MetadataValue(metadata_field_id);
CREATE INDEX metadatafield_schema_idx ON MetadataFieldRegistry(metadata_schema_id);
-------------------------------------------------------
-- Community table
-------------------------------------------------------
CREATE TABLE Community
(
community_id INTEGER PRIMARY KEY,
name VARCHAR2(128),
short_description VARCHAR2(512),
introductory_text CLOB,
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
copyright_text CLOB,
side_bar_text VARCHAR2(2000),
admin INTEGER REFERENCES EPersonGroup( eperson_group_id )
);
CREATE INDEX community_logo_fk_idx ON Community(logo_bitstream_id);
CREATE INDEX community_admin_fk_idx ON Community(admin);
-------------------------------------------------------
-- Collection table
-------------------------------------------------------
CREATE TABLE Collection
(
collection_id INTEGER PRIMARY KEY,
name VARCHAR2(128),
short_description VARCHAR2(512),
introductory_text CLOB,
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
template_item_id INTEGER REFERENCES Item(item_id),
provenance_description VARCHAR2(2000),
license CLOB,
copyright_text CLOB,
side_bar_text VARCHAR2(2000),
workflow_step_1 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
workflow_step_2 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
workflow_step_3 INTEGER REFERENCES EPersonGroup( eperson_group_id ),
submitter INTEGER REFERENCES EPersonGroup( eperson_group_id ),
admin INTEGER REFERENCES EPersonGroup( eperson_group_id )
);
CREATE INDEX collection_logo_fk_idx ON Collection(logo_bitstream_id);
CREATE INDEX collection_template_fk_idx ON Collection(template_item_id);
CREATE INDEX collection_workflow1_fk_idx ON Collection(workflow_step_1);
CREATE INDEX collection_workflow2_fk_idx ON Collection(workflow_step_2);
CREATE INDEX collection_workflow3_fk_idx ON Collection(workflow_step_3);
CREATE INDEX collection_submitter_fk_idx ON Collection(submitter);
CREATE INDEX collection_admin_fk_idx ON Collection(admin);
-------------------------------------------------------
-- Community2Community table
-------------------------------------------------------
CREATE TABLE Community2Community
(
id INTEGER PRIMARY KEY,
parent_comm_id INTEGER REFERENCES Community(community_id),
child_comm_id INTEGER,
CONSTRAINT com2com_child_fk FOREIGN KEY (child_comm_id) REFERENCES Community(community_id) DEFERRABLE
);
CREATE INDEX com2com_parent_fk_idx ON Community2Community(parent_comm_id);
CREATE INDEX com2com_child_fk_idx ON Community2Community(child_comm_id);
-------------------------------------------------------
-- Community2Collection table
-------------------------------------------------------
CREATE TABLE Community2Collection
(
id INTEGER PRIMARY KEY,
community_id INTEGER REFERENCES Community(community_id),
collection_id INTEGER,
CONSTRAINT comm2coll_collection_fk FOREIGN KEY (collection_id) REFERENCES Collection(collection_id) DEFERRABLE
);
-- Improve mapping tables
CREATE INDEX Comm2Coll_community_id_idx ON Community2Collection(community_id);
CREATE INDEX Comm2Coll_collection_id_idx ON Community2Collection(collection_id);
-------------------------------------------------------
-- Collection2Item table
-------------------------------------------------------
CREATE TABLE Collection2Item
(
id INTEGER PRIMARY KEY,
collection_id INTEGER REFERENCES Collection(collection_id),
item_id INTEGER,
CONSTRAINT coll2item_item_fk FOREIGN KEY (item_id) REFERENCES Item(item_id) DEFERRABLE
);
-- index by collection_id
CREATE INDEX collection2item_collection_idx ON Collection2Item(collection_id);
-- Improve mapping tables
CREATE INDEX Collection2Item_item_id_idx ON Collection2Item( item_id );
-------------------------------------------------------
-- ResourcePolicy table
-------------------------------------------------------
CREATE TABLE ResourcePolicy
(
policy_id INTEGER PRIMARY KEY,
resource_type_id INTEGER,
resource_id INTEGER,
action_id INTEGER,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
epersongroup_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
start_date DATE,
end_date DATE,
rpname VARCHAR2(30),
rptype VARCHAR2(30),
rpdescription VARCHAR2(100)
);
-- index by resource_type,resource_id - all queries by
-- authorization manager are select type=x, id=y, action=z
CREATE INDEX resourcepolicy_type_id_idx ON ResourcePolicy(resource_type_id,resource_id);
CREATE INDEX rp_eperson_fk_idx ON ResourcePolicy(eperson_id);
CREATE INDEX rp_epersongroup_fk_idx ON ResourcePolicy(epersongroup_id);
-------------------------------------------------------
-- EPersonGroup2EPerson table
-------------------------------------------------------
CREATE TABLE EPersonGroup2EPerson
(
id INTEGER PRIMARY KEY,
eperson_group_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
eperson_id INTEGER REFERENCES EPerson(eperson_id)
);
-- Index by group ID (used heavily by AuthorizeManager)
CREATE INDEX epersongroup2eperson_group_idx on EPersonGroup2EPerson(eperson_group_id);
CREATE INDEX epg2ep_eperson_fk_idx ON EPersonGroup2EPerson(eperson_id);
-------------------------------------------------------
-- Handle table
-------------------------------------------------------
CREATE TABLE Handle
(
handle_id INTEGER PRIMARY KEY,
handle VARCHAR2(256) UNIQUE,
resource_type_id INTEGER,
resource_id INTEGER
);
-- index by resource id and resource type id
CREATE INDEX handle_resource_id_type_idx ON handle(resource_id, resource_type_id);
-------------------------------------------------------
-- Doi table
-------------------------------------------------------
CREATE TABLE Doi
(
doi_id INTEGER PRIMARY KEY,
doi VARCHAR2(256) UNIQUE,
resource_type_id INTEGER,
resource_id INTEGER,
status INTEGER
);
-- index by resource id and resource type id
CREATE INDEX doi_resource_id_type_idx ON doi(resource_id, resource_type_id);
-------------------------------------------------------
-- WorkspaceItem table
-------------------------------------------------------
CREATE TABLE WorkspaceItem
(
workspace_item_id INTEGER PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
collection_id INTEGER REFERENCES Collection(collection_id),
-- Answers to questions on first page of submit UI
multiple_titles NUMBER(1), -- boolean
published_before NUMBER(1),
multiple_files NUMBER(1),
-- How for the user has got in the submit process
stage_reached INTEGER,
page_reached INTEGER
);
CREATE INDEX workspace_item_fk_idx ON WorkspaceItem(item_id);
CREATE INDEX workspace_coll_fk_idx ON WorkspaceItem(collection_id);
-------------------------------------------------------
-- WorkflowItem table
-------------------------------------------------------
CREATE TABLE WorkflowItem
(
workflow_id INTEGER PRIMARY KEY,
item_id INTEGER UNIQUE REFERENCES Item(item_id),
collection_id INTEGER REFERENCES Collection(collection_id),
state INTEGER,
owner INTEGER REFERENCES EPerson(eperson_id),
-- Answers to questions on first page of submit UI
multiple_titles NUMBER(1),
published_before NUMBER(1),
multiple_files NUMBER(1)
-- Note: stage reached not applicable here - people involved in workflow
-- can always jump around submission UI
);
CREATE INDEX workflow_coll_fk_idx ON WorkflowItem(collection_id);
CREATE INDEX workflow_owner_fk_idx ON WorkflowItem(owner);
-------------------------------------------------------
-- TasklistItem table
-------------------------------------------------------
CREATE TABLE TasklistItem
(
tasklist_id INTEGER PRIMARY KEY,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
workflow_id INTEGER REFERENCES WorkflowItem(workflow_id)
);
CREATE INDEX tasklist_eperson_fk_idx ON TasklistItem(eperson_id);
CREATE INDEX tasklist_workflow_fk_idx ON TasklistItem(workflow_id);
-------------------------------------------------------
-- RegistrationData table
-------------------------------------------------------
CREATE TABLE RegistrationData
(
registrationdata_id INTEGER PRIMARY KEY,
email VARCHAR2(64) UNIQUE,
token VARCHAR2(48),
expires TIMESTAMP
);
-------------------------------------------------------
-- Subscription table
-------------------------------------------------------
CREATE TABLE Subscription
(
subscription_id INTEGER PRIMARY KEY,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
collection_id INTEGER REFERENCES Collection(collection_id)
);
CREATE INDEX subs_eperson_fk_idx ON Subscription(eperson_id);
CREATE INDEX subs_collection_fk_idx ON Subscription(collection_id);
-------------------------------------------------------------------------------
-- EPersonGroup2WorkspaceItem table
-------------------------------------------------------------------------------
CREATE TABLE EPersonGroup2WorkspaceItem
(
id INTEGER PRIMARY KEY,
eperson_group_id INTEGER REFERENCES EPersonGroup(eperson_group_id),
workspace_item_id INTEGER REFERENCES WorkspaceItem(workspace_item_id)
);
CREATE INDEX epg2wi_group_fk_idx ON epersongroup2workspaceitem(eperson_group_id);
CREATE INDEX epg2wi_workspace_fk_idx ON epersongroup2workspaceitem(workspace_item_id);
-------------------------------------------------------
-- Communities2Item table
-------------------------------------------------------
CREATE TABLE Communities2Item
(
id INTEGER PRIMARY KEY,
community_id INTEGER REFERENCES Community(community_id),
item_id INTEGER REFERENCES Item(item_id)
);
-- Indexing browse tables update/re-index performance
CREATE INDEX Communities2Item_item_id_idx ON Communities2Item( item_id );
CREATE INDEX Comm2Item_community_fk_idx ON Communities2Item( community_id );
-------------------------------------------------------
-- Community2Item view
------------------------------------------------------
CREATE VIEW Community2Item as
SELECT Community2Collection.community_id, Collection2Item.item_id
FROM Community2Collection, Collection2Item
WHERE Collection2Item.collection_id = Community2Collection.collection_id
;
-------------------------------------------------------------------------
-- Tables to manage cache of item counts for communities and collections
-------------------------------------------------------------------------
CREATE TABLE collection_item_count (
collection_id INTEGER PRIMARY KEY REFERENCES collection(collection_id),
count INTEGER
);
CREATE TABLE community_item_count (
community_id INTEGER PRIMARY KEY REFERENCES community(community_id),
count INTEGER
);
-------------------------------------------------------
-- Create 'special' groups, for anonymous access
-- and administrators
-------------------------------------------------------
-- We don't use getnextid() for 'anonymous' since the sequences start at '1'
INSERT INTO epersongroup VALUES(0, 'Anonymous');
INSERT INTO epersongroup VALUES(1, 'Administrator');
-------------------------------------------------------
-- Create the checksum checker tables
-------------------------------------------------------
-- list of the possible results as determined
-- by the system or an administrator
CREATE TABLE checksum_results
(
result_code VARCHAR(64) PRIMARY KEY,
result_description VARCHAR2(2000)
);
-- This table has a one-to-one relationship
-- with the bitstream table. A row will be inserted
-- every time a row is inserted into the bitstream table, and
-- that row will be updated every time the checksum is
-- re-calculated.
CREATE TABLE most_recent_checksum
(
bitstream_id INTEGER PRIMARY KEY REFERENCES bitstream(bitstream_id),
to_be_processed NUMBER(1) NOT NULL,
expected_checksum VARCHAR(64),
current_checksum VARCHAR(64),
last_process_start_date TIMESTAMP NOT NULL,
last_process_end_date TIMESTAMP NOT NULL,
checksum_algorithm VARCHAR(64) NOT NULL,
matched_prev_checksum NUMBER(1) NOT NULL,
result VARCHAR(64) REFERENCES checksum_results(result_code)
);
CREATE INDEX mrc_result_fk_idx ON most_recent_checksum( result );
-- A row will be inserted into this table every
-- time a checksum is re-calculated.
CREATE SEQUENCE checksum_history_seq;
CREATE TABLE checksum_history
(
check_id INTEGER PRIMARY KEY,
bitstream_id INTEGER,
process_start_date TIMESTAMP,
process_end_date TIMESTAMP,
checksum_expected VARCHAR(64),
checksum_calculated VARCHAR(64),
result VARCHAR(64) REFERENCES checksum_results(result_code)
);
CREATE INDEX ch_result_fk_idx ON checksum_history( result );
-- this will insert into the result code
-- the initial results that should be
-- possible
insert into checksum_results
values
(
'INVALID_HISTORY',
'Install of the cheksum checking code do not consider this history as valid'
);
insert into checksum_results
values
(
'BITSTREAM_NOT_FOUND',
'The bitstream could not be found'
);
insert into checksum_results
values
(
'CHECKSUM_MATCH',
'Current checksum matched previous checksum'
);
insert into checksum_results
values
(
'CHECKSUM_NO_MATCH',
'Current checksum does not match previous checksum'
);
insert into checksum_results
values
(
'CHECKSUM_PREV_NOT_FOUND',
'Previous checksum was not found: no comparison possible'
);
insert into checksum_results
values
(
'BITSTREAM_INFO_NOT_FOUND',
'Bitstream info not found'
);
insert into checksum_results
values
(
'CHECKSUM_ALGORITHM_INVALID',
'Invalid checksum algorithm'
);
insert into checksum_results
values
(
'BITSTREAM_NOT_PROCESSED',
'Bitstream marked to_be_processed=false'
);
insert into checksum_results
values
(
'BITSTREAM_MARKED_DELETED',
'Bitstream marked deleted in bitstream table'
);
-------------------------------------------------------
-- Create the harvest settings table
-------------------------------------------------------
-- Values used by the OAIHarvester to harvest a collection
-- HarvestInstance is the DAO class for this table
CREATE TABLE harvested_collection
(
collection_id INTEGER REFERENCES collection(collection_id) ON DELETE CASCADE,
harvest_type INTEGER,
oai_source VARCHAR(256),
oai_set_id VARCHAR(256),
harvest_message VARCHAR2(512),
metadata_config_id VARCHAR(256),
harvest_status INTEGER,
harvest_start_time TIMESTAMP,
last_harvested TIMESTAMP,
id INTEGER PRIMARY KEY
);
CREATE INDEX harvested_collection_fk_idx ON harvested_collection(collection_id);
CREATE TABLE harvested_item
(
item_id INTEGER REFERENCES item(item_id) ON DELETE CASCADE,
last_harvested TIMESTAMP,
oai_id VARCHAR(64),
id INTEGER PRIMARY KEY
);
CREATE INDEX harvested_item_fk_idx ON harvested_item(item_id);
CREATE TABLE versionhistory
(
versionhistory_id INTEGER NOT NULL PRIMARY KEY
);
CREATE TABLE versionitem
(
versionitem_id INTEGER NOT NULL PRIMARY KEY,
item_id INTEGER REFERENCES Item(item_id),
version_number INTEGER,
eperson_id INTEGER REFERENCES EPerson(eperson_id),
version_date TIMESTAMP,
version_summary VARCHAR2(255),
versionhistory_id INTEGER REFERENCES VersionHistory(versionhistory_id)
);
CREATE TABLE Webapp
(
webapp_id INTEGER NOT NULL PRIMARY KEY,
AppName VARCHAR2(32),
URL VARCHAR2(1000),
Started TIMESTAMP,
isUI NUMBER(1)
);
CREATE TABLE requestitem
(
requestitem_id INTEGER NOT NULL,
token varchar(48),
item_id INTEGER,
bitstream_id INTEGER,
allfiles NUMBER(1),
request_email VARCHAR2(64),
request_name VARCHAR2(64),
request_date TIMESTAMP,
accept_request NUMBER(1),
decision_date TIMESTAMP,
expires TIMESTAMP,
CONSTRAINT requestitem_pkey PRIMARY KEY (requestitem_id),
CONSTRAINT requestitem_token_key UNIQUE (token)
);

View File

@@ -0,0 +1,86 @@
-- The contents of this file are subject to the license and copyright
-- detailed in the LICENSE and NOTICE files at the root of the source
-- tree and available online at
--
-- http://www.dspace.org/license/
-- ===============================================================
-- WARNING WARNING WARNING WARNING WARNING WARNING WARNING WARNING
--
-- DO NOT MANUALLY RUN THIS DATABASE MIGRATION. IT WILL BE EXECUTED
-- AUTOMATICALLY (IF NEEDED) BY "FLYWAY" WHEN YOU STARTUP DSPACE.
-- http://flywaydb.org/
-- ===============================================================
-------------------------------------------
-- Ensure that discoverable has a sensible default
-------------------------------------------
update item set discoverable=1 WHERE discoverable IS NULL;
-------------------------------------------
-- Add support for DOIs (table and seq.) --
-------------------------------------------
CREATE TABLE Doi
(
doi_id INTEGER PRIMARY KEY,
doi VARCHAR2(256) UNIQUE,
resource_type_id INTEGER,
resource_id INTEGER,
status INTEGER
);
CREATE SEQUENCE doi_seq;
-- index by resource id and resource type id
CREATE INDEX doi_resource_id_type_idx ON doi(resource_id, resource_type_id);
-------------------------------------------
-- Table of running web applications for 'dspace version' --
-------------------------------------------
CREATE TABLE Webapp
(
webapp_id INTEGER NOT NULL PRIMARY KEY,
AppName VARCHAR2(32),
URL VARCHAR2(1000),
Started TIMESTAMP,
isUI NUMBER(1)
);
CREATE SEQUENCE webapp_seq;
-------------------------------------------------------
-- DS-824 RequestItem table
-------------------------------------------------------
CREATE TABLE requestitem
(
requestitem_id INTEGER NOT NULL,
token varchar(48),
item_id INTEGER,
bitstream_id INTEGER,
allfiles NUMBER(1),
request_email VARCHAR2(64),
request_name VARCHAR2(64),
request_date TIMESTAMP,
accept_request NUMBER(1),
decision_date TIMESTAMP,
expires TIMESTAMP,
CONSTRAINT requestitem_pkey PRIMARY KEY (requestitem_id),
CONSTRAINT requestitem_token_key UNIQUE (token)
);
CREATE SEQUENCE requestitem_seq;
-------------------------------------------------------
-- DS-1655 Disable "Initial Questions" page in Submission UI by default
-------------------------------------------------------
update workspaceitem set multiple_titles=1, published_before=1, multiple_files=1;
update workflowitem set multiple_titles=1, published_before=1, multiple_files=1;
-------------------------------------------------------
-- DS-1811 Removing a collection fails if non-Solr DAO has been used before for item count
-------------------------------------------------------
delete from collection_item_count;
delete from community_item_count;