Files
DSpace/dspace/etc/database_schema.sql
Mark Diggory 78f5211cd5 Merging changes from 1.5.x to trunk for "dspace" project
r9930@mark-diggorys-computer-2 (orig r2763):  mdiggory | 2008-02-28 12:40:47 -0800
 Needs to look for SNAPSHOT version as well until released.
 r9931@mark-diggorys-computer-2 (orig r2764):  mdiggory | 2008-02-28 12:57:28 -0800
 Qualifying the location with ${basedir} assures that build will work in both top level and inside the dspace directory.
 r9932@mark-diggorys-computer-2 (orig r2765):  mdiggory | 2008-02-28 15:33:29 -0800
 Undo previous commit and adjust release management profiles.  We cannot currently build whole project from top level.
 r9968@mark-diggorys-computer-2 (orig r2772):  mdiggory | 2008-02-29 13:49:42 -0800
 fix rpoject version until release can be figured out.
 r9986@mark-diggorys-computer-2 (orig r2781):  ScottPhillips | 2008-03-03 16:46:49 -0800
 (Scott Phillips) Removed useless common problem.
 r9987@mark-diggorys-computer-2 (orig r2782):  ScottPhillips | 2008-03-03 17:41:06 -0800
 (Scott Phillips) SF#1896186 - mail.charset not documented in dspace.cfg
 r9988@mark-diggorys-computer-2 (orig r2783):  ScottPhillips | 2008-03-03 19:20:21 -0800
 (Scott Phillips) webui.content_disposition_threshold -> xmlui.content_disposition_threshold 
 r9993@mark-diggorys-computer-2 (orig r2788):  ScottPhillips | 2008-03-03 21:48:48 -0800
 (Scott Phillips) Added support for xmlui.supported.locales parameter so that an administrator can choose which languages to deploy Manakin in.
 r10033@mark-diggorys-computer-2 (orig r2791):  grahamtriggs | 2008-03-07 04:04:08 -0800
 Fix Oracle upgrade script
 r10035@mark-diggorys-computer-2 (orig r2793):  ScottPhillips | 2008-03-07 09:33:32 -0800
 (Scott Phillips) SF#1908952 - Office 2007 formats cannot be added to FormatRegistry
 r10036@mark-diggorys-computer-2 (orig r2794):  ScottPhillips | 2008-03-07 11:53:12 -0800
 (Scott Phillips) Added OpenOffice document formats to the default format registry.
 r10037@mark-diggorys-computer-2 (orig r2795):  mdiggory | 2008-03-07 15:16:10 -0800
 rename generated webapps and force assembly to use 2.2-beta-1
 r10061@mark-diggorys-computer-2 (orig r2798):  mdiggory | 2008-03-10 16:45:36 -0700
 1.) Moving language-packs to dspace-sandbox. See:  http://dspace-sandbox.googlecode.com/svn/modules/dspace-api-lang/trunk/
 2.) Adjusting dependencies and dspace-api-lang project name
 3.) Cleaning up versioning in poms, removing uneccessary dependencies and version tag
 4.) consolidating wars generated so that dspace-xxx-webapp wars are skinny by default.
 r10064@mark-diggorys-computer-2 (orig r2801):  ScottPhillips | 2008-03-10 18:59:40 -0700
 [maven-release-plugin] prepare release dspace-1.5-beta2
 r10066@mark-diggorys-computer-2 (orig r2803):  ScottPhillips | 2008-03-10 19:00:23 -0700
 [maven-release-plugin] prepare for next development iteration
 r10084@mark-diggorys-computer-2 (orig r2806):  mdiggory | 2008-03-11 08:16:09 -0700
 don't use version in war plugin.
 
 r10085@mark-diggorys-computer-2 (orig r2807):  mdiggory | 2008-03-11 08:22:24 -0700
 add trailing slashes to complete uri for webapps to be created correctly.
 r10086@mark-diggorys-computer-2 (orig r2808):  tdonohue | 2008-03-11 11:00:59 -0700
 Fix for [ SF# 1896466 ] 1.5 install breaks in Windows with spaces in path names
 
 The file path arguments in ANT should have single quotes (' ') around them, to ensure that filepaths with spaces are passed properly to the Load Registry scripts.
 r10088@mark-diggorys-computer-2 (orig r2810):  ScottPhillips | 2008-03-11 17:32:34 -0700
 (Scott Phillips) Split the update task into two: update_code and update_webapps. Also added the "-Dwars=true" switch to create war files.
 r10093@mark-diggorys-computer-2 (orig r2815):  ScottPhillips | 2008-03-11 23:01:29 -0700
 (Scott Phillips) Added shibboleth options to disable editing of metadata and registration of new users if desired.
 r10094@mark-diggorys-computer-2 (orig r2816):  ScottPhillips | 2008-03-11 23:02:28 -0700
 (Scott Phillips) Corrected target description.
 r10108@mark-diggorys-computer-2 (orig r2817):  grahamtriggs | 2008-03-12 05:08:19 -0700
 Corrections to Oracle schema
 r10111@mark-diggorys-computer-2 (orig r2820):  tdonohue | 2008-03-12 10:19:54 -0700
 Minor changes to documentation...added 'dspace-sword' to directories listing.
 r10112@mark-diggorys-computer-2 (orig r2821):  ScottPhillips | 2008-03-12 13:18:05 -0700
 (Scott Phillips) Add DRI Schema Reference to the DSpace manual
 r10113@mark-diggorys-computer-2 (orig r2822):  tdonohue | 2008-03-12 14:09:18 -0700
 Updates to the DRI Schema version 1.1 from Scott Phillips.
 r10119@mark-diggorys-computer-2 (orig r2828):  ScottPhillips | 2008-03-12 19:55:12 -0700
 (Scott Phillips) Added xmlui.user.loginredirect to determine where a user should go after logging into the system.
 r10120@mark-diggorys-computer-2 (orig r2829):  mdiggory | 2008-03-12 21:48:34 -0700
 Adjust xml declaration and include dspace-api-lang into build process if present.
 r10139@mark-diggorys-computer-2 (orig r2830):  tdonohue | 2008-03-13 08:08:06 -0700
 Cleaned up the 1.5 Windows Install instructions.  It previously contained a lot of Unix commands and Unix-specific language.
 r10140@mark-diggorys-computer-2 (orig r2831):  grahamtriggs | 2008-03-13 09:19:15 -0700
 Fixed problem with thumbnails appearing multiple times if you include multiple dates in your list columns.
 Also provides for a more attractive display, and faster table rendering.
 r10143@mark-diggorys-computer-2 (orig r2834):  tdonohue | 2008-03-13 12:15:32 -0700
 Removed references to the old 'history' directory, and the 'history.dir' param from dspace.cfg
 r10144@mark-diggorys-computer-2 (orig r2835):  tdonohue | 2008-03-13 12:18:32 -0700
 minor updates to Windows install instructions
 r10146@mark-diggorys-computer-2 (orig r2837):  tdonohue | 2008-03-13 13:57:30 -0700
 MAJOR reorg of the 'dspace.cfg' file.  Created sections to separate out "general configurations" (i.e. API-layer), XMLUI-specific, JSPUI-specific and ones that work in both those interfaces.  (Oh, and obviously a section for SWORD & OAI)
 r10147@mark-diggorys-computer-2 (orig r2838):  ScottPhillips | 2008-03-13 14:14:32 -0700
 (Scott Phillips) Recent submissions effects both interfaces.
 r10149@mark-diggorys-computer-2 (orig r2840):  ScottPhillips | 2008-03-13 15:44:19 -0700
 (Scott Phillips) Added a DTD for the xmlui.xconf
 r10150@mark-diggorys-computer-2 (orig r2841):  mdiggory | 2008-03-13 21:55:34 -0700
 correct id of snapshot repository.
 r10173@mark-diggorys-computer-2 (orig r2846):  mdiggory | 2008-03-17 14:15:17 -0700
 Adjust all modules to be under a simpler naming convention so that rebranding does not have to be of the war/webapp names themselves.
 r10174@mark-diggorys-computer-2 (orig r2847):  mdiggory | 2008-03-17 14:26:36 -0700
 Adjust all modules to be under a simpler naming convention so that rebranding does not have to be of the war/webapp names themselves.
 r10176@mark-diggorys-computer-2 (orig r2849):  ScottPhillips | 2008-03-17 22:23:13 -0700
 (Scott Phillips) Fixed a bug where the new.xml file was not being read. I changed the file to news-xmlui.xml so that it lists well with the other news files for the jspui. I also have supplied a default version of this file.
 r10193@mark-diggorys-computer-2 (orig r2855):  ScottPhillips | 2008-03-18 11:48:27 -0700
 [maven-release-plugin] prepare release dspace-1_5-rc1
 r10195@mark-diggorys-computer-2 (orig r2857):  ScottPhillips | 2008-03-18 11:51:15 -0700
 [maven-release-plugin] prepare for next development iteration
 r10223@mark-diggorys-computer-2 (orig r2863):  mdiggory | 2008-03-21 14:22:31 -0700
 Asure handle server logs to its own log and dspace is not in control of logging.
 r10227@mark-diggorys-computer-2 (orig r2865):  ScottPhillips | 2008-03-24 08:20:28 -0700
 (Scott Phillips) Added a licensing notice stating the copyright has transfered from HP+MIT to DSpace
 r10228@mark-diggorys-computer-2 (orig r2866):  ScottPhillips | 2008-03-24 08:20:57 -0700
 (Scott Phillips) Updated known bugs
 r10229@mark-diggorys-computer-2 (orig r2867):  ScottPhillips | 2008-03-24 19:25:48 -0700
 [maven-release-plugin] prepare release dspace-1_5
 r10231@mark-diggorys-computer-2 (orig r2869):  ScottPhillips | 2008-03-24 19:26:55 -0700
 [maven-release-plugin] prepare for next development iteration
 r10240@mark-diggorys-computer-2 (orig r2871):  mdiggory | 2008-03-28 07:13:29 -0700
 Correct issue with libraries being excluded
 r10296@mark-diggorys-computer-2 (orig r2895):  ScottPhillips | 2008-04-14 10:58:15 -0700
 (Scott Phillips) Added the ability for super admins to login as other users. This is controled by the parameter xmlui.user.assumelogin, default value is false.
 r10297@mark-diggorys-computer-2 (orig r2896):  ScottPhillips | 2008-04-14 11:37:31 -0700
 (Scott Phillips) Added easy support for google analytics statistics, if you want to use analytics simple provide your key in the parameter "xmlui.google.analytics.key".
 r10298@mark-diggorys-computer-2 (orig r2897):  ScottPhillips | 2008-04-14 21:14:43 -0700
 (Scott Phillips) Added an activity viewer to the Control Panel showing the current user activity on the repository.


git-svn-id: http://scm.dspace.org/svn/repo/trunk@2903 9c30dcfa-912a-0410-8fc2-9e0234be79fd
2008-04-15 23:57:13 +00:00

786 lines
26 KiB
SQL

--
-- database_schema.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.
--
--
--
--
-- DSpace SQL schema
--
-- Authors: Peter Breton, Robert Tansley, David Stuve, Daniel Chudnov,
-- Richard Jones
--
-- This file is used as-is to initialize a database. Therefore,
-- table and view definitions must be ordered correctly.
--
-- Caution: THIS IS POSTGRESQL-SPECIFIC:
--
-- * SEQUENCES are used for automatic ID generation
-- * FUNCTION getnextid used for automatic ID generation
--
--
-- To convert to work with another database, you need to ensure
-- an SQL function 'getnextid', which takes a table name as an
-- argument, will return a safe new ID to use to create a new
-- row in that table.
-------------------------------------------------------
-- Function for obtaining new IDs.
--
-- * The argument is a table name
-- * It returns a new ID safe to use for that table
--
-- The function reads the next value from the sequence
-- 'tablename_seq'
-------------------------------------------------------
CREATE FUNCTION getnextid(VARCHAR(40)) RETURNS INTEGER AS
'SELECT CAST (nextval($1 || ''_seq'') AS INTEGER) AS RESULT;' LANGUAGE SQL;
-------------------------------------------------------
-- Sequences for creating new IDs (primary keys) for
-- tables. Each table must have a corresponding
-- sequence called 'tablename_seq'.
-------------------------------------------------------
CREATE SEQUENCE bitstreamformatregistry_seq;
CREATE SEQUENCE fileextension_seq;
CREATE SEQUENCE bitstream_seq;
CREATE SEQUENCE eperson_seq;
CREATE SEQUENCE epersongroup_seq;
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 epersongroup2workspaceitem_seq;
CREATE SEQUENCE metadataschemaregistry_seq;
CREATE SEQUENCE metadatafieldregistry_seq;
CREATE SEQUENCE metadatavalue_seq;
CREATE SEQUENCE group2group_seq;
CREATE SEQUENCE group2groupcache_seq;
-------------------------------------------------------
-- BitstreamFormatRegistry table
-------------------------------------------------------
CREATE TABLE BitstreamFormatRegistry
(
bitstream_format_id INTEGER PRIMARY KEY,
mimetype VARCHAR(256),
short_description VARCHAR(128) UNIQUE,
description TEXT,
support_level INTEGER,
-- Identifies internal types
internal BOOL,
uuid VARCHAR(36)
);
-------------------------------------------------------
-- FileExtension table
-------------------------------------------------------
CREATE TABLE FileExtension
(
file_extension_id INTEGER PRIMARY KEY,
bitstream_format_id INTEGER REFERENCES BitstreamFormatRegistry(bitstream_format_id),
extension VARCHAR(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 VARCHAR(256),
size_bytes BIGINT,
checksum VARCHAR(64),
checksum_algorithm VARCHAR(32),
description TEXT,
user_format_description TEXT,
source VARCHAR(256),
internal_id VARCHAR(256),
deleted BOOL,
store_number INTEGER,
sequence_id INTEGER,
uuid VARCHAR(36)
);
CREATE INDEX bit_bitstream_fk_idx ON Bitstream(bitstream_format_id);
-------------------------------------------------------
-- EPerson table
-------------------------------------------------------
CREATE TABLE EPerson
(
eperson_id INTEGER PRIMARY KEY,
email VARCHAR(64) UNIQUE,
password VARCHAR(64),
firstname VARCHAR(64),
lastname VARCHAR(64),
can_log_in BOOL,
require_certificate BOOL,
self_registered BOOL,
last_active TIMESTAMP,
sub_frequency INTEGER,
phone VARCHAR(32),
netid VARCHAR(64),
language VARCHAR(64),
uuid VARCHAR(36)
);
-- index by email
CREATE INDEX eperson_email_idx ON EPerson(email);
-- index by netid
CREATE INDEX eperson_netid_idx ON EPerson(netid);
-------------------------------------------------------
-- EPersonGroup table
-------------------------------------------------------
CREATE TABLE EPersonGroup
(
eperson_group_id INTEGER PRIMARY KEY,
name VARCHAR(256) UNIQUE,
uuid VARCHAR(36)
);
------------------------------------------------------
-- 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 Group2Group(parent_id);
CREATE INDEX g2gc_child_fk_idx ON Group2Group(child_id);
-------------------------------------------------------
-- Item table
-------------------------------------------------------
CREATE TABLE Item
(
item_id INTEGER PRIMARY KEY,
submitter_id INTEGER REFERENCES EPerson(eperson_id),
in_archive BOOL,
withdrawn BOOL,
last_modified TIMESTAMP WITH TIME ZONE,
owning_collection INTEGER,
uuid VARCHAR(36)
);
CREATE INDEX item_submitter_fk_idx ON Item(submitter_id);
-------------------------------------------------------
-- Bundle table
-------------------------------------------------------
CREATE TABLE Bundle
(
bundle_id INTEGER PRIMARY KEY,
name VARCHAR(16), -- ORIGINAL | THUMBNAIL | TEXT
primary_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
uuid VARCHAR(36)
);
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)
);
-- index by bundle_id
CREATE INDEX bundle2bitstream_bundle_idx ON Bundle2Bitstream(bundle_id);
CREATE INDEX bundle2bitstream_bitstream_fk_idx ON Bundle2Bitstream(bitstream_id);
-------------------------------------------------------
-- Metadata Tables and Sequences
-------------------------------------------------------
CREATE TABLE MetadataSchemaRegistry
(
metadata_schema_id INTEGER PRIMARY KEY DEFAULT NEXTVAL('metadataschemaregistry_seq'),
namespace VARCHAR(256) UNIQUE,
short_id VARCHAR(32) UNIQUE,
uuid VARCHAR(36)
);
CREATE TABLE MetadataFieldRegistry
(
metadata_field_id INTEGER PRIMARY KEY DEFAULT NEXTVAL('metadatafieldregistry_seq'),
-- metadata_schema_id INTEGER NOT NULL REFERENCES MetadataSchemaRegistry(metadata_schema_id),
metadata_schema_id INTEGER REFERENCES MetadataSchemaRegistry(metadata_schema_id),
element VARCHAR(64),
qualifier VARCHAR(64),
scope_note TEXT,
uuid VARCHAR(36)
);
-- FIXME: Sort this out before the 1.6 release.
-- This is necessary because of the way in which entries in the field registry
-- are created. Eventually, it should be possible to re-introduce this
-- constraint.
ALTER TABLE metadatafieldregistry ALTER COLUMN metadata_schema_id DROP NOT NULL;
CREATE TABLE MetadataValue
(
metadata_value_id INTEGER PRIMARY KEY DEFAULT NEXTVAL('metadatavalue_seq'),
item_id INTEGER REFERENCES Item(item_id),
metadata_field_id INTEGER REFERENCES MetadataFieldRegistry(metadata_field_id),
text_value TEXT,
text_lang VARCHAR(24),
place INTEGER,
uuid VARCHAR(36)
);
-- 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 VARCHAR(128),
short_description VARCHAR(512),
introductory_text TEXT,
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
copyright_text TEXT,
side_bar_text TEXT,
uuid VARCHAR(36)
);
CREATE INDEX community_logo_fk_idx ON Community(logo_bitstream_id);
-------------------------------------------------------
-- Collection table
-------------------------------------------------------
CREATE TABLE Collection
(
collection_id INTEGER PRIMARY KEY,
name VARCHAR(128),
short_description VARCHAR(512),
introductory_text TEXT,
logo_bitstream_id INTEGER REFERENCES Bitstream(bitstream_id),
template_item_id INTEGER REFERENCES Item(item_id),
provenance_description TEXT,
license TEXT,
copyright_text TEXT,
side_bar_text TEXT,
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 ),
uuid VARCHAR(36)
);
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 REFERENCES Community(community_id)
);
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 REFERENCES Collection(collection_id)
);
-- Index on community ID
CREATE INDEX Community2Collection_community_id_idx ON Community2Collection(community_id);
-- Index on collection ID
CREATE INDEX Community2Collection_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 REFERENCES Item(item_id)
);
-- index by collection_id
CREATE INDEX collection2item_collection_idx ON Collection2Item(collection_id);
-- and item_id
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,
uuid VARCHAR(36)
);
-- 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);
-- NOTE: there is no longer an explicit Handle table (v1.6; Richard Jones)
-------------------------------------------------------
-- Handle table
-------------------------------------------------------
--CREATE TABLE Handle
--(
-- handle_id INTEGER PRIMARY KEY,
-- handle VARCHAR(256) UNIQUE,
-- resource_type_id INTEGER,
-- resource_id INTEGER
--);
-- index by handle, commonly looked up
--CREATE INDEX handle_handle_idx ON Handle(handle);
-- index by resource id and resource type id
--CREATE INDEX handle_resource_id_and_type_idx ON handle(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 BOOL,
published_before BOOL,
multiple_files BOOL,
-- How for the user has got in the submit process
stage_reached INTEGER,
page_reached INTEGER,
uuid VARCHAR(36)
);
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 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 BOOL,
published_before BOOL,
multiple_files BOOL,
-- Note: stage reached not applicable here - people involved in workflow
-- can always jump around submission UI
uuid VARCHAR(36)
);
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);
-------------------------------------------------------
-- 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 VARCHAR(64) UNIQUE,
token VARCHAR(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),
uuid VARCHAR(36)
);
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 DEFAULT nextval('epersongroup2workspaceitem_seq'),
eperson_group_id integer REFERENCES EPersonGroup(eperson_group_id),
workspace_item_id integer REFERENCES WorkspaceItem(workspace_item_id),
CONSTRAINT epersongroup2item_pkey PRIMARY KEY (id)
);
CREATE INDEX epg2wi_group_fk_idx ON epersongroup2workspaceitem(eperson_group_id);
CREATE INDEX epg2wi_workspace_fk_idx ON epersongroup2workspaceitem(workspace_item_id);
------------------------------------------------------------
-- 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)
);
-- Index by item_id for update/re-index
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
--
-- FIXME: This should be done in Java using the Group API. If it did, we
-- wouldn't need these horrible hard-coded UUIDs.
-------------------------------------------------------
-- We don't use getnextid() for 'anonymous' since the sequences start at '1'
INSERT INTO epersongroup VALUES(0, 'Anonymous', '3aa7309d-1bef-4f24-bd1e-ff7921238259');
INSERT INTO epersongroup VALUES(getnextid('epersongroup'), 'Administrator', 'd3e477f0-d28f-413f-8a38-4379279814ed');
-------------------------------------------------------
-- 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 PRIMARY KEY,
result_description VARCHAR
);
-- 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 BOOLEAN NOT NULL,
expected_checksum VARCHAR NOT NULL,
current_checksum VARCHAR NOT NULL,
last_process_start_date TIMESTAMP NOT NULL,
last_process_end_date TIMESTAMP NOT NULL,
checksum_algorithm VARCHAR NOT NULL,
matched_prev_checksum BOOLEAN NOT NULL,
result VARCHAR 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 TABLE checksum_history
(
check_id BIGSERIAL PRIMARY KEY,
bitstream_id INTEGER,
process_start_date TIMESTAMP,
process_end_date TIMESTAMP,
checksum_expected VARCHAR,
checksum_calculated VARCHAR,
result VARCHAR 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 UUID Table and Index
-------------------------------------------------------
CREATE TABLE uuid (
uuid VARCHAR(36) not null,
resource_type integer,
resource_id integer
);
CREATE INDEX uuid_idx ON uuid (uuid);
CREATE TABLE externalidentifier (
namespace varchar(20),
identifier text,
resource_type_id integer,
resource_id integer,
tombstone integer
);
CREATE INDEX externalidentifier_idx ON externalidentifier(namespace, identifier);