Oracle port. These files are meant to be copied to the parent directory

dspace/etc to overwrite the originals for the Oracle port to work.
The must be kept up to date with any schema changes!


git-svn-id: http://scm.dspace.org/svn/repo/trunk@1060 9c30dcfa-912a-0410-8fc2-9e0234be79fd
This commit is contained in:
David Stuve
2004-09-13 04:36:42 +00:00
parent d4a4657dd5
commit c13f24e570
4 changed files with 821 additions and 0 deletions

View File

@@ -0,0 +1,107 @@
DSpace on Oracle
Revision: 11-sep-04 dstuve
1 Introduction
2 Installing DSpace on Oracle
3 Porting notes for the curious
DSpace is now tested to work with Oracle 10x, and should work with
version 9 as well. The installation process is quite simple, involving
changinge a few configuration settings in dspace.cfg, and replacing a few
Postgres-specific sql files in etc/ with Oracle-specific ones. Everything
is fully functional, although Oracle limits you to 4k of text in text fields
such as item metadata or collection descriptions.
For people interested in switching from Postgres to Oracle, I know of
no tools that would do this automatically. You will need to recreate the
community, collection, and eperson structure in the Oracle system, and then
use the item export and import tools to move your content over.
How to Install DSpace on Oracle
Things you need
Oracle 9 or 10
Oracle JDBC driver
sequence update script from Akadia consulting:
currently incseq.sql at: http://akadia.com/services/scripts/incseq.sql
(put in your dspace source /etc directory)
Installation procedure
1. Create adatabase for DSpace. Make sure that the character set is one
of the Unicode character sets. DSpace uses UTF8 natively, and I would
suggest that the Oracle database use the same character set. Create
a user account for DSpace (we use 'dspace',) and ensure that it has
permissions to add and remove tables in the database.
2. Edit the config/dspace.cfg file in your source directory for the
following settings:
db.name = oracle
db.url = jdbc.oracle.thin:@//host:port/dspace
db.driver = oracle.jdbc.OracleDriver
3. Go to etc/oracle in your source directory and copy the contents
to their parent directory, overwriting the versions in the parent:
cd dspace_source/etc/oracle
cp * ..
You now have Oracle-specific .sql files in your etc directory, and
your dspace.cfg is modified to point to your Oracle database and
are ready to continue with a normal DSpace install, skipping the
Postgres setup steps.
NOTE**** DSpace uses sequences to generate unique object IDs - beware
Oracle sequences, which are said to lose their values when doing
a database export/import, say restoring from a backup. Be sure
to run the script etc/udpate-sequences.sql.
Oracle Porting Notes for the Curious
Oracle is missing quite a number of cool features found in Postgres, so
workarounds had to be found, most of which are hidden behind tests of
the db.name configuration parameter in dspace.cfg. If the db.name is
set to Oracle the workarounds are activated:
Oracle doesn't like ';' characters in JDBC SQL - they have all been removed
from the DSpace source, including code in the .sql file reader to strip ;'s.
browse code - LIMIT and OFFSET is used to limit browse results, and an
Oracle-hack is used to limit the result set to a given size
Oracle has no boolean data type, so a new schema file was created that
uses INTEGERs and code is inserted everywhere to use 0 for false
and 1 for true if the db.name is Oracle
Oracle doesn't have a TEXT data type either, so TEXT columns are defined
as VARCHAR2 in the Oracle-specific schema.
Oracle doesn't allow dynamic naming for objects, so our cute trick to
derive the name of the sequence by appending _seq to the table name
in a function doesn't work in Oracle - workaround is to insert Oracle
code to generate the name of the sequence and then place that into
our SQL calls to generate a new ID.
Oracle doesn't let you directly set the value of sequences, so
update-sequences.sql is forced to use a special script sequpdate.sql
to update the sequences.
Bitstream had a column 'size' which is a reserved word in Oracle,
so this had to be changed to 'size_bytes' with corresponding code changes.
VARCHAR2 has a limit of 4000 characters, so DSpace text data is limited to 4k.
Going to the CLOB data type can get around that, but seemed like too much effort
for now. Note that with UTF-8 encoding that 4k could translate to 1300
characters worst-case (every character taking up 3 bytes is the worst case
scenario.)
DatabaseManager had to have some of the type checking changed, because Oracle's
JDBC driver is reporting INTEGERS as type DECIMAL.
Oracle doesn't like it when you reference table names in lower case when
getting JDBC metadata for the tables, so they are converted in TableRow
to upper case.

View File

@@ -0,0 +1,588 @@
--
-- database_schema.sql (ORACLE version!)
--
-- Version: $Revision$
--
-- Date: $Date$
--
-- Copyright (c) 2002, Hewlett-Packard Company and Massachusetts
-- Institute of Technology. All rights reserved.
--
-- Redistribution and use in source and binary forms, with or without
-- modification, are permitted provided that the following conditions are
-- met:
--
-- - Redistributions of source code must retain the above copyright
-- notice, this list of conditions and the following disclaimer.
--
-- - Redistributions in binary form must reproduce the above copyright
-- notice, this list of conditions and the following disclaimer in the
-- documentation and/or other materials provided with the distribution.
--
-- - Neither the name of the Hewlett-Packard Company nor the name of the
-- Massachusetts Institute of Technology nor the names of their
-- contributors may be used to endorse or promote products derived from
-- this software without specific prior written permission.
--
-- THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
-- ``AS IS'' AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
-- LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
-- A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT
-- HOLDERS OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT,
-- INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING,
-- BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS
-- OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND
-- ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR
-- TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE
-- USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH
-- DAMAGE.
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 REFERENCES Item(item_id) UNIQUE,
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,90 @@
--
-- update-sequences.sql
--
-- Version: $Revision$
--
-- Date: $Date$
--
-- Copyright (c) 2002, Hewlett-Packard Company and Massachusetts
-- Institute of Technology. All rights reserved.
--
-- Redistribution and use in source and binary forms, with or without
-- modification, are permitted provided that the following conditions are
-- met:
--
-- - Redistributions of source code must retain the above copyright
-- notice, this list of conditions and the following disclaimer.
--
-- - Redistributions in binary form must reproduce the above copyright
-- notice, this list of conditions and the following disclaimer in the
-- documentation and/or other materials provided with the distribution.
--
-- - Neither the name of the Hewlett-Packard Company nor the name of the
-- Massachusetts Institute of Technology nor the names of their
-- contributors may be used to endorse or promote products derived from
-- this software without specific prior written permission.
--
-- THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
-- ``AS IS'' AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
-- LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
-- A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT
-- HOLDERS OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT,
-- INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING,
-- BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS
-- OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND
-- ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR
-- TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE
-- USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH
-- DAMAGE.
-- SQL code to update the ID (primary key) generating sequences, if some
-- import operation has set explicit IDs.
--
-- Sequences are used to generate IDs for new rows in the database. If a
-- bulk import operation, such as an SQL dump, specifies primary keys for
-- imported data explicitly, the sequences are out of sync and need updating.
-- This SQL code does just that.
--
-- This should rarely be needed; any bulk import should be performed using the
-- org.dspace.content API which is safe to use concurrently and in multiple
-- JVMs. The SQL code below will typically only be required after a direct
-- SQL data dump from a backup or somesuch.
-- There should be one of these calls for every ID sequence defined in
-- database_schema.sql.
-- depends on being run from sqlplus with incseq.sql in the current path
-- you can find incseq.sql at: http://akadia.com/services/scripts/incseq.sql
@incseq.sql bitstreamformatregistry_seq bitstreamformatregistry bitstream_format_id
@incseq.sql fileextension_seq fileextension file_extension_id
@incseq.sql bitstream_seq bitstream bitstream_id
@incseq.sql eperson_seq eperson eperson_id
@incseq.sql epersongroup_seq epersongroup eperson_group_id
@incseq.sql item_seq item item_id
@incseq.sql bundle_seq bundle bundle_id
@incseq.sql item2bundle_seq item2bundle id
@incseq.sql bundle2bitstream_seq bundle2bitstream id
@incseq.sql dctyperegistry_seq dctyperegistry dc_type_id
@incseq.sql dcvalue_seq dcvalue dc_value_id
@incseq.sql community_seq community community_id
@incseq.sql community2community_seq community2community id
@incseq.sql collection_seq collection collection_id
@incseq.sql community2collection_seq community2collection id
@incseq.sql collection2item_seq collection2item id
@incseq.sql resourcepolicy_seq resourcepolicy policy_id
@incseq.sql epersongroup2eperson_seq epersongroup2eperson id
@incseq.sql handle_seq handle handle_id
@incseq.sql workspaceitem_seq workspaceitem workspace_item_id
@incseq.sql workflowitem_seq workflowitem workflow_id
@incseq.sql tasklistitem_seq tasklistitem tasklist_id
@incseq.sql registrationdata_seq registrationdata registrationdata_id
@incseq.sql subscription_seq subscription subscription_id
@incseq.sql history_seq history history_id
@incseq.sql historystate_seq historystate history_state_id
@incseq.sql communities2item_seq communities2item id
@incseq.sql itemsbyauthor_seq itemsbyauthor items_by_author_id
@incseq.sql itemsbytitle_seq itemsbytitle items_by_title_id
@incseq.sql itemsbydate_seq itemsbydate items_by_date_id
@incseq.sql itemsbydateaccessioned_seq itemsbydateaccessioned items_by_date_accessioned_id

36
dspace/etc/oracle/updateseq.sql Executable file
View File

@@ -0,0 +1,36 @@
-- #############################################################################################
--
-- %Purpose: Set a sequence to the max value of a given attribute
--
-- #############################################################################################
--
-- Paramters:
-- 1: sequence name
-- 2: table name
-- 3: attribute name
--
-- Sample usage:
-- @updateseq-oracle.sql my_sequence my_table my_attribute
--
--------------------------------------------------------------------------------
--
SET SERVEROUTPUT ON SIZE 1000000;
--
DECLARE
dummy NUMBER := 0;
curr NUMBER := 0;
BEGIN
--
--SELECT &1..nextval INTO dummy FROM dual;
--dbms_output.put('start with next value=' || dummy);
--
SELECT max(&3) INTO curr FROM &2;
DROP SEQUENCE &1;
CREATE SEQUENCE &1 START WITH curr;
--
dbms_output.put_line(', end=' || dummy);
--
END;
/