Project

General

Profile

1
CREATE TABLE systemMetadata (
2
	guid   text,          -- the globally unique string identifier of the object that the system metadata describes
3
	serial_version VARCHAR(256), --the serial version of the object
4
	date_uploaded TIMESTAMP, -- the date/time the document was first submitted
5
	rights_holder VARCHAR(250), --the user who has rights to the document, usually the first persons to upload it
6
	checksum VARCHAR(512), --the checksum of the doc using the given algorithm (see below)
7
	checksum_algorithm VARCHAR(250), --the algorithm used to calculate the checksum
8
	origin_member_node VARCHAR(250), --the member node where the document was first uploaded
9
	authoritive_member_node VARCHAR(250), --the member node that currently controls the document
10
	date_modified TIMESTAMP, -- the last date/time that the file was changed
11
	submitter VARCHAR(256), -- the user who originally submitted the doc
12
	object_format VARCHAR(256), --the format of the object
13
	size VARCHAR(256), --the size of the object
14
	replication_allowed boolean,	 -- replication allowed
15
	number_replicas INT8, 	-- the number of replicas allowed
16
	obsoletes   text,       -- the identifier that this record obsoletes
17
	obsoleted_by   text,     -- the identifier of the record that replaces this record
18
	CONSTRAINT systemMetadata_pk PRIMARY KEY (guid)
19
);
20

    
21
CREATE TABLE systemMetadataReplicationPolicy (
22
	guid text,	-- the globally unique string identifier of the object that the system metadata describes
23
	member_node VARCHAR(250),	 -- replication member node
24
	policy text,	 -- the policy (preferred, blocked, etc...TBD)
25
	CONSTRAINT systemMetadataReplicationPolicy_fk 
26
		FOREIGN KEY (guid) REFERENCES systemMetadata
27
);
28

    
29
CREATE TABLE systemMetadataReplicationStatus (
30
	guid text,	-- the globally unique string identifier of the object that the system metadata describes
31
	member_node VARCHAR(250),	 -- replication member node
32
	status VARCHAR(250),	 -- replication status
33
	date_verified TIMESTAMP, 	-- the date replication was verified   
34
	CONSTRAINT systemMetadataReplicationStatus_fk 
35
		FOREIGN KEY (guid) REFERENCES systemMetadata
36
);
37

    
38
/*
39
 * Remove the old Identifier table (pre-2.0)
40
 */
41
DROP TABLE identifier;
42
/*
43
 * Create the new one (DataONE features)
44
 */
45
CREATE TABLE identifier (
46
   guid   text,          -- the globally unique string identifier
47
   docid  VARCHAR(250),  -- the local document id #
48
   rev    INT8,          -- the revision part of the local identifier
49
   CONSTRAINT identifier_pk PRIMARY KEY (guid)
50
);
51

    
52
/*
53
 * add the nodedatadate column to the tables that need it 
54
 */
55
ALTER TABLE xml_nodes ADD COLUMN nodedatadate TIMESTAMP;
56
ALTER TABLE xml_nodes_revisions ADD COLUMN nodedatadate TIMESTAMP;
57
ALTER TABLE xml_path_index ADD COLUMN nodedatadate TIMESTAMP;
58
CREATE INDEX xml_path_index_idx5 ON xml_path_index (nodedatadate);
59

    
60
/*
61
 * Replication changes to support DataONE System Metadata replication
62
 */
63
ALTER TABLE xml_replication ADD COLUMN systemmetadatareplicate INT8;
64

    
65
/**
66
 * track the user-agent for the request
67
 */
68
ALTER TABLE access_log ADD COLUMN user_agent VARCHAR(512);
69

    
70
/*
71
 * Register the new schema
72
 */
73
INSERT INTO xml_catalog (entry_type, public_id, system_id)
74
  VALUES ('Schema', '@eml2_1_1namespace@', '/schema/eml-2.1.1/eml.xsd');  
75

    
76
/**
77
 * Generate GUIDs for docid.rev
78
 */
79
INSERT INTO identifier (docid, rev, guid) 
80
	SELECT docid, rev, docid || '.' || rev FROM xml_documents;
81
INSERT INTO identifier (docid, rev, guid)
82
	SELECT docid, revisionid, docid || '.' || revisionid FROM xml_revisions;
83

    
84
/**
85
 *  Allow guid in xml_access table (for system metadata)
86
 */
87
ALTER TABLE xml_access ADD COLUMN guid text;
88

    
89
/**
90
 * Upgrade xml_access records to use GUID from identifier table
91
 */
92
INSERT INTO xml_access (
93
	guid, principal_name, permission, perm_type, perm_order, 
94
	docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
95
)
96
	SELECT 
97
		id.guid, xa.principal_name, xa.permission, xa.perm_type, xa.perm_order, 
98
		xa.docid, xa.accessfileid, xa.begin_time, xa.end_time, xa.ticket_count, xa.subtreeid, xa.startnodeid, xa.endnodeid
99
	FROM identifier id, xml_access xa
100
	WHERE id.docid = xa.docid;
101

    
102
/**
103
 * Include inline access rows -- they have a special guid: 'scope.docid.rev.index'
104
 */
105
INSERT INTO xml_access (
106
	guid, principal_name, permission, perm_type, perm_order, 
107
	docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
108
)
109
	SELECT 
110
		docid, principal_name, permission, perm_type, perm_order, 
111
		docid, accessfileid, begin_time, end_time, ticket_count, subtreeid, startnodeid, endnodeid
112
	FROM xml_access
113
	WHERE docid like '%.%.%.%';
114

    
115
/**
116
 * Update the accessfileid to use guid
117
 * TODO: specific revision should be used
118
 */
119
UPDATE xml_access
120
SET accessfileid = id.guid
121
FROM identifier id, xml_access xa
122
WHERE xa.accessfileid = id.docid
123

    
124

    
125
/**
126
 * Remove old access rules
127
 */
128
DELETE FROM xml_access WHERE guid is null;
129

    
130
/**
131
 * clean up the xml_access table
132
 */
133
ALTER TABLE xml_access DROP COLUMN docid;
134

    
135
/*
136
 * update the database version
137
 */
138
UPDATE db_version SET status=0;
139

    
140
INSERT INTO db_version (version, status, date_created) 
141
  VALUES ('2.0.0', 1, CURRENT_DATE);
142

    
(49-49/53)