mirror of
https://github.com/Alfresco/alfresco-community-repo.git
synced 2025-07-31 17:39:05 +00:00
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:
@@ -0,0 +1,10 @@
|
||||
--
|
||||
-- Title: Post-Create Indexes
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.2 Schema 86
|
||||
-- Author: Pavel Yurkevich
|
||||
--
|
||||
-- Hibernate only generates indexes on foreign key columns for Oracle.
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
@@ -0,0 +1,37 @@
|
||||
--
|
||||
-- Title: Activities Schema - Extras (Indexes, Sequences)
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V3.0.0 Schema
|
||||
--
|
||||
|
||||
-- Activity Post
|
||||
CREATE SEQUENCE alf_activity_post_seq START WITH 1 INCREMENT BY 1;
|
||||
CREATE INDEX post_jobtasknode_idx ON alf_activity_post(job_task_node);
|
||||
CREATE INDEX post_status_idx ON alf_activity_post(status);
|
||||
|
||||
-- Activity Feed
|
||||
CREATE SEQUENCE alf_activity_feed_seq START WITH 1 INCREMENT BY 1;
|
||||
|
||||
CREATE INDEX feed_postdate_idx ON alf_activity_feed(post_date);
|
||||
CREATE INDEX feed_postuserid_idx ON alf_activity_feed(post_user_id);
|
||||
CREATE INDEX feed_feeduserid_idx ON alf_activity_feed(feed_user_id);
|
||||
CREATE INDEX feed_sitenetwork_idx ON alf_activity_feed(site_network);
|
||||
CREATE INDEX feed_activityformat_idx ON alf_activity_feed(activity_format);
|
||||
|
||||
-- Activity Feed Control
|
||||
CREATE SEQUENCE alf_activity_feed_control_seq START WITH 1 INCREMENT BY 1;
|
||||
|
||||
CREATE INDEX feedctrl_feeduserid_idx ON alf_activity_feed_control(feed_user_id);
|
||||
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.0-0-CreateActivitiesExtras';
|
||||
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.0-0-CreateActivitiesExtras', 'Executed script create V3.0: Created activities extras',
|
||||
0, 125, -1, 126, null, 'UNKNOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -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'
|
||||
);
|
@@ -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'
|
||||
);
|
@@ -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'
|
||||
);
|
@@ -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'
|
||||
);
|
@@ -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'
|
||||
);
|
@@ -0,0 +1,15 @@
|
||||
/*
|
||||
* Solution to PostgreSQL issue:
|
||||
* function information_schema._pg_keypositions() does not exist
|
||||
* Taken from: http://archives.postgresql.org/pgsql-general/2005-12/msg00060.php
|
||||
* Author: Jason Long
|
||||
* Tested against PostgreSQL 8.2
|
||||
* First seen during upgrade testing of PostgreSQL from Alfresco 1.4.3 to 2.0
|
||||
*/
|
||||
SET search_path TO information_schema, public;
|
||||
CREATE FUNCTION _pg_keypositions() RETURNS SETOF integer
|
||||
LANGUAGE sql
|
||||
IMMUTABLE
|
||||
AS 'select g.s
|
||||
from generate_series(1,current_setting(''max_index_keys'')::int,1)
|
||||
as g(s)';
|
@@ -0,0 +1,205 @@
|
||||
--
|
||||
-- Title: Update for permissions schema changes
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.2 Schema 85
|
||||
-- Author:
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
CREATE TABLE alf_acl_change_set
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
|
||||
-- Add to ACL
|
||||
ALTER TABLE alf_access_control_list
|
||||
ADD COLUMN type INT4 NOT NULL DEFAULT 0,
|
||||
ADD COLUMN latest BOOL NOT NULL DEFAULT TRUE,
|
||||
ADD COLUMN acl_id VARCHAR(36) NOT NULL DEFAULT 'UNSET',
|
||||
ADD COLUMN acl_version INT8 NOT NULL DEFAULT 1,
|
||||
ADD COLUMN inherited_acl INT8,
|
||||
ADD COLUMN is_versioned BOOL NOT NULL DEFAULT FALSE,
|
||||
ADD COLUMN requires_version BOOL NOT NULL DEFAULT FALSE,
|
||||
ADD COLUMN acl_change_set INT8,
|
||||
ADD COLUMN inherits_from INT8,
|
||||
ADD CONSTRAINT fk_alf_acl_acs FOREIGN KEY (acl_change_set) REFERENCES alf_acl_change_set (id);
|
||||
CREATE INDEX idx_alf_acl_inh ON alf_access_control_list (inherits, inherits_from);
|
||||
CREATE INDEX fk_alf_acl_acs ON alf_access_control_list (acl_change_set);
|
||||
|
||||
UPDATE alf_access_control_list acl
|
||||
SET acl_id = (acl.id);
|
||||
|
||||
ALTER TABLE alf_access_control_list
|
||||
ADD UNIQUE (acl_id, latest, acl_version);
|
||||
|
||||
-- Create ACL member list
|
||||
CREATE TABLE alf_acl_member
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
acl_id INT8 NOT NULL,
|
||||
ace_id INT8 NOT NULL,
|
||||
pos INT4 NOT NULL,
|
||||
CONSTRAINT fk_alf_aclm_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id),
|
||||
CONSTRAINT fk_alf_aclm_ace FOREIGN KEY (ace_id) REFERENCES alf_access_control_entry (id),
|
||||
PRIMARY KEY (id),
|
||||
UNIQUE(acl_id, ace_id, pos)
|
||||
);
|
||||
CREATE INDEX fk_alf_aclm_acl ON alf_acl_member (acl_id);
|
||||
CREATE INDEX fk_alf_aclm_ace ON alf_acl_member (ace_id);
|
||||
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT alf_access_control_entry_acl_id_key; -- (optional)
|
||||
|
||||
-- Extend ACE
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD COLUMN applies INT4 NOT NULL DEFAULT 0,
|
||||
ADD COLUMN context_id INT8;
|
||||
|
||||
-- remove unused
|
||||
DROP TABLE alf_auth_ext_keys;
|
||||
|
||||
-- remove authority constraint
|
||||
DROP INDEX FKFFF41F99B25A50BF; -- (optional)
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT FKFFF41F99B25A50BF; -- (optional)
|
||||
|
||||
-- not required from 2.1-A
|
||||
-- restructure authority
|
||||
--ALTER TABLE alf_authority RENAME recipient TO authority;
|
||||
--ALTER TABLE alf_authority
|
||||
-- DROP CONSTRAINT alf_authority_pkey,
|
||||
-- ALTER COLUMN authority DROP NOT NULL,
|
||||
-- ADD COLUMN id INT8 NOT NULL DEFAULT NEXTVAL ('hibernate_sequence'),
|
||||
-- ADD COLUMN crc INT8,
|
||||
-- ADD primary key (id),
|
||||
-- ADD UNIQUE (authority, crc);
|
||||
--ALTER TABLE alf_authority ALTER id DROP DEFAULT;
|
||||
--CREATE INDEX idx_alf_auth_aut ON alf_authority (authority);
|
||||
|
||||
-- migrate data - fix up FK refs to authority
|
||||
--UPDATE alf_access_control_entry ace
|
||||
-- set auth_id = (select id from alf_authority a where a.authority = ace.authority_id);
|
||||
|
||||
|
||||
-- migrate data - build equivalent ACL entries
|
||||
INSERT INTO alf_acl_member (id, version, acl_id, ace_id, pos)
|
||||
SELECT
|
||||
NEXTVAL ('hibernate_sequence'), 1, ace.acl_id, ace.id, 0
|
||||
FROM
|
||||
alf_access_control_entry ace
|
||||
JOIN
|
||||
alf_access_control_list acl ON acl.id = ace.acl_id;
|
||||
|
||||
-- Create ACE context
|
||||
CREATE TABLE alf_ace_context
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
class_context VARCHAR(1024),
|
||||
property_context VARCHAR(1024),
|
||||
kvp_context VARCHAR(1024),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
|
||||
-- Create auth aliases table
|
||||
CREATE TABLE alf_authority_alias
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
auth_id INT8 NOT NULL,
|
||||
alias_id INT8 NOT NULL,
|
||||
CONSTRAINT fk_alf_autha_ali FOREIGN KEY (alias_id) REFERENCES alf_authority (id),
|
||||
CONSTRAINT fk_alf_autha_aut FOREIGN KEY (auth_id) REFERENCES alf_authority (id),
|
||||
PRIMARY KEY (id),
|
||||
UNIQUE (auth_id, alias_id)
|
||||
);
|
||||
CREATE INDEX fk_alf_autha_ali ON alf_authority_alias (alias_id);
|
||||
CREATE INDEX fk_alf_autha_aut ON alf_authority_alias (auth_id);
|
||||
|
||||
|
||||
-- Tidy up unused cols on ace tabl e and add the FK contstraint back
|
||||
-- finish take out of ACL_ID
|
||||
ALTER TABLE alf_access_control_entry
|
||||
DROP CONSTRAINT FKFFF41F99B9553F6C,
|
||||
DROP CONSTRAINT FKFFF41F9960601995,
|
||||
DROP COLUMN acl_id
|
||||
;
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD CONSTRAINT fk_alf_ace_auth FOREIGN KEY (authority_id) REFERENCES alf_authority (id),
|
||||
ADD CONSTRAINT fk_alf_ace_perm FOREIGN KEY (permission_id) REFERENCES alf_permission (id),
|
||||
ADD CONSTRAINT fk_alf_ace_ctx FOREIGN KEY (context_id) REFERENCES alf_ace_context (id)
|
||||
;
|
||||
DROP INDEX FKFFF41F99B9553F6C; -- (optional)
|
||||
DROP INDEX FKFFF41F9960601995;
|
||||
CREATE INDEX fk_alf_ace_auth ON alf_access_control_entry (authority_id);
|
||||
CREATE INDEX fk_alf_ace_perm ON alf_access_control_entry (permission_id);
|
||||
CREATE INDEX fk_alf_ace_ctx ON alf_access_control_entry (context_id);
|
||||
|
||||
CREATE TABLE alf_tmp_min_ace (
|
||||
min INT8 NOT NULL,
|
||||
permission_id INT8 NOT NULL,
|
||||
authority_id INT8 NOT NULL,
|
||||
allowed BOOL NOT NULL,
|
||||
applies INT4 NOT NULL,
|
||||
UNIQUE (permission_id, authority_id, allowed, applies)
|
||||
);
|
||||
|
||||
INSERT INTO alf_tmp_min_ace (min, permission_id, authority_id, allowed, applies)
|
||||
SELECT
|
||||
MIN(ace1.id),
|
||||
ace1.permission_id,
|
||||
ace1.authority_id,
|
||||
ace1.allowed,
|
||||
ace1.applies
|
||||
FROM
|
||||
alf_access_control_entry ace1
|
||||
GROUP BY
|
||||
ace1.permission_id, ace1.authority_id, ace1.allowed, ace1.applies
|
||||
;
|
||||
|
||||
|
||||
-- Update members to point to the first use of an access control entry
|
||||
UPDATE alf_acl_member mem
|
||||
SET ace_id = (SELECT help.min FROM alf_access_control_entry ace
|
||||
JOIN alf_tmp_min_ace help
|
||||
ON help.permission_id = ace.permission_id AND
|
||||
help.authority_id = ace.authority_id AND
|
||||
help.allowed = ace.allowed AND
|
||||
help.applies = ace.applies
|
||||
WHERE ace.id = mem.ace_id );
|
||||
|
||||
DROP TABLE alf_tmp_min_ace;
|
||||
|
||||
-- Remove duplicate aces the mysql way (as you can not use the deleted table in the where clause ...)
|
||||
|
||||
CREATE TABLE tmp_to_delete AS
|
||||
SELECT
|
||||
ace.id
|
||||
FROM
|
||||
alf_acl_member mem
|
||||
RIGHT OUTER JOIN alf_access_control_entry ace ON mem.ace_id = ace.id
|
||||
WHERE
|
||||
mem.ace_id IS NULL;
|
||||
DELETE FROM alf_access_control_entry ace USING tmp_to_delete t WHERE ace.id = t.id;
|
||||
DROP TABLE tmp_to_delete;
|
||||
|
||||
-- Add constraint for duplicate acls
|
||||
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD UNIQUE (permission_id, authority_id, allowed, applies, context_id);
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-ACL-From-2.1-A';
|
||||
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-V2.2-ACL-From-2.1-A', 'Manually executed script upgrade V2.2: Update acl schema',
|
||||
0, 82, -1, 120, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,23 @@
|
||||
--
|
||||
-- Title: Ensure the audit table path column is indexed
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.1 Schema 82
|
||||
-- Author: Andy Hind
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
-- Path was previously unused and unindex - new we use it the index is required.
|
||||
|
||||
CREATE INDEX idx_alf_adtf_pth ON alf_audit_fact (path);
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.1-AuditPathIndex';
|
||||
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-V2.1-AuditPathIndex', 'Manually executed script upgrade V2.1: Ensure existence of audit path index',
|
||||
0, 81, -1, 82, null, 'UNKNOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,190 @@
|
||||
--
|
||||
-- Title: Update for permissions schema changes
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.2 Schema 85
|
||||
-- Author: Andy Hind
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
CREATE TABLE alf_acl_change_set (
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
primary key (id)
|
||||
);
|
||||
|
||||
|
||||
-- Add to ACL
|
||||
ALTER TABLE alf_access_control_list
|
||||
ADD COLUMN type INT4 NOT NULL DEFAULT 0,
|
||||
ADD COLUMN latest BOOL NOT NULL DEFAULT TRUE,
|
||||
ADD COLUMN acl_id VARCHAR(36) NOT NULL DEFAULT 'UNSET',
|
||||
ADD COLUMN acl_version INT8 NOT NULL DEFAULT 1,
|
||||
ADD COLUMN inherited_acl INT8,
|
||||
ADD COLUMN is_versioned BOOL NOT NULL DEFAULT FALSE,
|
||||
ADD COLUMN requires_version BOOL NOT NULL DEFAULT FALSE,
|
||||
ADD COLUMN acl_change_set INT8,
|
||||
ADD COLUMN inherits_from INT8,
|
||||
ADD CONSTRAINT fk_alf_acl_acs FOREIGN KEY (acl_change_set) REFERENCES alf_acl_change_set (id);
|
||||
CREATE INDEX idx_alf_acl_inh ON alf_access_control_list (inherits, inherits_from);
|
||||
CREATE INDEX fk_alf_acl_acs ON alf_access_control_list (acl_change_set);
|
||||
|
||||
UPDATE alf_access_control_list acl
|
||||
set acl_id = (acl.id);
|
||||
|
||||
ALTER TABLE alf_access_control_list
|
||||
ADD UNIQUE (acl_id, latest, acl_version);
|
||||
|
||||
-- Create ACL member list
|
||||
CREATE TABLE alf_acl_member (
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
acl_id INT8 NOT NULL,
|
||||
ace_id INT8 NOT NULL,
|
||||
pos INT4 NOT NULL,
|
||||
CONSTRAINT fk_alf_aclm_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id),
|
||||
CONSTRAINT fk_alf_aclm_ace FOREIGN KEY (ace_id) REFERENCES alf_access_control_entry (id),
|
||||
primary key (id),
|
||||
unique(acl_id, ace_id, pos)
|
||||
);
|
||||
CREATE INDEX fk_alf_aclm_acl ON alf_acl_member (acl_id);
|
||||
CREATE INDEX fk_alf_aclm_ace ON alf_acl_member (ace_id);
|
||||
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT alf_access_control_entry_acl_id_key;
|
||||
|
||||
-- Extend ACE
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD COLUMN auth_id INT8 NOT NULL DEFAULT -1,
|
||||
ADD COLUMN applies INT4 NOT NULL DEFAULT 0,
|
||||
ADD COLUMN context_id INT8;
|
||||
|
||||
-- remove unused
|
||||
DROP TABLE alf_auth_ext_keys;
|
||||
|
||||
-- remove authority constraint
|
||||
DROP INDEX FKFFF41F99B25A50BF; -- (optional)
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT FKFFF41F99B25A50BF; -- (optional)
|
||||
|
||||
-- restructure authority
|
||||
ALTER TABLE alf_authority RENAME recipient TO authority;
|
||||
ALTER TABLE alf_authority
|
||||
DROP CONSTRAINT alf_authority_pkey,
|
||||
ALTER COLUMN authority DROP NOT NULL,
|
||||
ADD COLUMN id INT8 NOT NULL DEFAULT NEXTVAL ('hibernate_sequence'),
|
||||
ADD COLUMN crc INT8,
|
||||
ADD primary key (id),
|
||||
ADD UNIQUE (authority, crc);
|
||||
ALTER TABLE alf_authority ALTER id DROP DEFAULT;
|
||||
CREATE INDEX idx_alf_auth_aut ON alf_authority (authority);
|
||||
|
||||
-- migrate data - fix up FK refs to authority
|
||||
UPDATE alf_access_control_entry ace
|
||||
set auth_id = (select id from alf_authority a where a.authority = ace.authority_id);
|
||||
|
||||
|
||||
-- migrate data - build equivalent ACL entries
|
||||
INSERT INTO alf_acl_member (id, version, acl_id, ace_id, pos)
|
||||
select nextval ('hibernate_sequence'), 1, ace.acl_id, ace.id, 0 from alf_access_control_entry ace join alf_access_control_list acl on acl.id = ace.acl_id;
|
||||
|
||||
-- Create ACE context
|
||||
CREATE TABLE alf_ace_context (
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
class_context VARCHAR(1024),
|
||||
property_context VARCHAR(1024),
|
||||
kvp_context VARCHAR(1024),
|
||||
primary key (id)
|
||||
);
|
||||
|
||||
|
||||
-- Create auth aliases table
|
||||
CREATE TABLE alf_authority_alias (
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
auth_id INT8 NOT NULL,
|
||||
alias_id INT8 NOT NULL,
|
||||
CONSTRAINT fk_alf_autha_ali FOREIGN KEY (alias_id) REFERENCES alf_authority (id),
|
||||
CONSTRAINT fk_alf_autha_aut FOREIGN KEY (auth_id) REFERENCES alf_authority (id),
|
||||
primary key (id),
|
||||
UNIQUE (auth_id, alias_id)
|
||||
);
|
||||
CREATE INDEX fk_alf_autha_ali ON alf_authority_alias (alias_id);
|
||||
CREATE INDEX fk_alf_autha_aut ON alf_authority_alias (auth_id);
|
||||
|
||||
|
||||
-- Tidy up unused cols on ace tabl e and add the FK contstraint back
|
||||
-- finish take out of ACL_ID
|
||||
ALTER TABLE alf_access_control_entry
|
||||
DROP CONSTRAINT FKFFF41F99B9553F6C,
|
||||
DROP CONSTRAINT FKFFF41F9960601995,
|
||||
DROP COLUMN acl_id, DROP COLUMN authority_id
|
||||
;
|
||||
ALTER TABLE alf_access_control_entry RENAME auth_id TO authority_id;
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD CONSTRAINT fk_alf_ace_auth FOREIGN KEY (authority_id) REFERENCES alf_authority (id),
|
||||
ADD CONSTRAINT fk_alf_ace_perm FOREIGN KEY (permission_id) REFERENCES alf_permission (id),
|
||||
ADD CONSTRAINT fk_alf_ace_ctx FOREIGN KEY (context_id) REFERENCES alf_ace_context (id)
|
||||
;
|
||||
DROP INDEX FKFFF41F99B9553F6C; -- (optional)
|
||||
DROP INDEX FKFFF41F9960601995;
|
||||
CREATE INDEX fk_alf_ace_auth ON alf_access_control_entry (authority_id);
|
||||
CREATE INDEX fk_alf_ace_perm ON alf_access_control_entry (permission_id);
|
||||
CREATE INDEX fk_alf_ace_ctx ON alf_access_control_entry (context_id);
|
||||
|
||||
CREATE TABLE alf_tmp_min_ace (
|
||||
min INT8 NOT NULL,
|
||||
permission_id INT8 NOT NULL,
|
||||
authority_id INT8 NOT NULL,
|
||||
allowed BOOL NOT NULL,
|
||||
applies INT4 NOT NULL,
|
||||
UNIQUE (permission_id, authority_id, allowed, applies)
|
||||
);
|
||||
|
||||
INSERT INTO alf_tmp_min_ace (min, permission_id, authority_id, allowed, applies)
|
||||
SELECT
|
||||
min(ace1.id),
|
||||
ace1.permission_id,
|
||||
ace1.authority_id,
|
||||
ace1.allowed,
|
||||
ace1.applies
|
||||
FROM
|
||||
alf_access_control_entry ace1
|
||||
GROUP BY
|
||||
ace1.permission_id, ace1.authority_id, ace1.allowed, ace1.applies
|
||||
;
|
||||
|
||||
|
||||
-- Update members to point to the first use of an access control entry
|
||||
UPDATE alf_acl_member mem
|
||||
SET ace_id = (SELECT help.min FROM alf_access_control_entry ace
|
||||
JOIN alf_tmp_min_ace help
|
||||
ON help.permission_id = ace.permission_id AND
|
||||
help.authority_id = ace.authority_id AND
|
||||
help.allowed = ace.allowed AND
|
||||
help.applies = ace.applies
|
||||
WHERE ace.id = mem.ace_id );
|
||||
|
||||
DROP TABLE alf_tmp_min_ace;
|
||||
|
||||
-- Remove duplicate aces the mysql way (as you can not use the deleted table in the where clause ...)
|
||||
|
||||
CREATE TABLE tmp_to_delete AS SELECT ace.id FROM alf_acl_member mem RIGHT OUTER JOIN alf_access_control_entry ace ON mem.ace_id = ace.id WHERE mem.ace_id IS NULL;
|
||||
DELETE FROM alf_access_control_entry ace USING tmp_to_delete t WHERE ace.id = t.id;
|
||||
DROP TABLE tmp_to_delete;
|
||||
|
||||
-- Add constraint for duplicate acls
|
||||
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD UNIQUE (permission_id, authority_id, allowed, applies, context_id);
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-ACL';
|
||||
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-V2.2-ACL', 'Manually executed script upgrade V2.2: Update acl schema',
|
||||
0, 119, -1, 120, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,67 @@
|
||||
--
|
||||
-- Title: Move user name to be part of the association QNAME
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.2 Schema 91
|
||||
-- Author: Andy Hind
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
-- Path was previously unused and unindex - new we use it the index is required.
|
||||
|
||||
UPDATE
|
||||
alf_child_assoc
|
||||
SET
|
||||
qname_ns_id =
|
||||
(
|
||||
SELECT
|
||||
id
|
||||
FROM
|
||||
alf_namespace n
|
||||
WHERE
|
||||
n.uri = 'http://www.alfresco.org/model/content/1.0'
|
||||
),
|
||||
qname_localname =
|
||||
(
|
||||
SELECT
|
||||
LOWER(p.string_value)
|
||||
FROM
|
||||
alf_node_properties p
|
||||
JOIN alf_qname q on p.qname_id = q.id
|
||||
JOIN alf_namespace n on q.ns_id = n.id
|
||||
WHERE
|
||||
p.node_id = alf_child_assoc.child_node_id AND
|
||||
q.local_name ='userName' AND
|
||||
n.uri = 'http://www.alfresco.org/model/content/1.0'
|
||||
)
|
||||
WHERE exists
|
||||
(
|
||||
SELECT
|
||||
0
|
||||
FROM alf_node_properties pp
|
||||
JOIN alf_qname qq on pp.qname_id = qq.id
|
||||
JOIN alf_namespace nn on qq.ns_id = nn.id
|
||||
WHERE
|
||||
pp.node_id = alf_child_assoc.child_node_id AND
|
||||
qq.local_name ='userName' AND
|
||||
nn.uri = 'http://www.alfresco.org/model/content/1.0'
|
||||
)
|
||||
;
|
||||
|
||||
-- Validation query
|
||||
-- select count(*) from alf_child_assoc c
|
||||
-- JOIN alf_node_properties pp ON c.child_node_id = pp.node_id AND c.qname_localname = pp.string_value
|
||||
-- JOIN alf_qname qq on pp.qname_id = qq.id
|
||||
-- JOIN alf_namespace nn on qq.ns_id = nn.id AND c.qname_ns_id = nn.id
|
||||
-- WHERE qq.local_name ='userName' AND nn.uri = 'http://www.alfresco.org/model/content/1.0'
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Person-3';
|
||||
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-V2.2-Person-3', 'Manually executed script upgrade V2.2: Person user name also in the association qname',
|
||||
0, 2005, -1, 2006, null, 'UNKNOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,94 @@
|
||||
--
|
||||
-- Title: Create missing 2.1 tables
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.2 Schema 86
|
||||
-- Author: Derek Hulley
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
-- Upgrade paths that bypass V2.1 will need to have a some tables added in order
|
||||
-- to simplify subsequent upgrade scripts.
|
||||
--
|
||||
|
||||
-- Fix alf_audit_date column names
|
||||
|
||||
ALTER TABLE alf_audit_date RENAME halfYear TO half_year;
|
||||
ALTER TABLE alf_audit_date RENAME year TO full_year;
|
||||
|
||||
-- create other new tables
|
||||
|
||||
create table avm_aspects (
|
||||
id int8 not null,
|
||||
node_id int8,
|
||||
qname varchar(200),
|
||||
primary key (id)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_aspects_new (
|
||||
id int8 not null,
|
||||
name varchar(200) not null,
|
||||
primary key (id, name)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_node_properties (
|
||||
id int8 not null,
|
||||
node_id int8,
|
||||
qname varchar(200),
|
||||
actual_type varchar(15) not null,
|
||||
multi_valued bool not null,
|
||||
persisted_type varchar(15) not null,
|
||||
boolean_value bool,
|
||||
long_value int8,
|
||||
float_value float4,
|
||||
double_value float8,
|
||||
string_value varchar(1024),
|
||||
serializable_value bytea,
|
||||
primary key (id)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_node_properties_new (
|
||||
node_id int8 not null,
|
||||
actual_type varchar(15) not null,
|
||||
multi_valued bool not null,
|
||||
persisted_type varchar(15) not null,
|
||||
boolean_value bool,
|
||||
long_value int8,
|
||||
float_value float4,
|
||||
double_value float8,
|
||||
string_value varchar(1024),
|
||||
serializable_value bytea,
|
||||
qname varchar(200) not null,
|
||||
primary key (node_id, qname)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_store_properties (
|
||||
id int8 not null,
|
||||
avm_store_id int8,
|
||||
qname varchar(200),
|
||||
actual_type varchar(15) not null,
|
||||
multi_valued bool not null,
|
||||
persisted_type varchar(15) not null,
|
||||
boolean_value bool,
|
||||
long_value int8,
|
||||
float_value float4,
|
||||
double_value float8,
|
||||
string_value varchar(1024),
|
||||
serializable_value bytea,
|
||||
primary key (id)
|
||||
); -- (optional)
|
||||
|
||||
-- Add ACL column for AVM tables
|
||||
ALTER TABLE avm_stores
|
||||
ADD COLUMN acl_id int8;
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-0-CreateMissingTables';
|
||||
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-V2.2-0-CreateMissingTables', 'Manually executed script upgrade V2.2: Created missing tables',
|
||||
0, 120, -1, 121, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
File diff suppressed because it is too large
Load Diff
@@ -0,0 +1,671 @@
|
||||
--
|
||||
-- Title: Upgrade V2.2 SP1 or SP2
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V2.2 Schema 91
|
||||
-- Author: Derek Hulley
|
||||
--
|
||||
-- MLText values must be pulled back from attributes into localizable properties.
|
||||
-- NodeStatus has been moved to alf_node.
|
||||
-- Auditable properties have been moved to alf_node.
|
||||
-- alf_node contains the old alf_node_status information.
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
-- -------------------
|
||||
-- Build new Store --
|
||||
-- -------------------
|
||||
|
||||
CREATE TABLE t_alf_store
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
protocol VARCHAR(50) NOT NULL,
|
||||
identifier VARCHAR(100) NOT NULL,
|
||||
root_node_id INT8,
|
||||
PRIMARY KEY (id),
|
||||
CONSTRAINT alf_store_protocol_key UNIQUE (protocol, identifier)
|
||||
);
|
||||
|
||||
-- --------------------------
|
||||
-- Populate the ADM nodes --
|
||||
-- --------------------------
|
||||
|
||||
CREATE TABLE t_alf_node (
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
store_id INT8 NOT NULL,
|
||||
uuid VARCHAR(36) NOT NULL,
|
||||
transaction_id INT8 NOT NULL,
|
||||
node_deleted BOOL NOT NULL,
|
||||
type_qname_id INT8 NOT NULL,
|
||||
acl_id INT8,
|
||||
audit_creator VARCHAR(255),
|
||||
audit_created VARCHAR(30),
|
||||
audit_modifier VARCHAR(255),
|
||||
audit_modified VARCHAR(30),
|
||||
audit_accessed VARCHAR(30),
|
||||
CONSTRAINT fk_alf_node_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id),
|
||||
CONSTRAINT fk_alf_node_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id),
|
||||
CONSTRAINT fk_alf_node_txn FOREIGN KEY (transaction_id) REFERENCES alf_transaction (id),
|
||||
CONSTRAINT fk_alf_node_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id),
|
||||
PRIMARY KEY (id),
|
||||
CONSTRAINT alf_node_store_id_key UNIQUE (store_id, uuid)
|
||||
);
|
||||
CREATE INDEX idx_alf_node_del ON t_alf_node (node_deleted);
|
||||
CREATE INDEX fk_alf_node_acl ON t_alf_node (acl_id);
|
||||
CREATE INDEX fk_alf_node_tqn ON t_alf_node (type_qname_id);
|
||||
CREATE INDEX fk_alf_node_txn ON t_alf_node (transaction_id);
|
||||
CREATE INDEX fk_alf_node_store ON t_alf_node (store_id);
|
||||
|
||||
-- Fill the store table
|
||||
INSERT INTO t_alf_store (id, version, protocol, identifier, root_node_id)
|
||||
SELECT NEXTVAL ('hibernate_sequence'), 1, protocol, identifier, root_node_id FROM alf_store
|
||||
;
|
||||
|
||||
-- Summarize the alf_node_status table
|
||||
CREATE TABLE t_summary_nstat
|
||||
(
|
||||
node_id INT8 NOT NULL,
|
||||
transaction_id INT8 DEFAULT NULL,
|
||||
PRIMARY KEY (node_id)
|
||||
);
|
||||
INSERT INTO t_summary_nstat (node_id, transaction_id)
|
||||
SELECT node_id, transaction_id FROM alf_node_status WHERE node_id IS NOT NULL;
|
||||
|
||||
-- Copy data over
|
||||
INSERT INTO t_alf_node
|
||||
(
|
||||
id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, acl_id,
|
||||
audit_creator, audit_created, audit_modifier, audit_modified, audit_accessed
|
||||
)
|
||||
SELECT
|
||||
n.id, 1, s.id, n.uuid, nstat.transaction_id, false, n.type_qname_id, n.acl_id,
|
||||
null, null, null, null, null
|
||||
FROM
|
||||
alf_node n
|
||||
JOIN t_summary_nstat nstat ON (nstat.node_id = n.id)
|
||||
JOIN t_alf_store s ON (s.protocol = n.protocol AND s.identifier = n.identifier)
|
||||
;
|
||||
DROP TABLE t_summary_nstat;
|
||||
|
||||
-- Hook the store up to the root node
|
||||
ALTER TABLE t_alf_store
|
||||
ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id)
|
||||
;
|
||||
CREATE INDEX fk_alf_store_root ON t_alf_store (root_node_id);
|
||||
|
||||
-- -----------------------------
|
||||
-- Populate Version Counter --
|
||||
-- -----------------------------
|
||||
|
||||
CREATE TABLE t_alf_version_count
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
store_id INT8 NOT NULL,
|
||||
version_count INT4 NOT NULL,
|
||||
CONSTRAINT alf_version_count_store_id_key UNIQUE (store_id),
|
||||
CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
INSERT INTO t_alf_version_count
|
||||
(
|
||||
id, version, store_id, version_count
|
||||
)
|
||||
SELECT
|
||||
NEXTVAL ('hibernate_sequence'), 1, s.id, vc.version_count
|
||||
FROM
|
||||
alf_version_count vc
|
||||
JOIN t_alf_store s ON (s.protocol = vc.protocol AND s.identifier = vc.identifier)
|
||||
;
|
||||
|
||||
DROP TABLE alf_version_count;
|
||||
ALTER TABLE t_alf_version_count RENAME TO alf_version_count;
|
||||
|
||||
-- -----------------------------
|
||||
-- Populate the Child Assocs --
|
||||
-- -----------------------------
|
||||
|
||||
CREATE TABLE t_alf_child_assoc
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
parent_node_id INT8 NOT NULL,
|
||||
type_qname_id INT8 NOT NULL,
|
||||
child_node_name_crc INT8 NOT NULL,
|
||||
child_node_name VARCHAR(50) NOT NULL,
|
||||
child_node_id INT8 NOT NULL,
|
||||
qname_ns_id INT8 NOT NULL,
|
||||
qname_localname VARCHAR(255) NOT NULL,
|
||||
is_primary BOOL,
|
||||
assoc_index INT4,
|
||||
CONSTRAINT fk_alf_cass_pnode foreign key (parent_node_id) REFERENCES t_alf_node (id),
|
||||
CONSTRAINT fk_alf_cass_cnode foreign key (child_node_id) REFERENCES t_alf_node (id),
|
||||
CONSTRAINT fk_alf_cass_tqn foreign key (type_qname_id) REFERENCES alf_qname (id),
|
||||
CONSTRAINT fk_alf_cass_qnns foreign key (qname_ns_id) REFERENCES alf_namespace (id),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
CREATE INDEX idx_alf_cass_qnln ON t_alf_child_assoc (qname_localname);
|
||||
CREATE INDEX fk_alf_cass_pnode ON t_alf_child_assoc (parent_node_id);
|
||||
CREATE INDEX fk_alf_cass_cnode ON t_alf_child_assoc (child_node_id);
|
||||
CREATE INDEX fk_alf_cass_tqn ON t_alf_child_assoc (type_qname_id);
|
||||
CREATE INDEX fk_alf_cass_qnns ON t_alf_child_assoc (qname_ns_id);
|
||||
|
||||
INSERT INTO t_alf_child_assoc
|
||||
(
|
||||
id, version,
|
||||
parent_node_id,
|
||||
type_qname_id,
|
||||
child_node_name_crc, child_node_name,
|
||||
child_node_id,
|
||||
qname_ns_id, qname_localname,
|
||||
is_primary, assoc_index
|
||||
)
|
||||
SELECT
|
||||
ca.id, 1,
|
||||
ca.parent_node_id,
|
||||
ca.type_qname_id,
|
||||
ca.child_node_name_crc, ca.child_node_name,
|
||||
ca.child_node_id,
|
||||
ca.qname_ns_id, ca.qname_localname,
|
||||
ca.is_primary, ca.assoc_index
|
||||
FROM
|
||||
alf_child_assoc ca
|
||||
;
|
||||
|
||||
-- Clean up
|
||||
DROP TABLE alf_child_assoc;
|
||||
ALTER TABLE t_alf_child_assoc RENAME TO alf_child_assoc;
|
||||
ALTER TABLE alf_child_assoc
|
||||
ADD CONSTRAINT alf_child_assoc_parent_node_id_key UNIQUE (parent_node_id, type_qname_id, child_node_name_crc, child_node_name);
|
||||
|
||||
-- ----------------------------
|
||||
-- Populate the Node Assocs --
|
||||
-- ----------------------------
|
||||
|
||||
CREATE TABLE t_alf_node_assoc
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
source_node_id INT8 NOT NULL,
|
||||
target_node_id INT8 NOT NULL,
|
||||
type_qname_id INT8 NOT NULL,
|
||||
CONSTRAINT fk_alf_nass_snode FOREIGN KEY (source_node_id) REFERENCES t_alf_node (id),
|
||||
CONSTRAINT fk_alf_nass_tnode FOREIGN KEY (target_node_id) REFERENCES t_alf_node (id),
|
||||
CONSTRAINT fk_alf_nass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
CREATE INDEX fk_alf_nass_snode ON t_alf_node_assoc (source_node_id);
|
||||
CREATE INDEX fk_alf_nass_tnode ON t_alf_node_assoc (target_node_id);
|
||||
CREATE INDEX fk_alf_nass_tqn ON t_alf_node_assoc (type_qname_id);
|
||||
|
||||
INSERT INTO t_alf_node_assoc
|
||||
(
|
||||
id, version,
|
||||
source_node_id, target_node_id,
|
||||
type_qname_id
|
||||
)
|
||||
SELECT
|
||||
na.id, 1,
|
||||
na.source_node_id, na.target_node_id,
|
||||
na.type_qname_id
|
||||
FROM
|
||||
alf_node_assoc na
|
||||
;
|
||||
|
||||
-- Clean up
|
||||
DROP TABLE alf_node_assoc;
|
||||
ALTER TABLE t_alf_node_assoc RENAME TO alf_node_assoc;
|
||||
ALTER TABLE alf_node_assoc
|
||||
ADD CONSTRAINT alf_node_assoc_source_node_id_key UNIQUE (source_node_id, target_node_id, type_qname_id);
|
||||
|
||||
-- ----------------------------
|
||||
-- Populate the Usage Deltas --
|
||||
-- ----------------------------
|
||||
|
||||
CREATE TABLE t_alf_usage_delta
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL,
|
||||
node_id INT8 NOT NULL,
|
||||
delta_size INT8 NOT NULL,
|
||||
CONSTRAINT fk_alf_usaged_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
CREATE INDEX fk_alf_usaged_n ON t_alf_usage_delta (node_id);
|
||||
|
||||
INSERT INTO t_alf_usage_delta
|
||||
(
|
||||
id, version,
|
||||
node_id,
|
||||
delta_size
|
||||
)
|
||||
SELECT
|
||||
ud.id, 1,
|
||||
ud.node_id,
|
||||
ud.delta_size
|
||||
FROM
|
||||
alf_usage_delta ud
|
||||
; -- (optional)
|
||||
|
||||
-- Clean up
|
||||
DROP TABLE alf_usage_delta; -- (optional)
|
||||
ALTER TABLE t_alf_usage_delta RENAME TO alf_usage_delta;
|
||||
|
||||
-- -----------------------------
|
||||
-- Populate the Node Aspects --
|
||||
-- -----------------------------
|
||||
|
||||
CREATE TABLE t_alf_node_aspects
|
||||
(
|
||||
node_id INT8 NOT NULL,
|
||||
qname_id INT8 NOT NULL,
|
||||
CONSTRAINT fk_alf_nasp_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id),
|
||||
CONSTRAINT fk_alf_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id),
|
||||
PRIMARY KEY (node_id, qname_id)
|
||||
);
|
||||
CREATE INDEX fk_alf_nasp_n ON t_alf_node_aspects (node_id);
|
||||
CREATE INDEX fk_alf_nasp_qn ON t_alf_node_aspects (qname_id);
|
||||
|
||||
-- Note the omission of sys:referencable. This is implicit.
|
||||
INSERT INTO t_alf_node_aspects
|
||||
(
|
||||
node_id, qname_id
|
||||
)
|
||||
SELECT
|
||||
na.node_id,
|
||||
qname_id
|
||||
FROM
|
||||
alf_node_aspects na
|
||||
JOIN alf_qname qn ON (na.qname_id = qn.id)
|
||||
JOIN alf_namespace ns ON (qn.ns_id = ns.id)
|
||||
WHERE
|
||||
ns.uri != 'http://www.alfresco.org/model/system/1.0' OR
|
||||
qn.local_name != 'referenceable'
|
||||
;
|
||||
|
||||
-- Clean up
|
||||
DROP TABLE alf_node_aspects;
|
||||
ALTER TABLE t_alf_node_aspects RENAME TO alf_node_aspects;
|
||||
|
||||
-- ---------------------------------
|
||||
-- Populate the AVM Node Aspects --
|
||||
-- ---------------------------------
|
||||
|
||||
CREATE TABLE t_avm_aspects
|
||||
(
|
||||
node_id INT8 NOT NULL,
|
||||
qname_id INT8 NOT NULL,
|
||||
CONSTRAINT fk_avm_nasp_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id),
|
||||
CONSTRAINT fk_avm_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id),
|
||||
PRIMARY KEY (node_id, qname_id)
|
||||
);
|
||||
CREATE INDEX fk_avm_nasp_n ON t_avm_aspects (node_id);
|
||||
CREATE INDEX fk_avm_nasp_qn ON t_avm_aspects (qname_id);
|
||||
|
||||
INSERT INTO t_avm_aspects
|
||||
(
|
||||
node_id, qname_id
|
||||
)
|
||||
SELECT
|
||||
anew.id,
|
||||
anew.qname_id
|
||||
FROM
|
||||
avm_aspects_new anew
|
||||
;
|
||||
|
||||
-- Clean up
|
||||
DROP TABLE avm_aspects;
|
||||
DROP TABLE avm_aspects_new;
|
||||
ALTER TABLE t_avm_aspects RENAME TO avm_aspects;
|
||||
|
||||
-- ----------------------------------
|
||||
-- Migrate Sundry Property Tables --
|
||||
-- ----------------------------------
|
||||
|
||||
-- Modify the avm_store_properties table
|
||||
CREATE TABLE t_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,
|
||||
CONSTRAINT fk_avm_sprop_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id),
|
||||
CONSTRAINT fk_avm_sprop_qname FOREIGN KEY (qname_id) REFERENCES alf_qname (id),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
CREATE INDEX fk_avm_sprop_store ON t_avm_store_properties (avm_store_id);
|
||||
CREATE INDEX fk_avm_sprop_qname ON t_avm_store_properties (qname_id);
|
||||
|
||||
INSERT INTO t_avm_store_properties
|
||||
(
|
||||
id,
|
||||
avm_store_id,
|
||||
qname_id,
|
||||
actual_type_n, persisted_type_n,
|
||||
multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value
|
||||
)
|
||||
SELECT
|
||||
NEXTVAL ('hibernate_sequence'),
|
||||
p.avm_store_id,
|
||||
p.qname_id,
|
||||
p.actual_type_n, p.persisted_type_n,
|
||||
p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value
|
||||
FROM
|
||||
avm_store_properties p
|
||||
;
|
||||
DROP TABLE avm_store_properties;
|
||||
ALTER TABLE t_avm_store_properties RENAME TO avm_store_properties;
|
||||
|
||||
-- Modify the avm_node_properties_new table
|
||||
CREATE TABLE t_avm_node_properties
|
||||
(
|
||||
node_id INT8 NOT NULL,
|
||||
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,
|
||||
CONSTRAINT fk_avm_nprop_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id),
|
||||
CONSTRAINT fk_avm_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id),
|
||||
PRIMARY KEY (node_id, qname_id)
|
||||
);
|
||||
CREATE INDEX fk_avm_nprop_n ON t_avm_node_properties (node_id);
|
||||
CREATE INDEX fk_avm_nprop_qn ON t_avm_node_properties (qname_id);
|
||||
|
||||
INSERT INTO t_avm_node_properties
|
||||
(
|
||||
node_id,
|
||||
qname_id,
|
||||
actual_type_n, persisted_type_n,
|
||||
multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value
|
||||
)
|
||||
SELECT
|
||||
p.node_id,
|
||||
p.qname_id,
|
||||
p.actual_type_n, p.persisted_type_n,
|
||||
p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value
|
||||
FROM
|
||||
avm_node_properties_new p
|
||||
;
|
||||
|
||||
DROP TABLE avm_node_properties_new;
|
||||
DROP TABLE avm_node_properties;
|
||||
ALTER TABLE t_avm_node_properties RENAME TO avm_node_properties;
|
||||
|
||||
|
||||
-- -----------------
|
||||
-- Build Locales --
|
||||
-- -----------------
|
||||
|
||||
CREATE TABLE alf_locale
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
version INT8 NOT NULL DEFAULT 1,
|
||||
locale_str VARCHAR(20) NOT NULL,
|
||||
PRIMARY KEY (id),
|
||||
UNIQUE (locale_str)
|
||||
);
|
||||
|
||||
INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default');
|
||||
|
||||
-- Locales come from the attribute table which was used to support MLText persistence
|
||||
INSERT INTO alf_locale (id, locale_str)
|
||||
SELECT NEXTVAL ('hibernate_sequence'), mkey
|
||||
FROM
|
||||
(SELECT DISTINCT(ma.mkey)
|
||||
FROM alf_node_properties np
|
||||
JOIN alf_attributes a1 ON (np.attribute_value = a1.id)
|
||||
JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id)
|
||||
) X
|
||||
;
|
||||
|
||||
-- -------------------------------
|
||||
-- Migrate ADM Property Tables --
|
||||
-- -------------------------------
|
||||
|
||||
CREATE TABLE t_alf_node_properties
|
||||
(
|
||||
node_id INT8 NOT NULL,
|
||||
qname_id INT8 NOT NULL,
|
||||
locale_id INT8 NOT NULL,
|
||||
list_index INT4 NOT NULL,
|
||||
actual_type_n INT4 NOT NULL,
|
||||
persisted_type_n INT4 NOT NULL,
|
||||
boolean_value BOOL,
|
||||
long_value INT8,
|
||||
float_value FLOAT4,
|
||||
double_value FLOAT8,
|
||||
string_value VARCHAR(1024),
|
||||
serializable_value BYTEA,
|
||||
CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id),
|
||||
CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id),
|
||||
CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id),
|
||||
PRIMARY KEY (node_id, qname_id, list_index, locale_id)
|
||||
);
|
||||
CREATE INDEX fk_alf_nprop_n ON t_alf_node_properties (node_id);
|
||||
CREATE INDEX fk_alf_nprop_qn ON t_alf_node_properties (qname_id);
|
||||
CREATE INDEX fk_alf_nprop_loc ON t_alf_node_properties (locale_id);
|
||||
|
||||
-- Copy values over
|
||||
INSERT INTO t_alf_node_properties
|
||||
(
|
||||
node_id, qname_id, locale_id, list_index,
|
||||
actual_type_n, persisted_type_n,
|
||||
boolean_value, long_value, float_value, double_value,
|
||||
string_value,
|
||||
serializable_value
|
||||
)
|
||||
SELECT
|
||||
np.node_id, np.qname_id, 1, -1,
|
||||
np.actual_type_n, np.persisted_type_n,
|
||||
np.boolean_value, np.long_value, np.float_value, np.double_value,
|
||||
np.string_value,
|
||||
np.serializable_value
|
||||
FROM
|
||||
alf_node_properties np
|
||||
WHERE
|
||||
np.attribute_value IS NULL
|
||||
;
|
||||
|
||||
UPDATE t_alf_node n SET audit_creator =
|
||||
(
|
||||
SELECT
|
||||
string_value
|
||||
FROM
|
||||
t_alf_node_properties np
|
||||
JOIN alf_qname qn ON (np.qname_id = qn.id)
|
||||
JOIN alf_namespace ns ON (qn.ns_id = ns.id)
|
||||
WHERE
|
||||
np.node_id = n.id AND
|
||||
ns.uri = 'http://www.alfresco.org/model/content/1.0' AND
|
||||
qn.local_name = 'creator'
|
||||
);
|
||||
UPDATE t_alf_node n SET audit_created =
|
||||
(
|
||||
SELECT
|
||||
string_value
|
||||
FROM
|
||||
t_alf_node_properties np
|
||||
JOIN alf_qname qn ON (np.qname_id = qn.id)
|
||||
JOIN alf_namespace ns ON (qn.ns_id = ns.id)
|
||||
WHERE
|
||||
np.node_id = n.id AND
|
||||
ns.uri = 'http://www.alfresco.org/model/content/1.0' AND
|
||||
qn.local_name = 'created'
|
||||
);
|
||||
UPDATE t_alf_node n SET audit_modifier =
|
||||
(
|
||||
SELECT
|
||||
string_value
|
||||
FROM
|
||||
t_alf_node_properties np
|
||||
JOIN alf_qname qn ON (np.qname_id = qn.id)
|
||||
JOIN alf_namespace ns ON (qn.ns_id = ns.id)
|
||||
WHERE
|
||||
np.node_id = n.id AND
|
||||
ns.uri = 'http://www.alfresco.org/model/content/1.0' AND
|
||||
qn.local_name = 'modifier'
|
||||
);
|
||||
UPDATE t_alf_node n SET audit_modified =
|
||||
(
|
||||
SELECT
|
||||
string_value
|
||||
FROM
|
||||
t_alf_node_properties np
|
||||
JOIN alf_qname qn ON (np.qname_id = qn.id)
|
||||
JOIN alf_namespace ns ON (qn.ns_id = ns.id)
|
||||
WHERE
|
||||
np.node_id = n.id AND
|
||||
ns.uri = 'http://www.alfresco.org/model/content/1.0' AND
|
||||
qn.local_name = 'modified'
|
||||
);
|
||||
-- Remove the unused cm:auditable properties
|
||||
DELETE
|
||||
FROM t_alf_node_properties
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1 FROM alf_qname, alf_namespace
|
||||
WHERE
|
||||
t_alf_node_properties.qname_id = alf_qname.id AND
|
||||
alf_qname.ns_id = alf_namespace.id AND
|
||||
alf_namespace.uri = 'http://www.alfresco.org/model/content/1.0' AND
|
||||
alf_qname.local_name IN ('creator', 'created', 'modifier', 'modified')
|
||||
);
|
||||
|
||||
-- Copy all MLText values over
|
||||
INSERT INTO t_alf_node_properties
|
||||
(
|
||||
node_id, qname_id, list_index, locale_id,
|
||||
actual_type_n, persisted_type_n,
|
||||
boolean_value, long_value, float_value, double_value,
|
||||
string_value,
|
||||
serializable_value
|
||||
)
|
||||
SELECT
|
||||
np.node_id, np.qname_id, -1, loc.id,
|
||||
-1, 0,
|
||||
FALSE, 0, 0, 0,
|
||||
a2.string_value,
|
||||
a2.serializable_value
|
||||
FROM
|
||||
alf_node_properties np
|
||||
JOIN alf_attributes a1 ON (np.attribute_value = a1.id)
|
||||
JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id)
|
||||
JOIN alf_locale loc ON (ma.mkey = loc.locale_str)
|
||||
JOIN alf_attributes a2 ON (ma.attribute_id = a2.id)
|
||||
; -- (OPTIONAL)
|
||||
UPDATE t_alf_node_properties
|
||||
SET actual_type_n = 6, persisted_type_n = 6, serializable_value = NULL
|
||||
WHERE actual_type_n = -1 AND string_value IS NOT NULL
|
||||
;
|
||||
UPDATE t_alf_node_properties
|
||||
SET actual_type_n = 9, persisted_type_n = 9
|
||||
WHERE actual_type_n = -1 AND serializable_value IS NOT NULL
|
||||
;
|
||||
DELETE FROM t_alf_node_properties WHERE actual_type_n = -1;
|
||||
|
||||
-- Delete the node properties and move the fixed values over
|
||||
DROP TABLE alf_node_properties;
|
||||
ALTER TABLE t_alf_node_properties RENAME TO alf_node_properties;
|
||||
|
||||
CREATE TABLE t_del_attributes
|
||||
(
|
||||
id INT8 NOT NULL,
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
INSERT INTO t_del_attributes
|
||||
SELECT id FROM alf_attributes WHERE type = 'M'
|
||||
;
|
||||
DELETE FROM t_del_attributes
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1
|
||||
FROM alf_map_attribute_entries ma
|
||||
WHERE ma.attribute_id = t_del_attributes.id
|
||||
);
|
||||
DELETE FROM t_del_attributes
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1
|
||||
FROM alf_list_attribute_entries la
|
||||
WHERE la.attribute_id = t_del_attributes.id
|
||||
);
|
||||
DELETE FROM t_del_attributes
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1
|
||||
FROM alf_global_attributes ga
|
||||
WHERE ga.attribute = t_del_attributes.id
|
||||
);
|
||||
INSERT INTO t_del_attributes
|
||||
SELECT a.id FROM t_del_attributes t
|
||||
JOIN alf_map_attribute_entries ma ON (ma.map_id = t.id)
|
||||
JOIN alf_attributes a ON (ma.attribute_id = a.id)
|
||||
;
|
||||
DELETE FROM alf_map_attribute_entries
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1
|
||||
FROM t_del_attributes t
|
||||
WHERE alf_map_attribute_entries.map_id = t.id
|
||||
);
|
||||
DELETE FROM alf_list_attribute_entries
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1
|
||||
FROM t_del_attributes t
|
||||
WHERE alf_list_attribute_entries.list_id = t.id
|
||||
);
|
||||
DELETE FROM alf_attributes
|
||||
WHERE EXISTS
|
||||
(
|
||||
SELECT 1
|
||||
FROM t_del_attributes t
|
||||
WHERE alf_attributes.id = t.id
|
||||
);
|
||||
DROP TABLE t_del_attributes;
|
||||
|
||||
-- ------------------
|
||||
-- Final clean up --
|
||||
-- ------------------
|
||||
DROP TABLE alf_node_status;
|
||||
ALTER TABLE alf_store DROP CONSTRAINT fk_alf_store_rn;
|
||||
DROP TABLE alf_node;
|
||||
ALTER TABLE t_alf_node RENAME TO alf_node;
|
||||
DROP TABLE alf_store;
|
||||
ALTER TABLE t_alf_store RENAME TO alf_store;
|
||||
CREATE INDEX idx_alf_auth_aut ON alf_authority (authority); -- (optional)
|
||||
|
||||
-- ----------------
|
||||
-- JBPM Differences
|
||||
-- ----------------
|
||||
ALTER TABLE jbpm_processinstance DROP CONSTRAINT jbpm_processinstance_key__key; -- (optional)
|
||||
CREATE INDEX idx_procin_key ON jbpm_processinstance (key_); -- (optional)
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Upgrade-From-2.2SP1';
|
||||
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-V2.2-Upgrade-From-2.2SP1', 'Manually executed script upgrade V2.2: Upgraded V2.2 SP1 or SP2',
|
||||
86, 90, -1, 91, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,21 @@
|
||||
--
|
||||
-- Title: Increase the ipAddress field length to allow IPv6 adresses
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V3.1 schema 1009
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
ALTER TABLE alf_server ALTER COLUMN ip_address TYPE varchar(39);
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.1-Allow-IPv6';
|
||||
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.1-Allow-IPv6', 'Manually executed script upgrade V3.1: Increase the ipAddress field length',
|
||||
0, 1009, -1, 1010, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,40 @@
|
||||
--
|
||||
-- Title: Upgrade to V3.2 - upgrade jbpm tables to jbpm 3.3.1
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V3.2 schema 2013
|
||||
-- Author:
|
||||
--
|
||||
-- upgrade jbpm tables to jbpm 3.3.1
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
-- we mark next statement as optional to not fail the upgrade from 2.1.a (as it doesn't contain jbpm)
|
||||
alter table JBPM_ACTION alter column EXPRESSION_ type text; -- (optional)
|
||||
alter table JBPM_COMMENT alter column MESSAGE_ type text; -- (optional)
|
||||
alter table JBPM_DELEGATION alter column CLASSNAME_ type text; -- (optional)
|
||||
alter table JBPM_DELEGATION alter column CONFIGURATION_ type text; -- (optional)
|
||||
alter table JBPM_EXCEPTIONHANDLER alter column EXCEPTIONCLASSNAME_ type text; -- (optional)
|
||||
alter table JBPM_JOB alter column EXCEPTION_ type text; -- (optional)
|
||||
alter table JBPM_LOG alter column MESSAGE_ type text,
|
||||
alter column EXCEPTION_ type text,
|
||||
alter column OLDSTRINGVALUE_ type text,
|
||||
alter column NEWSTRINGVALUE_ type text; -- (optional)
|
||||
alter table JBPM_MODULEDEFINITION alter column NAME_ type varchar(255); -- (optional)
|
||||
alter table JBPM_NODE alter column DESCRIPTION_ type text; -- (optional)
|
||||
alter table JBPM_PROCESSDEFINITION alter column DESCRIPTION_ type text; -- (optional)
|
||||
alter table JBPM_TASK alter column DESCRIPTION_ type text; -- (optional)
|
||||
alter table JBPM_TASKINSTANCE alter column DESCRIPTION_ type text; -- (optional)
|
||||
alter table JBPM_TRANSITION alter column DESCRIPTION_ type text; -- (optional)
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-Upgrade-JBPM';
|
||||
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-Upgrade-JBPM', 'Manually executed script upgrade V3.2 to jbpm version 3.3.1 usage',
|
||||
0, 2017, -1, 2018, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,24 @@
|
||||
--
|
||||
-- Title: Upgrade to V3.2 - modify AVM mimetype
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V3.2 schema 2017
|
||||
-- Author:
|
||||
--
|
||||
-- modify AVM mimetype (increase column size)
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
ALTER TABLE avm_nodes ALTER COLUMN mime_type TYPE VARCHAR(100);
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-Modify-AVM-MimeType';
|
||||
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-Modify-AVM-MimeType', 'Manually executed script upgrade V3.2 to modify AVM mimetype',
|
||||
0, 2016, -1, 2017, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
@@ -0,0 +1,31 @@
|
||||
--
|
||||
-- Title: Upgrade to V3.2 - Remove AVM Issuer
|
||||
-- Database: PostgreSQL
|
||||
-- Since: V3.2 schema 2008
|
||||
-- Author: janv
|
||||
--
|
||||
-- remove AVM node issuer - replace with sequence
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
-- update sequence, if needed
|
||||
|
||||
SELECT SETVAL('hibernate_sequence', GREATEST((MAX(id)+1), NEXTVAL('hibernate_sequence'))) FROM avm_nodes;
|
||||
|
||||
-- drop issuer table
|
||||
|
||||
DROP TABLE avm_issuer_ids;
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V3.2-Remove-AVM-Issuer';
|
||||
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-Remove-AVM-Issuer', 'Manually executed script upgrade V3.2 to remove AVM Issuer',
|
||||
0, 2007, -1, 2008, null, 'UNKOWN', TRUE, TRUE, 'Script completed'
|
||||
);
|
||||
|
Reference in New Issue
Block a user