Moved PostgreSQL-specific scripts into community-visible repository project

git-svn-id: https://svn.alfresco.com/repos/alfresco-enterprise/alfresco/HEAD/root@17114 c4b6b30b-aa2e-2d43-bbcb-ca4b014f7261
This commit is contained in:
Derek Hulley
2009-10-23 10:03:39 +00:00
parent 9889264e8b
commit f1999bb3d3
19 changed files with 3159 additions and 0 deletions

View File

@@ -0,0 +1,62 @@
--
-- Title: Audit tables
-- Database: PostgreSql
-- Since: V3.2 Schema 3002
-- Author: Pavel Yurkevich
--
-- Please contact support@alfresco.com if you need assistance with the upgrade.
--
CREATE TABLE alf_audit_model
(
id INT8 NOT NULL,
content_data_id INT8 NOT NULL,
content_crc INT8 NOT NULL,
CONSTRAINT fk_alf_audit_model_cd FOREIGN KEY (content_data_id) REFERENCES alf_content_data (id),
PRIMARY KEY (id)
);
CREATE UNIQUE INDEX idx_alf_audit_cfg_crc ON alf_audit_model(content_crc);
CREATE SEQUENCE alf_audit_model_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_audit_app
(
id INT8 NOT NULL,
version INT4 NOT NULL,
app_name_id INT8 NOT NULL CONSTRAINT idx_alf_audit_app_app UNIQUE,
audit_model_id INT8 NOT NULL,
disabled_paths_id INT8 NOT NULL,
CONSTRAINT fk_alf_audit_app_app FOREIGN KEY (app_name_id) REFERENCES alf_prop_value (id),
CONSTRAINT fk_alf_audit_app_model FOREIGN KEY (audit_model_id) REFERENCES alf_audit_model (id) ON DELETE CASCADE,
CONSTRAINT fk_alf_audit_app_dis FOREIGN KEY (disabled_paths_id) REFERENCES alf_prop_root (id),
PRIMARY KEY (id)
);
CREATE SEQUENCE alf_audit_app_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_audit_entry
(
id INT8 NOT NULL,
audit_app_id INT8 NOT NULL,
audit_time INT8 NOT NULL,
audit_user_id INT8 NULL,
audit_values_id INT8 NULL,
CONSTRAINT fk_alf_audit_ent_app FOREIGN KEY (audit_app_id) REFERENCES alf_audit_app (id) ON DELETE CASCADE,
CONSTRAINT fk_alf_audit_ent_user FOREIGN KEY (audit_user_id) REFERENCES alf_prop_value (id),
CONSTRAINT fk_alf_audit_ent_prop FOREIGN KEY (audit_values_id) REFERENCES alf_prop_root (id),
PRIMARY KEY (id)
);
CREATE INDEX idx_alf_audit_ent_time ON alf_audit_entry(audit_time);
CREATE SEQUENCE alf_audit_entry_seq START WITH 1 INCREMENT BY 1;
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-AuditTables';
INSERT INTO alf_applied_patch
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
VALUES
(
'patch.db-V3.2-AuditTables', 'Manually executed script upgrade V3.2: Audit Tables',
0, 3001, -1, 3002, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
);

View File

@@ -0,0 +1,246 @@
--
-- Title: Create AVM tables
-- Database: PostgreSql
-- Since: V3.2.0 Schema 3002
-- Author: Pavel Yurkevich
--
-- Please contact support@alfresco.com if you need assistance with the upgrade.
--
create table avm_aspects (
node_id INT8 not null,
qname_id INT8 not null,
primary key (node_id, qname_id)
);
create table avm_child_entries (
parent_id INT8 not null,
name varchar(160) not null,
child_id INT8 not null,
primary key (parent_id, name)
);
create table avm_history_links (
ancestor INT8 not null,
descendent INT8 not null,
primary key (ancestor, descendent)
);
create table avm_merge_links (
mfrom INT8 not null,
mto INT8 not null,
primary key (mfrom, mto)
);
create table avm_node_properties (
node_id INT8 not null,
actual_type_n INT4 not null,
persisted_type_n INT4 not null,
multi_valued BOOL not null,
boolean_value BOOL,
long_value INT8,
float_value FLOAT4,
double_value FLOAT8,
string_value VARCHAR(1024),
serializable_value BYTEA,
qname_id INT8 not null,
primary key (node_id, qname_id)
);
create table avm_nodes (
id INT8 not null,
class_type varchar(20) not null,
vers INT8 not null,
version_id INT4 not null,
guid varchar(36),
creator varchar(255) not null,
owner varchar(255) not null,
lastModifier varchar(255) not null,
createDate INT8 not null,
modDate INT8 not null,
accessDate INT8 not null,
is_root BOOL,
store_new_id INT8,
acl_id INT8,
deletedType INT4,
layer_id INT8,
indirection VARCHAR(1024),
indirection_version INT4,
primary_indirection BOOL,
opacity BOOL,
content_url varchar(128),
mime_type varchar(100),
encoding varchar(16),
length INT8,
primary key (id)
);
CREATE SEQUENCE avm_nodes_seq START WITH 1 INCREMENT BY 1;
create table avm_store_properties (
id INT8 not null,
avm_store_id INT8,
qname_id INT8 not null,
actual_type_n INT4 not null,
persisted_type_n INT4 not null,
multi_valued BOOL not null,
boolean_value BOOL,
long_value INT8,
float_value FLOAT4,
double_value FLOAT8,
string_value VARCHAR(1024),
serializable_value BYTEA,
primary key (id)
);
CREATE SEQUENCE avm_store_properties_seq START WITH 1 INCREMENT BY 1;
create table avm_stores (
id INT8 not null,
vers INT8 not null,
name varchar(255) unique,
next_version_id INT4 not null,
current_root_id INT8,
acl_id INT8,
primary key (id)
);
CREATE SEQUENCE avm_stores_seq START WITH 1 INCREMENT BY 1;
create table avm_version_layered_node_entry (
version_root_id INT8 not null,
md5sum varchar(32) not null,
path VARCHAR(1024),
primary key (version_root_id, md5sum)
);
create table avm_version_roots (
id INT8 not null,
version_id INT4 not null,
avm_store_id INT8 not null,
create_date INT8 not null,
creator varchar(255) not null,
root_id INT8 not null,
tag varchar(255),
description VARCHAR(1024),
primary key (id),
unique (version_id, avm_store_id)
);
CREATE SEQUENCE avm_version_roots_seq START WITH 1 INCREMENT BY 1;
alter table avm_aspects
add constraint fk_avm_nasp_n
foreign key (node_id)
references avm_nodes (id);
create index fk_avm_nasp_n on avm_aspects(node_id);
alter table avm_child_entries
add constraint fk_avm_ce_child
foreign key (child_id)
references avm_nodes (id);
create index fk_avm_ce_child on avm_child_entries(child_id);
alter table avm_child_entries
add constraint fk_avm_ce_parent
foreign key (parent_id)
references avm_nodes (id);
create index fk_avm_ce_parent on avm_child_entries(parent_id);
alter table avm_history_links
add constraint fk_avm_hl_desc
foreign key (descendent)
references avm_nodes (id);
create index fk_avm_hl_desc on avm_history_links(descendent);
alter table avm_history_links
add constraint fk_avm_hl_ancestor
foreign key (ancestor)
references avm_nodes (id);
create index fk_avm_hl_ancestor on avm_history_links(ancestor);
alter table avm_merge_links
add constraint fk_avm_ml_from
foreign key (mfrom)
references avm_nodes (id);
create index fk_avm_ml_from on avm_merge_links(mfrom);
alter table avm_merge_links
add constraint fk_avm_ml_to
foreign key (mto)
references avm_nodes (id);
create index fk_avm_ml_to on avm_merge_links(mto);
alter table avm_node_properties
add constraint fk_avm_nprop_n
foreign key (node_id)
references avm_nodes (id);
create index fk_avm_nprop_n on avm_node_properties(node_id);
create index idx_avm_n_pi on avm_nodes (primary_indirection);
alter table avm_nodes
add constraint fk_avm_n_acl
foreign key (acl_id)
references alf_access_control_list (id);
create index fk_avm_n_acl on avm_nodes(acl_id);
alter table avm_nodes
add constraint fk_avm_n_store
foreign key (store_new_id)
references avm_stores (id);
create index fk_avm_n_store on avm_nodes(store_new_id);
alter table avm_store_properties
add constraint fk_avm_sprop_store
foreign key (avm_store_id)
references avm_stores (id);
create index fk_avm_sprop_store on avm_store_properties(avm_store_id);
alter table avm_stores
add constraint fk_avm_s_root
foreign key (current_root_id)
references avm_nodes (id);
create index fk_avm_s_root on avm_stores(current_root_id);
alter table avm_version_layered_node_entry
add constraint fk_avm_vlne_vr
foreign key (version_root_id)
references avm_version_roots (id);
create index fk_avm_vlne_vr on avm_version_layered_node_entry(version_root_id);
create index idx_avm_vr_version on avm_version_roots (version_id);
alter table avm_version_roots
add constraint fk_avm_vr_store
foreign key (avm_store_id)
references avm_stores (id);
create index fk_avm_vr_store on avm_version_roots(avm_store_id);
alter table avm_version_roots
add constraint fk_avm_vr_root
foreign key (root_id)
references avm_nodes (id);
create index fk_avm_vr_root on avm_version_roots(root_id);
CREATE INDEX fk_avm_nasp_qn ON avm_aspects (qname_id);
ALTER TABLE avm_aspects ADD CONSTRAINT fk_avm_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id);
CREATE INDEX fk_avm_nprop_qn ON avm_node_properties (qname_id);
ALTER TABLE avm_node_properties ADD CONSTRAINT fk_avm_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id);
CREATE INDEX fk_avm_sprop_qname ON avm_store_properties (qname_id);
ALTER TABLE avm_store_properties ADD CONSTRAINT fk_avm_sprop_qname FOREIGN KEY (qname_id) REFERENCES alf_qname (id);
CREATE INDEX idx_avm_hl_revpk ON avm_history_links (descendent, ancestor);
CREATE INDEX idx_avm_vr_revuq ON avm_version_roots (avm_store_id, version_id);
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-AvmTables';
INSERT INTO alf_applied_patch
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
VALUES
(
'patch.db-V3.2-AvmTables', 'Manually executed script upgrade V3.2: AVM Tables',
0, 3001, -1, 3002, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
);

View File

@@ -0,0 +1,78 @@
--
-- Title: Create Content tables
-- Database: PostgreSQL
-- Since: V3.2 Schema 2012
-- Author:
--
-- Please contact support@alfresco.com if you need assistance with the upgrade.
--
CREATE TABLE alf_mimetype
(
id INT8 NOT NULL,
version INT8 NOT NULL,
mimetype_str VARCHAR(100) NOT NULL,
PRIMARY KEY (id),
UNIQUE (mimetype_str)
);
CREATE SEQUENCE alf_mimetype_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_encoding
(
id INT8 NOT NULL,
version INT8 NOT NULL,
encoding_str VARCHAR(100) NOT NULL,
PRIMARY KEY (id),
UNIQUE (encoding_str)
);
CREATE SEQUENCE alf_encoding_seq START WITH 1 INCREMENT BY 1;
-- This table may exist during upgrades, but must be removed.
-- The drop statement is therefore optional.
DROP TABLE alf_content_url; --(optional)
CREATE TABLE alf_content_url
(
id INT8 NOT NULL,
version INT8 NOT NULL,
content_url VARCHAR(255) NOT NULL,
content_url_short VARCHAR(12) NOT NULL,
content_url_crc INT8 NOT NULL,
content_size INT8 NOT NULL,
PRIMARY KEY (id)
);
CREATE INDEX idx_alf_cont_url_crc ON alf_content_url (content_url_short, content_url_crc);
CREATE SEQUENCE alf_content_url_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_content_data
(
id INT8 NOT NULL,
version INT8 NOT NULL,
content_url_id INT8 NULL,
content_mimetype_id INT8 NULL,
content_encoding_id INT8 NULL,
content_locale_id INT8 NULL,
CONSTRAINT fk_alf_cont_url FOREIGN KEY (content_url_id) REFERENCES alf_content_url (id),
CONSTRAINT fk_alf_cont_mim FOREIGN KEY (content_mimetype_id) REFERENCES alf_mimetype (id),
CONSTRAINT fk_alf_cont_enc FOREIGN KEY (content_encoding_id) REFERENCES alf_encoding (id),
CONSTRAINT fk_alf_cont_loc FOREIGN KEY (content_locale_id) REFERENCES alf_locale (id),
PRIMARY KEY (id)
);
CREATE SEQUENCE alf_content_data_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_content_clean
(
content_url VARCHAR(255) NOT NULL
);
CREATE INDEX idx_alf_contentclean_url ON alf_content_clean (content_url);
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-ContentTables';
INSERT INTO alf_applied_patch
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
VALUES
(
'patch.db-V3.2-ContentTables', 'Manually executed script upgrade V3.2: Content Tables',
0, 2011, -1, 2012, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
);

View File

@@ -0,0 +1,49 @@
--
-- Title: Create lock tables
-- Database: PostgreSQL
-- Since: V3.2 Schema 2011
-- Author:
--
-- Please contact support@alfresco.com if you need assistance with the upgrade.
--
CREATE TABLE alf_lock_resource
(
id INT8 NOT NULL,
version INT8 NOT NULL,
qname_ns_id INT8 NOT NULL,
qname_localname VARCHAR(255) NOT NULL,
CONSTRAINT fk_alf_lockr_ns FOREIGN KEY (qname_ns_id) REFERENCES alf_namespace (id),
PRIMARY KEY (id)
);
CREATE INDEX idx_alf_lockr_key ON alf_lock_resource (qname_ns_id, qname_localname);
CREATE SEQUENCE alf_lock_resource_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_lock
(
id INT8 NOT NULL,
version INT8 NOT NULL,
shared_resource_id INT8 NOT NULL,
excl_resource_id INT8 NOT NULL,
lock_token VARCHAR(36) NOT NULL,
start_time INT8 NOT NULL,
expiry_time INT8 NOT NULL,
CONSTRAINT fk_alf_lock_shared FOREIGN KEY (shared_resource_id) REFERENCES alf_lock_resource (id),
CONSTRAINT fk_alf_lock_excl FOREIGN KEY (excl_resource_id) REFERENCES alf_lock_resource (id),
PRIMARY KEY (id)
);
CREATE INDEX idx_alf_lock_key ON alf_lock (shared_resource_id, excl_resource_id);
CREATE SEQUENCE alf_lock_seq START WITH 1 INCREMENT BY 1;
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-LockTables';
INSERT INTO alf_applied_patch
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
VALUES
(
'patch.db-V3.2-LockTables', 'Manually executed script upgrade V3.2: Lock Tables',
0, 2010, -1, 2011, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
);

View File

@@ -0,0 +1,132 @@
--
-- Title: Property Value tables
-- Database: PostgreSql
-- Since: V3.2 Schema 3001
-- Author: Pavel Yurkevich
--
-- Please contact support@alfresco.com if you need assistance with the upgrade.
--
CREATE TABLE alf_prop_class
(
id INT8 NOT NULL,
java_class_name VARCHAR(255) NOT NULL,
java_class_name_short VARCHAR(32) NOT NULL,
java_class_name_crc INT8 NOT NULL,
PRIMARY KEY (id)
);
CREATE UNIQUE INDEX idx_alf_prop_class_crc ON alf_prop_class(java_class_name_crc, java_class_name_short);
CREATE INDEX idx_alf_prop_class_class ON alf_prop_class(java_class_name);
CREATE SEQUENCE alf_prop_class_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_prop_date_value
(
date_value INT8 NOT NULL,
full_year INT4 NOT NULL,
half_of_year INT2 NOT NULL,
quarter_of_year INT2 NOT NULL,
month_of_year INT2 NOT NULL,
week_of_year INT2 NOT NULL,
week_of_month INT2 NOT NULL,
day_of_year INT4 NOT NULL,
day_of_month INT2 NOT NULL,
day_of_week INT2 NOT NULL,
PRIMARY KEY (date_value)
);
CREATE INDEX idx_alf_prop_date_units ON alf_prop_date_value(full_year, month_of_year, day_of_month);
CREATE TABLE alf_prop_double_value
(
id INT8 NOT NULL,
double_value FLOAT8 NOT NULL,
PRIMARY KEY (id)
);
CREATE UNIQUE INDEX idx_alf_prop_dbl_val ON alf_prop_double_value(double_value);
CREATE SEQUENCE alf_prop_double_value_seq START WITH 1 INCREMENT BY 1;
-- Stores unique, case-sensitive string values --
CREATE TABLE alf_prop_string_value
(
id INT8 NOT NULL,
string_value VARCHAR(1024) NOT NULL,
string_end_lower VARCHAR(16) NOT NULL,
string_crc INT8 NOT NULL,
PRIMARY KEY (id)
);
CREATE INDEX idx_alf_prop_str ON alf_prop_string_value(string_value);
CREATE UNIQUE INDEX idx_alf_prop_crc ON alf_prop_string_value(string_end_lower, string_crc);
CREATE SEQUENCE alf_prop_string_value_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_prop_serializable_value
(
id INT8 NOT NULL,
serializable_value BYTEA NOT NULL,
PRIMARY KEY (id)
);
CREATE SEQUENCE alf_prop_serializable_value_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_prop_value
(
id INT8 NOT NULL,
actual_type_id INT8 NOT NULL,
persisted_type INT2 NOT NULL,
long_value INT8 NOT NULL,
PRIMARY KEY (id)
);
CREATE INDEX idx_alf_prop_per ON alf_prop_value(persisted_type, long_value);
CREATE UNIQUE INDEX idx_alf_prop_act ON alf_prop_value(actual_type_id, long_value);
CREATE SEQUENCE alf_prop_value_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_prop_root
(
id INT8 NOT NULL,
version INT4 NOT NULL,
PRIMARY KEY (id)
);
CREATE SEQUENCE alf_prop_root_seq START WITH 1 INCREMENT BY 1;
CREATE TABLE alf_prop_link
(
root_prop_id INT8 NOT NULL,
prop_index INT8 NOT NULL,
contained_in INT8 NOT NULL,
key_prop_id INT8 NOT NULL,
value_prop_id INT8 NOT NULL,
CONSTRAINT fk_alf_prop_link_root FOREIGN KEY (root_prop_id) REFERENCES alf_prop_root (id) ON DELETE CASCADE,
CONSTRAINT fk_alf_prop_link_key FOREIGN KEY (key_prop_id) REFERENCES alf_prop_value (id) ON DELETE CASCADE,
CONSTRAINT fk_alf_prop_link_val FOREIGN KEY (value_prop_id) REFERENCES alf_prop_value (id) ON DELETE CASCADE,
PRIMARY KEY (root_prop_id, contained_in, prop_index)
);
CREATE INDEX idx_alf_prop_link_for ON alf_prop_link(root_prop_id, key_prop_id, value_prop_id);
CREATE TABLE alf_prop_unique_ctx
(
id INT8 NOT NULL,
version INT4 NOT NULL,
value1_prop_id INT8 NOT NULL,
value2_prop_id INT8 NOT NULL,
value3_prop_id INT8 NOT NULL,
CONSTRAINT fk_alf_prop_unique_ctx_1 FOREIGN KEY (value1_prop_id) REFERENCES alf_prop_value (id) ON DELETE CASCADE,
CONSTRAINT fk_alf_prop_unique_ctx_2 FOREIGN KEY (value2_prop_id) REFERENCES alf_prop_value (id) ON DELETE CASCADE,
CONSTRAINT fk_alf_prop_unique_ctx_3 FOREIGN KEY (value3_prop_id) REFERENCES alf_prop_value (id) ON DELETE CASCADE,
PRIMARY KEY (id)
);
CREATE UNIQUE INDEX idx_alf_prop_unique_ctx ON alf_prop_unique_ctx(value1_prop_id, value2_prop_id, value3_prop_id);
CREATE SEQUENCE alf_prop_unique_ctx_seq START WITH 1 INCREMENT BY 1;
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-PropertyValueTables';
INSERT INTO alf_applied_patch
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
VALUES
(
'patch.db-V3.2-PropertyValueTables', 'Manually executed script upgrade V3.2: PropertyValue Tables',
0, 3000, -1, 3001, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
);