From 7160ceb7db5555e01ce7d946d9144303dbf59f06 Mon Sep 17 00:00:00 2001 From: Robert Tansley Date: Thu, 16 May 2002 18:10:04 +0000 Subject: [PATCH] Schema tweaks: Changes from original SQL: MODIFIED DCValue from: CREATE TABLE DCValue ( dc_value_id INTEGER PRIMARY KEY, text_value TEXT, text_lang VARCHAR(24), source_id INTEGER ); to: 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 TEXT, text_lang VARCHAR(24), place INTEGER source_id INTEGER ); CREATE INDEX dcvalue_dc_type_id_idx on DCValue(dc_type_id); REMOVED Item2DCValue REMOVED Storage REMOVED Bitstream2Storage CHANGED Bitstream from: ------------------------------------------------------- -- Bitstream table ------------------------------------------------------- DROP TABLE Bitstream; CREATE TABLE Bitstream ( bitstream_id INTEGER PRIMARY KEY, bitstream_type_id INTEGER REFERENCES BitstreamTypeRegistry(bitstream_type_id), name VARCHAR(256), size INTEGER, checksum VARCHAR(64), checksum_algorithm VARCHAR(32), description TEXT, user_type_description TEXT, source VARCHAR(256), deleted BOOL ); to: ------------------------------------------------------- -- Bitstream table ------------------------------------------------------- DROP TABLE Bitstream; CREATE TABLE Bitstream ( bitstream_id INTEGER PRIMARY KEY, bitstream_type_id INTEGER REFERENCES BitstreamTypeRegistry(bitstream_type_id), name VARCHAR(256), size INTEGER, checksum VARCHAR(64), checksum_algorithm VARCHAR(32), description TEXT, user_type_description TEXT, source VARCHAR(256), internal_id VARCHAR(256), deleted BOOL ); Views: REMOVED Item2Bitstream REMOVED Collection2Bitstream REMOVED Community2Bitstream REMOVED WorkflowItemsBySubmitter REMOVED PersonalWorkspaceBySubmitter REMOVED AllStorage REMOVED ItemVersion CHANGED DCResult from: ------------------------------------------------------- -- DCResult view ------------------------------------------------------- DROP VIEW DCResult; CREATE VIEW DCResult as SELECT Item.item_id, Item.in_archive, Item.submitter_id, dc_type_id, DCValue.* FROM Item2DCValue, DCValue, Item WHERE Item2DCValue.dc_value_id = DCValue.dc_value_id AND Item.item_id = Item2DCValue.item_id ; to: ------------------------------------------------------- -- DCResult view ------------------------------------------------------- DROP VIEW DCResult; CREATE VIEW DCResult as SELECT DCValue.*, Item.in_archive, Item.submitter_id FROM DCValue, Item WHERE Item.item_id = DCValue.item_id ; git-svn-id: http://scm.dspace.org/svn/repo/trunk@15 9c30dcfa-912a-0410-8fc2-9e0234be79fd --- dspace/etc/database_schema.sql | 193 +++++++-------------------------- 1 file changed, 38 insertions(+), 155 deletions(-) diff --git a/dspace/etc/database_schema.sql b/dspace/etc/database_schema.sql index 254c9db3a9..85a188a487 100644 --- a/dspace/etc/database_schema.sql +++ b/dspace/etc/database_schema.sql @@ -71,16 +71,18 @@ DROP TABLE Bitstream; CREATE TABLE Bitstream ( - bitstream_id INTEGER PRIMARY KEY, - bitstream_type_id INTEGER REFERENCES BitstreamTypeRegistry(bitstream_type_id), - name VARCHAR(256), - size INTEGER, - checksum VARCHAR(64), - checksum_algorithm VARCHAR(32), - description TEXT, - user_type_description TEXT, - source VARCHAR(256), - deleted BOOL + bitstream_id INTEGER PRIMARY KEY, + bitstream_type_id INTEGER REFERENCES +BitstreamTypeRegistry(bitstream_type_id), + name VARCHAR(256), + size INTEGER, + checksum VARCHAR(64), + checksum_algorithm VARCHAR(32), + description TEXT, + user_type_description TEXT, + source VARCHAR(256), + internal_id VARCHAR(256), + deleted BOOL ); ------------------------------------------------------- @@ -181,43 +183,16 @@ DROP TABLE DCValue; 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 TEXT, text_lang VARCHAR(24), + place INTEGER, source_id INTEGER ); --- An index for text_value --- CREATE INDEX dcvalue_text_value_idx ON DCValue(text_value); - -------------------------------------------------------- --- Item2DCValue table -------------------------------------------------------- -DROP TABLE Item2DCValue; - -CREATE TABLE Item2DCValue -( - id INTEGER PRIMARY KEY, - item_id INTEGER REFERENCES Item(item_id), - dc_value_id INTEGER REFERENCES DCValue(dc_value_id), - dc_type_id INTEGER REFERENCES DCTypeRegistry(dc_type_id), - -- index, position, etc are reserved words! - place INTEGER -); - -- An index for dctypes -CREATE INDEX dcvalue_dc_type_id_idx on Item2DCValue(dc_type_id); - -------------------------------------------------------- --- ItemVersion table -------------------------------------------------------- -DROP TABLE ItemVersion; - -CREATE TABLE ItemVersion -( - id INTEGER PRIMARY KEY, - old_item_id INTEGER REFERENCES Item(item_id), - new_item_id INTEGER REFERENCES Item(item_id) -); +CREATE INDEX dcvalue_dc_type_id_idx on DCValue(dc_type_id); ------------------------------------------------------- -- Community table @@ -324,31 +299,6 @@ CREATE TABLE Handle resource_id INTEGER ); -------------------------------------------------------- --- Storage table -------------------------------------------------------- -DROP TABLE Storage; - -CREATE TABLE Storage -( - storage_id INTEGER PRIMARY KEY, - storage_name VARCHAR(256), - internal_id VARCHAR(256), - UNIQUE(storage_name, internal_id) -); - -------------------------------------------------------- --- Bitstream2Storage table -------------------------------------------------------- -DROP TABLE Bitstream2Storage; - -CREATE TABLE Bitstream2Storage -( - id INTEGER PRIMARY KEY, - bitstream_id INTEGER REFERENCES Bitstream(bitstream_id), - storage_id INTEGER REFERENCES Storage(storage_id) -); - ------------------------------------------------------- -- PersonalWorkspace table ------------------------------------------------------- @@ -492,18 +442,15 @@ CREATE TABLE TestTableMapping -- Convenience views ------------------------------------------------------------ --- Views for CM API - ------------------------------------------------------- --- DCResult view +-- Item2Handle view ------------------------------------------------------- -DROP VIEW DCResult; +-- Note: DSpaceTypes.ITEM = 2 +DROP VIEW Item2Handle; -CREATE VIEW DCResult as -SELECT Item.item_id, Item.in_archive, Item.submitter_id, dc_type_id, DCValue.* -FROM Item2DCValue, DCValue, Item -WHERE Item2DCValue.dc_value_id = DCValue.dc_value_id -AND Item.item_id = Item2DCValue.item_id +CREATE VIEW Item2Handle as +select handle_id, handle, resource_id as item_id +from Handle where resource_type_id = 2 ; ------------------------------------------------------- @@ -517,6 +464,22 @@ FROM Community2Collection, Collection2Item WHERE Collection2Item.collection_id = Community2Collection.collection_id ; + +------------------------------------------------------------ +-- Browse subsystem views +------------------------------------------------------------ + +------------------------------------------------------- +-- DCResult view +------------------------------------------------------- +DROP VIEW DCResult; + +CREATE VIEW DCResult as +SELECT DCValue.*, Item.in_archive, Item.submitter_id +FROM DCValue, Item +WHERE Item.item_id = DCValue.item_id +; + ------------------------------------------------------- -- ItemsByAuthor view ------------------------------------------------------- @@ -677,75 +640,6 @@ WHERE ItemsByDate.item_id = Community2Item.item_id ORDER BY DateIssued desc, ItemsByDate.item_id ; -------------------------------------------------------- --- AllStorage view -------------------------------------------------------- -DROP VIEW AllStorage; - -CREATE VIEW AllStorage as -SELECT Bitstream.*, Storage.*, - BitstreamTypeRegistry.mimetype, BitstreamTypeRegistry.short_description -FROM Bitstream, Storage, Bitstream2Storage, BitstreamTypeRegistry -WHERE Bitstream.bitstream_id = Bitstream2Storage.bitstream_id -AND Storage.storage_id = Bitstream2Storage.storage_id -AND Bitstream.bitstream_type_id = BitstreamTypeRegistry.bitstream_type_id -; - -------------------------------------------------------- --- Item2Bitstream view -------------------------------------------------------- -DROP VIEW Item2Bitstream; - -CREATE VIEW Item2Bitstream as -SELECT Item2Bundle.item_id, Bundle2Bitstream.bitstream_id -FROM Item2Bundle, Bundle2Bitstream -WHERE Item2Bundle.bundle_id = Bundle2Bitstream.bundle_id -; - -------------------------------------------------------- --- Collection2Bitstream view -------------------------------------------------------- -DROP VIEW Collection2Bitstream; - -CREATE VIEW Collection2Bitstream as -SELECT Collection2Item.collection_id, Bundle2Bitstream.bitstream_id -FROM Collection2Item, Item2Bundle, Bundle2Bitstream -WHERE Collection2Item.item_id = Item2Bundle.item_id -AND Item2Bundle.bundle_id = Bundle2Bitstream.bundle_id -; - - -------------------------------------------------------- --- Community2Bitstream view -------------------------------------------------------- -DROP VIEW Community2Bitstream; - -CREATE VIEW Community2Bitstream as -SELECT Community2Collection.community_id, Collection2Bitstream.bitstream_id -FROM Community2Collection, Collection2Bitstream -WHERE Community2Collection.collection_id = Collection2Bitstream.collection_id -; - -------------------------------------------------------- --- WorkflowItemsBySubmitter view -------------------------------------------------------- -DROP VIEW WorkflowItemBySubmitter; - -CREATE VIEW WorkflowItemBySubmitter as -SELECT WorkflowItem.*, Item.submitter_id -FROM WorkflowItem, Item -WHERE WorkflowItem.item_id = Item.item_id; - -------------------------------------------------------- --- PersonalWorkspaceBySubmitter view -------------------------------------------------------- -DROP VIEW PersonalWorkspaceBySubmitter; - -CREATE VIEW PersonalWorkspaceBySubmitter as -SELECT PersonalWorkspace.*, Item.submitter_id -FROM PersonalWorkspace, Item -WHERE PersonalWorkspace.item_id = Item.item_id; - ------------------------------------------------------- -- ItemsByDateAccessioned view ------------------------------------------------------- @@ -785,14 +679,3 @@ WHERE ItemsByDateAccessioned.item_id = Community2Item.item_id ORDER BY DateAccessioned desc, ItemsByDateAccessioned.item_id ; -------------------------------------------------------- --- Item2Handle view -------------------------------------------------------- --- Note: DSpaceTypes.ITEM = 2 -DROP VIEW Item2Handle; - -CREATE VIEW Item2Handle as -select handle_id, handle, resource_id as item_id -from Handle where resource_type_id = 2 - -;