mirror of
https://github.com/DSpace/DSpace.git
synced 2025-10-14 21:43:11 +00:00
Support Metadata On All DSpaceObjects
This commit is contained in:
@@ -146,13 +146,9 @@ 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,
|
||||
@@ -171,31 +167,25 @@ CREATE TABLE EPerson
|
||||
password VARCHAR(128),
|
||||
salt VARCHAR(32),
|
||||
digest_algorithm VARCHAR(16),
|
||||
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)
|
||||
sub_frequency INTEGER
|
||||
);
|
||||
|
||||
-- index by email
|
||||
CREATE INDEX eperson_email_idx ON EPerson(email);
|
||||
|
||||
-- index by netid
|
||||
CREATE INDEX eperson_netid_idx ON EPerson(netid);
|
||||
--CREATE INDEX eperson_netid_idx ON EPerson(netid);
|
||||
|
||||
-------------------------------------------------------
|
||||
-- EPersonGroup table
|
||||
-------------------------------------------------------
|
||||
CREATE TABLE EPersonGroup
|
||||
(
|
||||
eperson_group_id INTEGER PRIMARY KEY,
|
||||
name VARCHAR(256) UNIQUE
|
||||
eperson_group_id INTEGER PRIMARY KEY
|
||||
);
|
||||
|
||||
------------------------------------------------------
|
||||
@@ -312,7 +302,8 @@ CREATE TABLE MetadataFieldRegistry
|
||||
CREATE TABLE MetadataValue
|
||||
(
|
||||
metadata_value_id INTEGER PRIMARY KEY DEFAULT NEXTVAL('metadatavalue_seq'),
|
||||
item_id INTEGER REFERENCES Item(item_id),
|
||||
resource_id INTEGER NOT NULL,
|
||||
resource_type_id INTEGER NOT NULL,
|
||||
metadata_field_id INTEGER REFERENCES MetadataFieldRegistry(metadata_field_id),
|
||||
text_value TEXT,
|
||||
text_lang VARCHAR(24),
|
||||
@@ -323,18 +314,16 @@ CREATE TABLE MetadataValue
|
||||
|
||||
-- Create a dcvalue view for backwards compatibilty
|
||||
CREATE VIEW dcvalue AS
|
||||
SELECT MetadataValue.metadata_value_id AS "dc_value_id", MetadataValue.item_id,
|
||||
SELECT MetadataValue.metadata_value_id AS "dc_value_id", MetadataValue.resource_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;
|
||||
AND MetadataFieldRegistry.metadata_schema_id = 1 AND MetadataValue.resource_type_id = 2;
|
||||
|
||||
-- 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);
|
||||
|
||||
@@ -344,12 +333,7 @@ CREATE INDEX metadatafield_schema_idx ON MetadataFieldRegistry(metadata_schema_i
|
||||
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,
|
||||
admin INTEGER REFERENCES EPersonGroup( eperson_group_id )
|
||||
);
|
||||
|
||||
@@ -362,15 +346,8 @@ CREATE INDEX community_admin_fk_idx ON Community(admin);
|
||||
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 ),
|
||||
@@ -645,8 +622,9 @@ CREATE TABLE community_item_count (
|
||||
-- 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(getnextid('epersongroup'), 'Administrator');
|
||||
INSERT INTO epersongroup VALUES(0);
|
||||
INSERT INTO epersongroup VALUES(getnextid('epersongroup'));
|
||||
|
||||
|
||||
|
||||
-------------------------------------------------------
|
||||
|
@@ -14,4 +14,317 @@ BEGIN;
|
||||
ALTER TABLE requestitem ADD request_message TEXT;
|
||||
|
||||
|
||||
alter table metadatavalue rename item_id to resource_id;
|
||||
alter table metadatavalue alter column resource_id set not null;
|
||||
alter table metadatavalue add column resource_type_id integer;
|
||||
UPDATE metadatavalue SET resource_type_id = 2;
|
||||
alter table metadatavalue alter column resource_type_id set not null;
|
||||
alter table metadatavalue drop constraint metadatavalue_item_id_fkey;
|
||||
|
||||
|
||||
-- ---------
|
||||
-- community
|
||||
-- ---------
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
community_id AS resource_id,
|
||||
4 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier is null) AS metadata_field_id,
|
||||
introductory_text AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM community where not introductory_text is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
community_id AS resource_id,
|
||||
4 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier = 'abstract') AS metadata_field_id,
|
||||
short_description AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM community where not short_description is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
community_id AS resource_id,
|
||||
4 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier = 'tableofcontents') AS metadata_field_id,
|
||||
side_bar_text AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM community where not side_bar_text is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
community_id AS resource_id,
|
||||
4 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'rights' and qualifier is null) AS metadata_field_id,
|
||||
copyright_text AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM community where not copyright_text is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
community_id AS resource_id,
|
||||
4 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'title' and qualifier is null) AS metadata_field_id,
|
||||
name AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM community where not name is null;
|
||||
|
||||
alter table community drop column introductory_text, drop column short_description, drop column side_bar_text, drop column copyright_text, drop column name;
|
||||
|
||||
|
||||
-- ----------
|
||||
-- collection
|
||||
-- ----------
|
||||
|
||||
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier is null) AS metadata_field_id,
|
||||
introductory_text AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not introductory_text is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier = 'abstract') AS metadata_field_id,
|
||||
short_description AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not short_description is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier = 'tableofcontents') AS metadata_field_id,
|
||||
side_bar_text AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not side_bar_text is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'rights' and qualifier is null) AS metadata_field_id,
|
||||
copyright_text AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not copyright_text is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'title' and qualifier is null) AS metadata_field_id,
|
||||
name AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not name is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'provenance' and qualifier is null) AS metadata_field_id,
|
||||
provenance_description AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not provenance_description is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
collection_id AS resource_id,
|
||||
3 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'rights' and qualifier = 'license') AS metadata_field_id,
|
||||
license AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM collection where not license is null;
|
||||
|
||||
alter table collection drop column introductory_text, drop column short_description, drop column copyright_text, drop column side_bar_text, drop column name, drop column license, drop column provenance_description;
|
||||
|
||||
|
||||
-- ---------
|
||||
-- bundle
|
||||
-- ---------
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
bundle_id AS resource_id,
|
||||
1 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'title' and qualifier is null) AS metadata_field_id,
|
||||
name AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM bundle where not name is null;
|
||||
|
||||
alter table bundle drop column name;
|
||||
|
||||
|
||||
|
||||
-- ---------
|
||||
-- bitstream
|
||||
-- ---------
|
||||
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
bitstream_id AS resource_id,
|
||||
0 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'title' and qualifier is null) AS metadata_field_id,
|
||||
name AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM bitstream where not name is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
bitstream_id AS resource_id,
|
||||
0 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'description' and qualifier is null) AS metadata_field_id,
|
||||
description AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM bitstream where not description is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
bitstream_id AS resource_id,
|
||||
0 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'format' and qualifier is null) AS metadata_field_id,
|
||||
user_format_description AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM bitstream where not user_format_description is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
bitstream_id AS resource_id,
|
||||
0 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'source' and qualifier is null) AS metadata_field_id,
|
||||
source AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM bitstream where not source is null;
|
||||
|
||||
alter table bitstream drop column name, drop column description, drop column user_format_description, drop column source;
|
||||
|
||||
|
||||
-- ---------
|
||||
-- epersongroup
|
||||
-- ---------
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_group_id AS resource_id,
|
||||
6 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='dc') and element = 'title' and qualifier is null) AS metadata_field_id,
|
||||
name AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM epersongroup where not name is null;
|
||||
|
||||
alter table epersongroup drop column name;
|
||||
|
||||
|
||||
|
||||
-- ---------
|
||||
-- eperson
|
||||
-- ---------
|
||||
|
||||
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_id AS resource_id,
|
||||
7 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='eperson') and element = 'email' and qualifier is null) AS metadata_field_id,
|
||||
email AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM eperson where not email is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_id AS resource_id,
|
||||
7 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='eperson') and element = 'firstname' and qualifier is null) AS metadata_field_id,
|
||||
firstname AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM eperson where not firstname is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_id AS resource_id,
|
||||
7 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='eperson') and element = 'lastname' and qualifier is null) AS metadata_field_id,
|
||||
lastname AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM eperson where not lastname is null;
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_id AS resource_id,
|
||||
7 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='eperson') and element = 'phone' and qualifier is null) AS metadata_field_id,
|
||||
phone AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM eperson where not phone is null;
|
||||
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_id AS resource_id,
|
||||
7 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='eperson') and element = 'netid' and qualifier is null) AS metadata_field_id,
|
||||
netid AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM eperson where not netid is null;
|
||||
|
||||
|
||||
INSERT INTO metadatavalue (resource_id, resource_type_id, metadata_field_id, text_value, text_lang, place)
|
||||
SELECT
|
||||
eperson_id AS resource_id,
|
||||
7 AS resource_type_id,
|
||||
(select metadata_field_id from metadatafieldregistry where metadata_schema_id=(select metadata_schema_id from metadataschemaregistry where short_id='eperson') and element = 'language' and qualifier is null) AS metadata_field_id,
|
||||
language AS text_value,
|
||||
null AS text_lang,
|
||||
0 AS place
|
||||
FROM eperson where not language is null;
|
||||
|
||||
|
||||
alter table eperson drop column firstname, drop column lastname, drop column phone, drop column netid, drop column language;
|
||||
|
||||
-- ---------
|
||||
-- dcvalue view
|
||||
-- ---------
|
||||
|
||||
drop view dcvalue;
|
||||
|
||||
CREATE VIEW dcvalue AS
|
||||
SELECT MetadataValue.metadata_value_id AS "dc_value_id", MetadataValue.resource_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 AND MetadataValue.resource_type_id = 2;
|
||||
|
||||
COMMIT;
|
Reference in New Issue
Block a user