diff --git a/config/alfresco/bootstrap-context.xml b/config/alfresco/bootstrap-context.xml index 2886791b52..efaf413c97 100644 --- a/config/alfresco/bootstrap-context.xml +++ b/config/alfresco/bootstrap-context.xml @@ -64,23 +64,14 @@ - - - + + - diff --git a/config/alfresco/dbscripts/create/2.2/org.hibernate.dialect.Dialect/AlfrescoPostCreate-2.2-MappedFKIndexes.sql b/config/alfresco/dbscripts/create/2.2/org.hibernate.dialect.Dialect/AlfrescoPostCreate-2.2-MappedFKIndexes.sql index e70b358cd9..2eb5b4e0be 100644 --- a/config/alfresco/dbscripts/create/2.2/org.hibernate.dialect.Dialect/AlfrescoPostCreate-2.2-MappedFKIndexes.sql +++ b/config/alfresco/dbscripts/create/2.2/org.hibernate.dialect.Dialect/AlfrescoPostCreate-2.2-MappedFKIndexes.sql @@ -18,6 +18,8 @@ CREATE INDEX fk_alf_acl_acs ON alf_access_control_list (acl_change_set); CREATE INDEX fk_alf_aclm_acl ON alf_acl_member (acl_id); CREATE INDEX fk_alf_aclm_ace ON alf_acl_member (ace_id); +CREATE INDEX fk_alf_attr_acl ON alf_attributes (acl_id); + CREATE INDEX fk_alf_adtf_src ON alf_audit_fact (audit_source_id); CREATE INDEX fk_alf_adtf_date ON alf_audit_fact (audit_date_id); CREATE INDEX fk_alf_adtf_conf ON alf_audit_fact (audit_conf_id); @@ -25,48 +27,44 @@ CREATE INDEX fk_alf_adtf_conf ON alf_audit_fact (audit_conf_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); -CREATE INDEX fk_alf_ca_pnode ON alf_child_assoc (parent_node_id); -CREATE INDEX fk_alf_ca_tqn ON alf_child_assoc (type_qname_id); -CREATE INDEX fk_alf_ca_qn_ns ON alf_child_assoc (qname_ns_id); -CREATE INDEX fk_alf_ca_cnode ON alf_child_assoc (child_node_id); - -CREATE INDEX fk_alf_attr_acl ON alf_attributes (acl_id); +CREATE INDEX fk_alf_cass_pnode ON alf_child_assoc (parent_node_id); +CREATE INDEX fk_alf_cass_tqn ON alf_child_assoc (type_qname_id); +CREATE INDEX fk_alf_cass_qnns ON alf_child_assoc (qname_ns_id); +CREATE INDEX fk_alf_cass_cnode ON alf_child_assoc (child_node_id); -- alf_global_attributes.attribute is declared unique. Indexes may automatically have been created. CREATE INDEX fk_alf_gatt_att ON alf_global_attributes (attribute); -- (optional) CREATE INDEX fk_alf_lent_att ON alf_list_attribute_entries (attribute_id); - CREATE INDEX fk_alf_lent_latt ON alf_list_attribute_entries (list_id); CREATE INDEX fk_alf_matt_matt ON alf_map_attribute_entries (map_id); CREATE INDEX fk_alf_matt_att ON alf_map_attribute_entries (attribute_id); -CREATE INDEX fk_alf_n_acl ON alf_node (acl_id); -CREATE INDEX fk_alf_n_tqname ON alf_node (type_qname_id); -CREATE INDEX fk_alf_n_store ON alf_node (protocol, identifier); +CREATE INDEX fk_alf_node_acl ON alf_node (acl_id); +CREATE INDEX fk_alf_node_tqn ON alf_node (type_qname_id); +CREATE INDEX fk_alf_node_txn ON alf_node (transaction_id); +CREATE INDEX fk_alf_node_store ON alf_node (store_id); -CREATE INDEX fk_alf_n_asp ON alf_node_aspects (node_id); -CREATE INDEX fk_alf_na_snode ON alf_node_assoc (source_node_id); +CREATE INDEX fk_alf_nasp_n ON alf_node_aspects (node_id); -CREATE INDEX fk_alf_na_tqn ON alf_node_assoc (type_qname_id); -CREATE INDEX fk_alf_na_tnode ON alf_node_assoc (target_node_id); - -CREATE INDEX fk_alf_perm_tqn ON alf_permission (type_qname_id); +CREATE INDEX fk_alf_nass_snode ON alf_node_assoc (source_node_id); +CREATE INDEX fk_alf_nass_tqn ON alf_node_assoc (type_qname_id); +CREATE INDEX fk_alf_nass_tnode ON alf_node_assoc (target_node_id); CREATE INDEX fk_alf_nprop_n ON alf_node_properties (node_id); -CREATE INDEX fk_alf_ns_node ON alf_node_status (node_id); -CREATE INDEX fk_alf_ns_trans ON alf_node_status (transaction_id); +CREATE INDEX fk_alf_perm_tqn ON alf_permission (type_qname_id); CREATE INDEX fk_alf_qname_ns ON alf_qname (ns_id); -CREATE INDEX fk_alf_store_rn ON alf_store (root_node_id); +CREATE INDEX fk_alf_store_root ON alf_store (root_node_id); CREATE INDEX fk_alf_txn_svr ON alf_transaction (server_id); -CREATE INDEX fk_avm_asp_node ON avm_aspects (node_id); -CREATE INDEX fk_avm_asp_n ON avm_aspects_new (id); +CREATE INDEX fk_alf_vc_store ON alf_version_count (store_id); + +CREATE INDEX fk_avm_nasp_n ON avm_aspects (node_id); CREATE INDEX fk_avm_ce_child ON avm_child_entries (child_id); CREATE INDEX fk_avm_ce_parent ON avm_child_entries (parent_id); @@ -77,14 +75,13 @@ CREATE INDEX fk_avm_hl_ancestor ON avm_history_links (ancestor); CREATE INDEX fk_avm_ml_to ON avm_merge_links (mto); CREATE INDEX fk_avm_ml_from ON avm_merge_links (mfrom); -CREATE INDEX fk_avm_np_node ON avm_node_properties (node_id); -CREATE INDEX fk_avm_np_n ON avm_node_properties_new (node_id); +CREATE INDEX fk_avm_nprop_n ON avm_node_properties (node_id); CREATE INDEX fk_avm_n_acl ON avm_nodes (acl_id); CREATE INDEX fk_avm_n_store ON avm_nodes (store_new_id); -CREATE INDEX fk_avm_sp_qname ON avm_store_properties (qname_id); -CREATE INDEX fk_avm_sp_store ON avm_store_properties (avm_store_id); +CREATE INDEX fk_avm_sprop_qname ON avm_store_properties (qname_id); +CREATE INDEX fk_avm_sprop_store ON avm_store_properties (avm_store_id); CREATE INDEX fk_avm_s_acl ON avm_stores (acl_id); CREATE INDEX fk_avm_s_root ON avm_stores (current_root_id); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/upgrade-4-extra-indexes-and-constraints.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/upgrade-4-extra-indexes-and-constraints.sql deleted file mode 100644 index 904b865aaa..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/upgrade-4-extra-indexes-and-constraints.sql +++ /dev/null @@ -1,86 +0,0 @@ --- --- Title: Create additional indexes and constraints --- Database: Generic --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - -CREATE INDEX idx_alf_adtd_woy ON alf_audit_date (week_of_year); - -CREATE INDEX idx_alf_adtd_q ON alf_audit_date (quarter); - -CREATE INDEX idx_alf_adtd_wom ON alf_audit_date (week_of_month); - -CREATE INDEX idx_alf_adtd_dom ON alf_audit_date (day_of_month); - -CREATE INDEX idx_alf_adtd_doy ON alf_audit_date (day_of_year); - -CREATE INDEX idx_alf_adtd_dow ON alf_audit_date (day_of_week); - -CREATE INDEX idx_alf_adtd_m ON alf_audit_date (month); - -CREATE INDEX idx_alf_adtd_hy ON alf_audit_date (half_year); - -CREATE INDEX idx_alf_adtd_fy ON alf_audit_date (full_year); - -CREATE INDEX idx_alf_adtd_dat ON alf_audit_date (date_only); - -CREATE INDEX idx_alf_adtf_ref ON alf_audit_fact (store_protocol, store_id, node_uuid); - -CREATE INDEX idx_alf_adtf_usr ON alf_audit_fact (user_id); - -CREATE INDEX idx_alf_adts_met ON alf_audit_source (method); - -CREATE INDEX idx_alf_adts_ser ON alf_audit_source (service); - -CREATE INDEX idx_alf_adts_app ON alf_audit_source (application); - -CREATE INDEX idx_alf_ca_qn_ln ON alf_child_assoc (qname_localname); - -CREATE INDEX idx_alf_txn_ctms ON alf_transaction (commit_time_ms); - - -- The was 'idx_avm_lyr_indn'. Rename it if you have the old name. -CREATE INDEX idx_avm_n_pi on avm_nodes (primary_indirection); - -CREATE INDEX idx_avm_np_name ON avm_node_properties (qname); - -CREATE INDEX idx_avm_vr_version ON avm_version_roots (version_id); - --- --- Explicit indexes and constraints not declared in the mappings --- - -CREATE INDEX idx_alf_acl_inh ON alf_access_control_list (inherits, inherits_from); - -CREATE INDEX fk_alf_na_qn ON alf_node_aspects (qname_id); -ALTER TABLE alf_node_aspects ADD CONSTRAINT fk_alf_na_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id); - --- alf_node_properties is fully rebuilt in another script --- CREATE INDEX fk_alf_nprop_qn ON alf_node_properties (qname_id); --- ALTER TABLE alf_node_properties ADD CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id); --- CREATE INDEX fk_alf_nprop_loc ON alf_node_properties (locale_id); --- ALTER TABLE alf_node_properties ADD CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id); - -CREATE INDEX fk_avm_na_qn ON avm_aspects_new (qname_id); -ALTER TABLE avm_aspects_new ADD CONSTRAINT fk_avm_na_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id); - -CREATE INDEX fk_avm_np_qn ON avm_node_properties_new (qname_id); -ALTER TABLE avm_node_properties_new ADD CONSTRAINT fk_avm_np_qn 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-V2.2-4-ExtraIndexesAndConstraints'; -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-4-ExtraIndexesAndConstraints', 'Manually executed script upgrade V2.2: Created additional indexes and constraints', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/upgrade-5-mapped-fk-indexes.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/upgrade-5-mapped-fk-indexes.sql deleted file mode 100644 index 41e0b40b8f..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/upgrade-5-mapped-fk-indexes.sql +++ /dev/null @@ -1,108 +0,0 @@ --- --- Title: Post-Create Indexes --- Database: Generic --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Hibernate only generates indexes on foreign key columns for MySQL. --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - -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 INDEX fk_alf_acl_acs ON alf_access_control_list (acl_change_set); - -CREATE INDEX fk_alf_aclm_acl ON alf_acl_member (acl_id); -CREATE INDEX fk_alf_aclm_ace ON alf_acl_member (ace_id); - -CREATE INDEX fk_alf_adtf_src ON alf_audit_fact (audit_source_id); -CREATE INDEX fk_alf_adtf_date ON alf_audit_fact (audit_date_id); -CREATE INDEX fk_alf_adtf_conf ON alf_audit_fact (audit_conf_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); - -CREATE INDEX fk_alf_ca_pnode ON alf_child_assoc (parent_node_id); -CREATE INDEX fk_alf_ca_tqn ON alf_child_assoc (type_qname_id); -CREATE INDEX fk_alf_ca_qn_ns ON alf_child_assoc (qname_ns_id); -CREATE INDEX fk_alf_ca_cnode ON alf_child_assoc (child_node_id); - -CREATE INDEX fk_alf_attr_acl ON alf_attributes (acl_id); - --- alf_global_attributes.attribute is declared unique. Indexes may automatically have been created. -CREATE INDEX fk_alf_gatt_att ON alf_global_attributes (attribute); -- (optional) - -CREATE INDEX fk_alf_lent_att ON alf_list_attribute_entries (attribute_id); - -CREATE INDEX fk_alf_lent_latt ON alf_list_attribute_entries (list_id); - -CREATE INDEX fk_alf_matt_matt ON alf_map_attribute_entries (map_id); -CREATE INDEX fk_alf_matt_att ON alf_map_attribute_entries (attribute_id); - -CREATE INDEX fk_alf_n_acl ON alf_node (acl_id); -CREATE INDEX fk_alf_n_tqname ON alf_node (type_qname_id); -CREATE INDEX fk_alf_n_store ON alf_node (protocol, identifier); - -CREATE INDEX fk_alf_n_asp ON alf_node_aspects (node_id); -CREATE INDEX fk_alf_na_snode ON alf_node_assoc (source_node_id); - -CREATE INDEX fk_alf_na_tqn ON alf_node_assoc (type_qname_id); -CREATE INDEX fk_alf_na_tnode ON alf_node_assoc (target_node_id); - -CREATE INDEX fk_alf_perm_tqn ON alf_permission (type_qname_id); - --- alf_node_properties is fully rebuilt in another script --- CREATE INDEX fk_alf_nprop_n ON alf_node_properties (node_id); - -CREATE INDEX fk_alf_ns_node ON alf_node_status (node_id); -CREATE INDEX fk_alf_ns_trans ON alf_node_status (transaction_id); - -CREATE INDEX fk_alf_qname_ns ON alf_qname (ns_id); - -CREATE INDEX fk_alf_store_rn ON alf_store (root_node_id); - -CREATE INDEX fk_alf_txn_svr ON alf_transaction (server_id); - -CREATE INDEX fk_avm_asp_node ON avm_aspects (node_id); -CREATE INDEX fk_avm_asp_n ON avm_aspects_new (id); - -CREATE INDEX fk_avm_ce_child ON avm_child_entries (child_id); -CREATE INDEX fk_avm_ce_parent ON avm_child_entries (parent_id); - -CREATE INDEX fk_avm_hl_desc ON avm_history_links (descendent); -CREATE INDEX fk_avm_hl_ancestor ON avm_history_links (ancestor); - -CREATE INDEX fk_avm_ml_to ON avm_merge_links (mto); -CREATE INDEX fk_avm_ml_from ON avm_merge_links (mfrom); - -CREATE INDEX fk_avm_np_node ON avm_node_properties (node_id); -CREATE INDEX fk_avm_np_n ON avm_node_properties_new (node_id); - -CREATE INDEX fk_avm_n_acl ON avm_nodes (acl_id); -CREATE INDEX fk_avm_n_store ON avm_nodes (store_new_id); - -CREATE INDEX fk_avm_sp_qname ON avm_store_properties (qname_id); -CREATE INDEX fk_avm_sp_store ON avm_store_properties (avm_store_id); - -CREATE INDEX fk_avm_s_acl ON avm_stores (acl_id); -CREATE INDEX fk_avm_s_root ON avm_stores (current_root_id); - -CREATE INDEX fk_avm_vlne_vr ON avm_version_layered_node_entry (version_root_id); - -CREATE INDEX fk_avm_vr_root ON avm_version_roots (root_id); -CREATE INDEX fk_avm_vr_store ON avm_version_roots (avm_store_id); - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-5-MappedFKIndexes'; -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-5-MappedFKIndexes', 'Manually executed script upgrade V2.2: Created FK indexes', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/AlfrescoSchemaUpdate-2.2-ACL.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/AlfrescoSchemaUpdate-2.2-ACL.sql index 3fdb3faa33..9a4aa1d477 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/AlfrescoSchemaUpdate-2.2-ACL.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/AlfrescoSchemaUpdate-2.2-ACL.sql @@ -24,10 +24,10 @@ ALTER TABLE alf_access_control_list ADD COLUMN is_versioned BOOLEAN NOT NULL DEFAULT FALSE, ADD COLUMN requires_version BOOLEAN NOT NULL DEFAULT FALSE, ADD COLUMN acl_change_set BIGINT, - ADD COLUMN inherits_from BIGINT; -CREATE INDEX fk_alf_acl_acs ON alf_access_control_list (acl_change_set); -ALTER TABLE alf_access_control_list 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); + ADD COLUMN inherits_from BIGINT, + ADD INDEX fk_alf_acl_acs (acl_change_set), + ADD CONSTRAINT fk_alf_acl_acs FOREIGN KEY (acl_change_set) REFERENCES alf_acl_change_set (id), + ADD INDEX idx_alf_acl_inh (inherits, inherits_from); UPDATE alf_access_control_list acl set acl_id = (acl.id); @@ -42,14 +42,13 @@ CREATE TABLE alf_acl_member ( acl_id BIGINT NOT NULL, ace_id BIGINT NOT NULL, pos INT NOT NULL, + INDEX fk_alf_aclm_acl (acl_id), + CONSTRAINT fk_alf_aclm_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + INDEX fk_alf_aclm_ace (ace_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) ) ENGINE=InnoDB; -CREATE INDEX fk_alf_aclm_acl ON alf_acl_member (acl_id); -ALTER TABLE alf_acl_member ADD CONSTRAINT fk_alf_aclm_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id); -CREATE INDEX fk_alf_aclm_ace ON alf_acl_member (ace_id); -ALTER TABLE alf_acl_member ADD CONSTRAINT fk_alf_aclm_ace FOREIGN KEY (ace_id) REFERENCES alf_access_control_entry (id); - ALTER TABLE alf_access_control_entry DROP INDEX acl_id; @@ -71,9 +70,9 @@ ALTER TABLE alf_authority ADD COLUMN id BIGINT NOT NULL AUTO_INCREMENT, ADD COLUMN crc BIGINT, CHANGE recipient authority VARCHAR(100), + ADD INDEX idx_alf_auth_aut (authority), ADD primary key (id), ADD UNIQUE (authority, crc); -CREATE INDEX idx_alf_auth_aut on alf_authority (authority); -- migrate data - fix up FK refs to authority UPDATE alf_access_control_entry ace @@ -101,13 +100,13 @@ CREATE TABLE alf_authority_alias ( version BIGINT NOT NULL, auth_id BIGINT NOT NULL, alias_id BIGINT NOT NULL, + INDEX fk_alf_autha_ali (alias_id), + CONSTRAINT fk_alf_autha_ali FOREIGN KEY (alias_id) REFERENCES alf_authority (id), + INDEX fk_alf_autha_aut (auth_id), + CONSTRAINT fk_alf_autha_aut FOREIGN KEY (auth_id) REFERENCES alf_authority (id), primary key (id), UNIQUE (auth_id, alias_id) ) ENGINE=InnoDB; -CREATE INDEX fk_alf_autha_ali ON alf_authority_alias (alias_id); -ALTER TABLE alf_authority_alias ADD CONSTRAINT fk_alf_autha_ali FOREIGN KEY (alias_id) REFERENCES alf_authority (id); -CREATE INDEX fk_alf_autha_aut ON alf_authority_alias (auth_id); -ALTER TABLE alf_authority_alias ADD CONSTRAINT fk_alf_autha_aut FOREIGN KEY (auth_id) REFERENCES alf_authority (id); -- Tidy up unused cols on ace table and add the FK contstraint back diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-0-create-missing-tables.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-0-create-missing-tables.sql index d2d340ae9c..37d78f7cea 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-0-create-missing-tables.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-0-create-missing-tables.sql @@ -77,6 +77,10 @@ ALTER TABLE alf_audit_date CHANGE COLUMN year full_year INTEGER NOT NULL; primary key (id) ) type=InnoDB; -- (optional) +-- Add ACL column for AVM tables +ALTER TABLE avm_stores + ADD COLUMN acl_id BIGINT; + -- -- Record script finish -- diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-drop-indexes-and-constraints.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-drop-indexes-and-constraints.sql deleted file mode 100644 index 8a6dfe070b..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-drop-indexes-and-constraints.sql +++ /dev/null @@ -1,164 +0,0 @@ --- --- Title: Remote all pre-2.2 indexes and constraints --- Database: MySQL --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - -ALTER TABLE alf_access_control_entry DROP INDEX fk_alf_ace_ctx, DROP FOREIGN KEY fk_alf_ace_ctx; - -ALTER TABLE alf_access_control_entry DROP INDEX fk_alf_ace_perm, DROP FOREIGN KEY fk_alf_ace_perm; - -ALTER TABLE alf_access_control_entry DROP INDEX fk_alf_ace_auth, DROP FOREIGN KEY fk_alf_ace_auth; - -ALTER TABLE alf_access_control_list DROP INDEX fk_alf_acl_acs, DROP FOREIGN KEY fk_alf_acl_acs; - -ALTER TABLE alf_access_control_list DROP INDEX idx_alf_acl_inh; - -ALTER TABLE alf_acl_member DROP INDEX fk_alf_aclm_acl, DROP FOREIGN KEY fk_alf_aclm_acl; - -ALTER TABLE alf_acl_member DROP INDEX fk_alf_aclm_ace, DROP FOREIGN KEY fk_alf_aclm_ace; - --- Table might not exist -ALTER TABLE alf_attributes DROP INDEX fk_attributes_n_acl, DROP FOREIGN KEY fk_attributes_n_acl; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_woy_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_date_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_y_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_q_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_m_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_dow_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_doy_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_dom_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_hy_idx; -- (optional) - -ALTER TABLE alf_audit_date DROP INDEX adt_wom_idx; -- (optional) - -ALTER TABLE alf_audit_fact DROP INDEX adt_user_idx; -- (optional) - -ALTER TABLE alf_audit_fact DROP INDEX adt_store_idx; -- (optional) - -ALTER TABLE alf_audit_fact DROP INDEX FKEAD18174A0F9B8D9, DROP FOREIGN KEY FKEAD18174A0F9B8D9; - -ALTER TABLE alf_audit_fact DROP INDEX FKEAD1817484342E39, DROP FOREIGN KEY FKEAD1817484342E39; - -ALTER TABLE alf_audit_fact DROP INDEX FKEAD18174F524CFD7, DROP FOREIGN KEY FKEAD18174F524CFD7; - -ALTER TABLE alf_audit_source DROP INDEX app_source_app_idx; -- (optional) - -ALTER TABLE alf_audit_source DROP INDEX app_source_ser_idx; -- (optional) - -ALTER TABLE alf_audit_source DROP INDEX app_source_met_idx; -- (optional) - -ALTER TABLE alf_authority DROP INDEX idx_alf_auth_aut; - -ALTER TABLE alf_authority_alias DROP INDEX fk_alf_autha_ali, DROP FOREIGN KEY fk_alf_autha_ali; - -ALTER TABLE alf_authority_alias DROP INDEX fk_alf_autha_aut, DROP FOREIGN KEY fk_alf_autha_aut; - -ALTER TABLE alf_child_assoc DROP INDEX FKFFC5468E8E50E582, DROP FOREIGN KEY FKFFC5468E8E50E582; - -ALTER TABLE alf_child_assoc DROP INDEX FKFFC5468E74173FF4, DROP FOREIGN KEY FKFFC5468E74173FF4; - -ALTER TABLE alf_global_attributes DROP FOREIGN KEY FK64D0B9CF69B9F16A; -- (optional) -ALTER TABLE alf_global_attributes DROP INDEX FK64D0B9CF69B9F16A; --(optional) - -ALTER TABLE alf_list_attribute_entries DROP INDEX FKC7D52FB02C5AB86C, DROP FOREIGN KEY FKC7D52FB02C5AB86C; -- (optional) - -ALTER TABLE alf_list_attribute_entries DROP INDEX FKC7D52FB0ACD8822C, DROP FOREIGN KEY FKC7D52FB0ACD8822C; -- (optional) - -ALTER TABLE alf_map_attribute_entries DROP INDEX FK335CAE26AEAC208C, DROP FOREIGN KEY FK335CAE26AEAC208C; -- (optional) - -ALTER TABLE alf_map_attribute_entries DROP INDEX FK335CAE262C5AB86C, DROP FOREIGN KEY FK335CAE262C5AB86C; -- (optional) - -ALTER TABLE alf_node DROP INDEX FK60EFB626B9553F6C, DROP FOREIGN KEY FK60EFB626B9553F6C; - -ALTER TABLE alf_node DROP INDEX FK60EFB626D24ADD25, DROP FOREIGN KEY FK60EFB626D24ADD25; - -ALTER TABLE alf_node_aspects DROP INDEX FKD654E027F2C8017, DROP FOREIGN KEY FKD654E027F2C8017; - -ALTER TABLE alf_node_assoc DROP INDEX FKE1A550BCB69C43F3, DROP FOREIGN KEY FKE1A550BCB69C43F3; - -ALTER TABLE alf_node_assoc DROP INDEX FKE1A550BCA8FC7769, DROP FOREIGN KEY FKE1A550BCA8FC7769; - -ALTER TABLE alf_node_properties DROP INDEX FK7D4CF8EC7F2C8017, DROP FOREIGN KEY FK7D4CF8EC7F2C8017; - -ALTER TABLE alf_node_properties DROP INDEX FK7D4CF8EC40E780DC, DROP FOREIGN KEY FK7D4CF8EC40E780DC; -- (optional) - -ALTER TABLE alf_node_status DROP INDEX FK71C2002B7F2C8017, DROP FOREIGN KEY FK71C2002B7F2C8017; - -ALTER TABLE alf_node_status DROP INDEX FK71C2002B9E57C13D, DROP FOREIGN KEY FK71C2002B9E57C13D; - -ALTER TABLE alf_store DROP INDEX FKBD4FF53D22DBA5BA, DROP FOREIGN KEY FKBD4FF53D22DBA5BA; - -ALTER TABLE alf_transaction DROP INDEX idx_commit_time_ms; -- (optional) - -ALTER TABLE alf_transaction DROP INDEX FKB8761A3A9AE340B7, DROP FOREIGN KEY FKB8761A3A9AE340B7; - -ALTER TABLE avm_aspects DROP INDEX fk_avm_asp_node, DROP FOREIGN KEY fk_avm_asp_node; --(optional) - -ALTER TABLE avm_aspects_new DROP INDEX FKD3FD9F95EDCD4A96, DROP FOREIGN KEY FKD3FD9F95EDCD4A96; -- (optional) - -ALTER TABLE avm_child_entries DROP INDEX fk_avm_ce_child, DROP FOREIGN KEY fk_avm_ce_child; --(optional) - -ALTER TABLE avm_child_entries DROP INDEX fk_avm_ce_parent, DROP FOREIGN KEY fk_avm_ce_parent; --(optional) - -ALTER TABLE avm_history_links DROP INDEX fk_avm_hl_desc, DROP FOREIGN KEY fk_avm_hl_desc; --(optional) - -ALTER TABLE avm_history_links DROP INDEX fk_avm_hl_ancestor, DROP FOREIGN KEY fk_avm_hl_ancestor; --(optional) - -ALTER TABLE avm_history_links DROP INDEX idx_avm_hl_revpk; --(optional) - -ALTER TABLE avm_merge_links DROP INDEX fk_avm_ml_to, DROP FOREIGN KEY fk_avm_ml_to; --(optional) - -ALTER TABLE avm_merge_links DROP INDEX fk_avm_ml_from, DROP FOREIGN KEY fk_avm_ml_from; --(optional) - -ALTER TABLE avm_node_properties DROP INDEX idx_avm_np_name; --(optional) - -ALTER TABLE avm_node_properties DROP INDEX fk_avm_np_node, DROP FOREIGN KEY fk_avm_np_node; --(optional) - -ALTER TABLE avm_node_properties_new DROP INDEX FK44A37C8A6BD529F3, DROP FOREIGN KEY FK44A37C8A6BD529F3; -- (optional) - -ALTER TABLE avm_nodes DROP INDEX fk_avm_n_acl, DROP FOREIGN KEY fk_avm_n_acl; --(optional) - -ALTER TABLE avm_nodes DROP INDEX fk_avm_n_store, DROP FOREIGN KEY fk_avm_n_store; --(optional) - -ALTER TABLE avm_nodes DROP INDEX idx_avm_n_pi; --(optional) - -ALTER TABLE avm_store_properties DROP INDEX idx_avm_sp_name; --(optional) - -ALTER TABLE avm_store_properties DROP INDEX fk_avm_sp_store, DROP FOREIGN KEY fk_avm_sp_store; --(optional) - -ALTER TABLE avm_stores DROP INDEX fk_avm_s_root, DROP FOREIGN KEY fk_avm_s_root; --(optional) - -ALTER TABLE avm_version_layered_node_entry DROP INDEX FK182E672DEB9D70C, DROP FOREIGN KEY FK182E672DEB9D70C; -- (optional) - -ALTER TABLE avm_version_roots DROP INDEX idx_avm_vr_version; --(optional) - -ALTER TABLE avm_version_roots DROP INDEX idx_avm_vr_revuq; --(optional) - -ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_root, DROP FOREIGN KEY fk_avm_vr_root; --(optional) - -ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_store, DROP FOREIGN KEY fk_avm_vr_store; --(optional) - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-1-DropIndexesAndConstraints'; -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-1-DropIndexesAndConstraints', 'Manually executed script upgrade V2.2: Remove pre-2.2 indexes and constraints', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-mltext.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-mltext.sql deleted file mode 100644 index 3fd6b5e70b..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-mltext.sql +++ /dev/null @@ -1,157 +0,0 @@ --- --- Title: Pull MLText Values into Node Properties --- Database: MySQL --- Since: V2.2 Schema 91 --- Author: Derek Hulley --- --- MLText values must be pulled back from attributes into localizable properties. --- Several statements are not relevant to upgrades from below 77. These are optional. --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - -CREATE TABLE alf_locale -( - id BIGINT NOT NULL AUTO_INCREMENT, - version BIGINT NOT NULL DEFAULT 1, - locale_str VARCHAR(20) NOT NULL, - PRIMARY KEY (id), - UNIQUE (locale_str) -) TYPE=InnoDB; - -INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default'); - -INSERT INTO alf_locale (locale_str) - 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) -; -- (OPTIONAL) - --- Create a temporary table to hold the attribute_value information that needs replacing -CREATE TABLE t_alf_node_properties -( - node_id BIGINT NOT NULL, - qname_id BIGINT NOT NULL, - list_index integer NOT NULL, - locale_id BIGINT NOT NULL, - actual_type_n integer NOT NULL, - persisted_type_n integer NOT NULL, - boolean_value BIT, - long_value BIGINT, - float_value FLOAT, - double_value DOUBLE PRECISION, - string_value TEXT, - serializable_value BLOB, - INDEX fk_alf_nprop_n (node_id), - CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES alf_node (id), - INDEX fk_alf_nprop_qn (qname_id), - CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), - INDEX fk_alf_nprop_loc (locale_id), - CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id), - PRIMARY KEY (node_id, qname_id, list_index, locale_id) -) TYPE=InnoDB; - --- Copy all simple 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, 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 -; - --- 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 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; - --- Clean up unused attribute values - -CREATE TABLE t_del_attributes -( - id BIGINT NOT NULL, - PRIMARY KEY (id) -); -INSERT INTO t_del_attributes - SELECT id FROM alf_attributes WHERE type = 'M' -; -DELETE t_del_attributes - FROM t_del_attributes - JOIN alf_map_attribute_entries ma ON (ma.attribute_id = t_del_attributes.id) -; -DELETE t_del_attributes - FROM t_del_attributes - JOIN alf_list_attribute_entries la ON (la.attribute_id = t_del_attributes.id) -; -DELETE t_del_attributes - FROM t_del_attributes - JOIN alf_global_attributes ga ON (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 alf_map_attribute_entries - FROM alf_map_attribute_entries - JOIN t_del_attributes t ON (alf_map_attribute_entries.map_id = t.id) -; -DELETE alf_attributes - FROM alf_attributes - JOIN t_del_attributes t ON (alf_attributes.id = t.id) -; -DROP TABLE t_del_attributes; - - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-1-MLText'; -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-1-MLText', 'Manually executed script upgrade V2.2: Moved MLText values', - 86, 90, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-2-move-qnames.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-2-move-qnames.sql deleted file mode 100644 index 40df8d8156..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-2-move-qnames.sql +++ /dev/null @@ -1,370 +0,0 @@ --- --- Title: Move static QNames and Namsespaces into a separate table --- Database: MySQL --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- --- This script replaces the various static QName and Namespace entries --- with a more efficient FK relationship to the static values. --- - --- Create static namespace and qname tables -CREATE TABLE alf_namespace -( - id BIGINT NOT NULL AUTO_INCREMENT, - version BIGINT NOT NULL, - uri VARCHAR(100) NOT NULL, - PRIMARY KEY (id), - UNIQUE (uri) -) ENGINE=InnoDB; - -CREATE TABLE alf_qname -( - id BIGINT NOT NULL AUTO_INCREMENT, - version BIGINT NOT NULL, - ns_id BIGINT NOT NULL, - local_name VARCHAR(200) NOT NULL, - PRIMARY KEY (id), - UNIQUE (ns_id, local_name) -) ENGINE=InnoDB; - --- Create temporary index -CREATE INDEX t_fk_alf_qn_ns on alf_qname (ns_id); - --- Create temporary table for dynamic (child) QNames -CREATE TABLE t_qnames_dyn -( - qname varchar(255) NOT NULL, - namespace varchar(255) -) ENGINE=InnoDB; -CREATE INDEX tidx_qnd_qn ON t_qnames_dyn (qname); -CREATE INDEX tidx_qnd_ns ON t_qnames_dyn (namespace); - --- Populate the table with the child association paths -INSERT INTO t_qnames_dyn (qname) -( - SELECT qname FROM alf_child_assoc -); --- Extract the Namespace -UPDATE t_qnames_dyn SET namespace = CONCAT('FILLER-', SUBSTR(SUBSTRING_INDEX(qname, '}', 1), 2)); --- Move the namespaces to the their new home -INSERT INTO alf_namespace (uri, version) -( - SELECT - distinct(x.namespace), 1 - FROM - ( - SELECT t.namespace, n.uri FROM t_qnames_dyn t LEFT OUTER JOIN alf_namespace n ON (n.uri = t.namespace) - ) x - WHERE - x.uri IS NULL -); - --- Check the data -ALTER TABLE alf_qname ADD CONSTRAINT t_fk_alf_qn_ns FOREIGN KEY (ns_id) REFERENCES alf_namespace (id); - --- We can trash the temp table -DROP TABLE t_qnames_dyn; - --- Create temporary table to hold static QNames -CREATE TABLE t_qnames -( - qname varchar(255) NOT NULL, - namespace varchar(255), - localname varchar(255) -) ENGINE=InnoDB; -CREATE INDEX tidx_tqn_qn ON t_qnames (qname); -CREATE INDEX tidx_tqn_ns ON t_qnames (namespace); -CREATE INDEX tidx_tqn_ln ON t_qnames (localname); - --- Populate the table with all known static QNames -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_node -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM alf_node_aspects -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM alf_node_properties -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT name FROM avm_aspects_new -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM avm_node_properties_new -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM avm_store_properties -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_node_assoc -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_child_assoc -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_permission -); --- Extract the namespace and localnames from the QNames -UPDATE t_qnames SET namespace = CONCAT('FILLER-', SUBSTR(SUBSTRING_INDEX(qname, '}', 1), 2)); -UPDATE t_qnames SET localname = SUBSTRING_INDEX(qname, '}', -1); --- Move the Namespaces to their new home -INSERT INTO alf_namespace (uri, version) -( - SELECT - distinct(x.namespace), 1 - FROM - ( - SELECT t.namespace, n.uri FROM t_qnames t LEFT OUTER JOIN alf_namespace n ON (n.uri = t.namespace) - ) x - WHERE - x.uri IS NULL -); - --- Move the Localnames to their new home -INSERT INTO alf_qname (ns_id, local_name, version) -( - SELECT - x.ns_id, x.t_localname, 1 - FROM - ( - SELECT n.id AS ns_id, t.localname AS t_localname, q.local_name AS q_localname - FROM t_qnames t - JOIN alf_namespace n ON (n.uri = t.namespace) - LEFT OUTER JOIN alf_qname q ON (q.local_name = t.localname) - ) x - WHERE - q_localname IS NULL - GROUP BY x.ns_id, x.t_localname -); - --- We can trash the temp table -DROP TABLE t_qnames; - --- --- DATA REPLACEMENT: alf_node.type_qname --- -ALTER TABLE alf_node ADD COLUMN type_qname_id BIGINT NULL AFTER uuid; -UPDATE alf_node n SET n.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = n.type_qname -); -ALTER TABLE alf_node DROP COLUMN type_qname; -ALTER TABLE alf_node MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER uuid; - --- --- DATA REPLACEMENT: alf_node_aspects.qname --- Due to the the potentially-missing primary key on the original table, it is --- possible to have duplicates. These are removed. --- -ALTER TABLE alf_node_aspects DROP PRIMARY KEY; -- (optional) -ALTER TABLE alf_node_aspects ADD COLUMN qname_id BIGINT NULL AFTER node_id; -UPDATE alf_node_aspects na SET na.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = na.qname -); -ALTER TABLE alf_node_aspects DROP COLUMN qname; -ALTER TABLE alf_node_aspects MODIFY COLUMN qname_id BIGINT NOT NULL AFTER node_id; -CREATE TABLE t_dup_aspects -( - node_id BIGINT NOT NULL, - qname_id BIGINT NOT NULL -); -INSERT INTO t_dup_aspects (node_id, qname_id) -( - SELECT - node_id, qname_id - FROM - alf_node_aspects - GROUP BY - node_id, qname_id - HAVING - count(*) > 1 -); -DELETE FROM na - USING alf_node_aspects na - JOIN t_dup_aspects t ON (t.node_id = na.node_id AND t.qname_id = na.qname_id); -INSERT INTO alf_node_aspects (node_id, qname_id) -( - SELECT - node_id, qname_id - FROM - t_dup_aspects -); -DROP TABLE t_dup_aspects; -ALTER TABLE alf_node_aspects ADD PRIMARY KEY (node_id, qname_id); - --- --- DATA REPLACEMENT: alf_node_properties.qname --- -ALTER TABLE alf_node_properties DROP PRIMARY KEY; -ALTER TABLE alf_node_properties ADD COLUMN qname_id BIGINT NULL AFTER node_id; -UPDATE alf_node_properties np SET np.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = np.qname -); -ALTER TABLE alf_node_properties DROP COLUMN qname; -ALTER TABLE alf_node_properties MODIFY COLUMN qname_id BIGINT NOT NULL AFTER node_id; -ALTER TABLE alf_node_properties ADD PRIMARY KEY (node_id, qname_id); - --- --- DATA REPLACEMENT: avm_aspects_new.name (aka qname) --- -ALTER TABLE avm_aspects_new DROP PRIMARY KEY; -ALTER TABLE avm_aspects_new ADD COLUMN qname_id BIGINT NULL AFTER id; -UPDATE avm_aspects_new na SET na.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = na.name -); -ALTER TABLE avm_aspects_new DROP COLUMN name; -ALTER TABLE avm_aspects_new MODIFY COLUMN qname_id BIGINT NOT NULL AFTER id; -ALTER TABLE avm_aspects_new ADD PRIMARY KEY (id, qname_id); - --- --- DATA REPLACEMENT: avm_node_properties.qname --- --- This table is deprecated and made empty so there is no need to alter it - --- --- DATA REPLACEMENT: avm_node_properties_new.qname --- -ALTER TABLE avm_node_properties_new DROP PRIMARY KEY; -ALTER TABLE avm_node_properties_new ADD COLUMN qname_id BIGINT NULL AFTER node_id; -UPDATE avm_node_properties_new np SET np.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = np.qname -); -ALTER TABLE avm_node_properties_new DROP COLUMN qname; -ALTER TABLE avm_node_properties_new MODIFY COLUMN qname_id BIGINT NOT NULL AFTER node_id; -ALTER TABLE avm_node_properties_new ADD PRIMARY KEY (node_id, qname_id); - --- --- DATA REPLACEMENT: avm_store_properties.qname --- -ALTER TABLE avm_store_properties ADD COLUMN qname_id BIGINT NULL AFTER avm_store_id; -UPDATE avm_store_properties np SET np.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = np.qname -); -ALTER TABLE avm_store_properties DROP COLUMN qname; -ALTER TABLE avm_store_properties MODIFY COLUMN qname_id BIGINT NOT NULL AFTER avm_store_id; - --- --- DATA REPLACEMENT: alf_child_assoc.type_qname --- -ALTER TABLE alf_child_assoc DROP INDEX parent_node_id; -- (optional) -ALTER TABLE alf_child_assoc DROP INDEX UIDX_CHILD_NAME; -- (optional) -ALTER TABLE alf_child_assoc DROP INDEX IDX_CHILD_NAMECRC; -- (optional) -ALTER TABLE alf_child_assoc ADD COLUMN type_qname_id BIGINT NULL AFTER child_node_id; -UPDATE alf_child_assoc ca SET ca.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = ca.type_qname -); -ALTER TABLE alf_child_assoc DROP COLUMN type_qname; -ALTER TABLE alf_child_assoc MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER child_node_id; -ALTER TABLE alf_child_assoc ADD UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc); - --- --- DATA REPLACEMENT: alf_child_assoc.qname --- --- Namespace -ALTER TABLE alf_child_assoc ADD COLUMN qname_ns_id BIGINT NULL AFTER type_qname_id; -UPDATE alf_child_assoc ca SET ca.qname_ns_id = -( - SELECT ns.id - FROM alf_namespace ns - WHERE SUBSTR(SUBSTRING_INDEX(qname, '}', 1), 2) = SUBSTR(ns.uri, 8) -); -ALTER TABLE alf_child_assoc MODIFY COLUMN qname_ns_id BIGINT NOT NULL AFTER type_qname_id; --- LocalName -ALTER TABLE alf_child_assoc ADD COLUMN qname_localname VARCHAR(200) NULL AFTER qname_ns_id; -UPDATE alf_child_assoc ca SET ca.qname_localname = SUBSTRING_INDEX(qname, '}', -1); -ALTER TABLE alf_child_assoc MODIFY COLUMN qname_localname VARCHAR(200) NOT NULL AFTER qname_ns_id; --- Drop old column -ALTER TABLE alf_child_assoc DROP COLUMN qname; - --- --- DATA REPLACEMENT: alf_node_assoc.type_qname --- -ALTER TABLE alf_node_assoc DROP INDEX IDX_ASSOC; -- (optional) -ALTER TABLE alf_node_assoc DROP INDEX UIDX_CHILD_NAME; -- (optional) -ALTER TABLE alf_node_assoc DROP INDEX source_node_id; -- (optional) -ALTER TABLE alf_node_assoc ADD COLUMN type_qname_id BIGINT NULL AFTER target_node_id; -UPDATE alf_node_assoc na SET na.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = na.type_qname -); -ALTER TABLE alf_node_assoc DROP COLUMN type_qname; -ALTER TABLE alf_node_assoc MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER target_node_id; -ALTER TABLE alf_node_assoc ADD UNIQUE (source_node_id, target_node_id, type_qname_id); - --- --- DATA REPLACEMENT: alf_permission.type_qname --- -ALTER TABLE alf_permission DROP INDEX type_qname; -ALTER TABLE alf_permission ADD COLUMN type_qname_id BIGINT NULL AFTER id; -UPDATE alf_permission p SET p.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = p.type_qname -); -ALTER TABLE alf_permission DROP COLUMN type_qname; -ALTER TABLE alf_permission MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER id; -ALTER TABLE alf_permission ADD UNIQUE (type_qname_id, name); - --- Drop the temporary indexes and constraints -ALTER TABLE alf_qname DROP INDEX t_fk_alf_qn_ns; -ALTER TABLE alf_qname DROP FOREIGN KEY t_fk_alf_qn_ns; - --- Remove the FILLER- values from the namespace uri -UPDATE alf_namespace SET uri = '.empty' WHERE uri = 'FILLER-'; -UPDATE alf_namespace SET uri = SUBSTR(uri, 8) WHERE uri LIKE 'FILLER-%'; - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-2-MoveQNames'; -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-2-MoveQNames', 'Manually executed script upgrade V2.2: Moved static QNames and Namespaces', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-3-proptypes.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-3-proptypes.sql deleted file mode 100644 index 08af754d77..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-3-proptypes.sql +++ /dev/null @@ -1,102 +0,0 @@ --- --- Title: Replace property type descriptors with numerical equivalents --- Database: MySQL --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - --- Create temporary mapping for property types -CREATE TABLE t_prop_types -( - type_name VARCHAR(15) NOT NULL, - type_id INTEGER NOT NULL, - PRIMARY KEY (type_name) -); -INSERT INTO t_prop_types values ('NULL', 0); -INSERT INTO t_prop_types values ('BOOLEAN', 1); -INSERT INTO t_prop_types values ('INTEGER', 2); -INSERT INTO t_prop_types values ('LONG', 3); -INSERT INTO t_prop_types values ('FLOAT', 4); -INSERT INTO t_prop_types values ('DOUBLE', 5); -INSERT INTO t_prop_types values ('STRING', 6); -INSERT INTO t_prop_types values ('DATE', 7); -INSERT INTO t_prop_types values ('DB_ATTRIBUTE', 8); -INSERT INTO t_prop_types values ('SERIALIZABLE', 9); -INSERT INTO t_prop_types values ('MLTEXT', 10); -INSERT INTO t_prop_types values ('CONTENT', 11); -INSERT INTO t_prop_types values ('NODEREF', 12); -INSERT INTO t_prop_types values ('CHILD_ASSOC_REF', 13); -INSERT INTO t_prop_types values ('ASSOC_REF', 14); -INSERT INTO t_prop_types values ('QNAME', 15); -INSERT INTO t_prop_types values ('PATH', 16); -INSERT INTO t_prop_types values ('LOCALE', 17); -INSERT INTO t_prop_types values ('VERSION_NUMBER', 18); - --- Modify the alf_node_properties table -ALTER TABLE alf_node_properties ADD COLUMN actual_type_n INTEGER NULL AFTER qname_id; -ALTER TABLE alf_node_properties ADD COLUMN persisted_type_n INTEGER NULL AFTER actual_type_n; - -UPDATE alf_node_properties p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE alf_node_properties p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE alf_node_properties DROP COLUMN actual_type; -ALTER TABLE alf_node_properties DROP COLUMN persisted_type; - -ALTER TABLE alf_node_properties MODIFY COLUMN actual_type_n INTEGER NOT NULL AFTER qname_id; -ALTER TABLE alf_node_properties MODIFY COLUMN persisted_type_n INTEGER NOT NULL AFTER actual_type_n; - --- Modify the avm_node_properties_new table -ALTER TABLE avm_node_properties_new ADD COLUMN actual_type_n INTEGER NULL AFTER qname_id; -ALTER TABLE avm_node_properties_new ADD COLUMN persisted_type_n INTEGER NULL AFTER actual_type_n; - -UPDATE avm_node_properties_new p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE avm_node_properties_new p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE avm_node_properties_new DROP COLUMN actual_type; -ALTER TABLE avm_node_properties_new DROP COLUMN persisted_type; - -ALTER TABLE avm_node_properties_new MODIFY COLUMN actual_type_n INTEGER NOT NULL AFTER qname_id; -ALTER TABLE avm_node_properties_new MODIFY COLUMN persisted_type_n INTEGER NOT NULL AFTER actual_type_n; - --- Modify the avm_store_properties table -ALTER TABLE avm_store_properties ADD COLUMN actual_type_n INTEGER NULL AFTER qname_id; -ALTER TABLE avm_store_properties ADD COLUMN persisted_type_n INTEGER NULL AFTER actual_type_n; - -UPDATE avm_store_properties p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE avm_store_properties p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE avm_store_properties DROP COLUMN actual_type; -ALTER TABLE avm_store_properties DROP COLUMN persisted_type; - -ALTER TABLE avm_store_properties MODIFY COLUMN actual_type_n INTEGER NOT NULL AFTER qname_id; -ALTER TABLE avm_store_properties MODIFY COLUMN persisted_type_n INTEGER NOT NULL AFTER actual_type_n; - --- Modify the avm_node_properties table -ALTER TABLE avm_node_properties ADD COLUMN actual_type_n INTEGER NULL AFTER qname; -ALTER TABLE avm_node_properties ADD COLUMN persisted_type_n INTEGER NULL AFTER actual_type_n; - -UPDATE avm_node_properties p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE avm_node_properties p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE avm_node_properties DROP COLUMN actual_type; -ALTER TABLE avm_node_properties DROP COLUMN persisted_type; - -ALTER TABLE avm_node_properties MODIFY COLUMN actual_type_n INTEGER NOT NULL AFTER qname; -ALTER TABLE avm_node_properties MODIFY COLUMN persisted_type_n INTEGER NOT NULL AFTER actual_type_n; - --- Remove temporary table -DROP TABLE t_prop_types; - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-3-PropTypes'; -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-3-PropTypes', 'Manually executed script upgrade V2.2: Changed PropertyValue types', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-5-mapped-fk-indexes.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-5-mapped-fk-indexes.sql deleted file mode 100644 index 7f0fa59ab0..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-5-mapped-fk-indexes.sql +++ /dev/null @@ -1,22 +0,0 @@ --- --- Title: Post-Create Indexes --- Database: MySQL --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Hibernate only generates indexes on foreign key columns for MySQL. --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-5-MappedFKIndexes'; -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-5-MappedFKIndexes', 'Manually executed script upgrade V2.2: Created FK indexes', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-fulldm.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql similarity index 61% rename from config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-fulldm.sql rename to config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql index 3296e91af0..213c0a5357 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-1-fulldm.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql @@ -1,5 +1,5 @@ -- --- Title: Apply all DM schema modifications +-- Title: Apply schema modifications to upgrade from 2.1 -- Database: MySQL -- Since: V2.2 Schema 91 -- Author: Derek Hulley @@ -15,9 +15,9 @@ -- Please contact support@alfresco.com if you need assistance with the upgrade. -- ---------------------------------- +-- ------------------------------- -- Build Namespaces and QNames -- ---------------------------------- +-- ------------------------------- CREATE TABLE alf_namespace ( @@ -43,10 +43,10 @@ CREATE TABLE alf_qname -- Create temporary table for dynamic (child) QNames CREATE TABLE t_qnames_dyn ( - qname VARCHAR(100) NOT NULL, + qname VARCHAR(255) NOT NULL, namespace VARCHAR(100), namespace_id BIGINT, - local_name VARCHAR(100), + local_name VARCHAR(200), INDEX tidx_qnd_qn (qname), INDEX tidx_qnd_ns (namespace) ) ENGINE=InnoDB; @@ -188,13 +188,15 @@ UPDATE t_qnames t SET t.qname_id = WHERE ns.uri = t.namespace AND q.local_name = t.localname ); ------------------------------- +-- ---------------------------- -- Populate the Permissions -- ------------------------------- +-- ---------------------------- -- This is a small table so we change it in place -ALTER TABLE alf_permission DROP INDEX type_qname; -ALTER TABLE alf_permission ADD COLUMN type_qname_id BIGINT NULL AFTER id; +ALTER TABLE alf_permission + DROP INDEX type_qname, + ADD COLUMN type_qname_id BIGINT NULL AFTER id +; UPDATE alf_permission p SET p.type_qname_id = ( SELECT q.id @@ -202,13 +204,17 @@ UPDATE alf_permission p SET p.type_qname_id = JOIN alf_namespace ns ON (q.ns_id = ns.id) WHERE CONCAT('{', SUBSTR(ns.uri, 8), '}', q.local_name) = p.type_qname ); -ALTER TABLE alf_permission DROP COLUMN type_qname; -ALTER TABLE alf_permission MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER id; -ALTER TABLE alf_permission ADD UNIQUE (type_qname_id, name); +ALTER TABLE alf_permission + DROP COLUMN type_qname, + MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER id, + ADD UNIQUE (type_qname_id, name), + ADD INDEX fk_alf_perm_tqn (type_qname_id), + ADD CONSTRAINT fk_alf_perm_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) +; ---------------------- +-- ------------------- -- Build new Store -- ---------------------- +-- ------------------- CREATE TABLE t_alf_store ( @@ -221,6 +227,10 @@ CREATE TABLE t_alf_store UNIQUE (protocol, identifier) ) TYPE=InnoDB; +-- -------------------------- +-- Populate the ADM nodes -- +-- -------------------------- + CREATE TABLE t_alf_node ( id BIGINT NOT NULL AUTO_INCREMENT, version BIGINT NOT NULL, @@ -230,10 +240,10 @@ CREATE TABLE t_alf_node ( node_deleted bit NOT NULL, type_qname_id BIGINT NOT NULL, acl_id BIGINT, - audit_creator VARCHAR(255) NOT NULL, - audit_created VARCHAR(30) NOT NULL, - audit_modifier VARCHAR(255) NOT NULL, - audit_modified VARCHAR(30) NOT NULL, + audit_creator VARCHAR(255), + audit_created VARCHAR(30), + audit_modifier VARCHAR(255), + audit_modified VARCHAR(30), audit_accessed VARCHAR(30), INDEX idx_alf_node_del (node_deleted), INDEX fk_alf_node_acl (acl_id), @@ -253,18 +263,13 @@ INSERT INTO t_alf_store (version, protocol, identifier, root_node_id) SELECT 1, protocol, identifier, root_node_id FROM alf_store ; ----------------------------- --- Populate the new nodes -- ----------------------------- - --- Query OK, 830222 rows affected (2 min 18.96 sec) INSERT INTO t_alf_node ( - id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, + id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, acl_id, audit_creator, audit_created, audit_modifier, audit_modified ) SELECT - n.id, 1, s.id, n.uuid, nstat.transaction_id, false, q.qname_id, + n.id, 1, s.id, n.uuid, nstat.transaction_id, false, q.qname_id, n.acl_id, 'unknown', '2008-09-17T02:23:37.212+01:00', 'unkown', '2008-09-17T02:23:37.212+01:00' FROM t_qnames q @@ -279,9 +284,38 @@ ALTER TABLE t_alf_store ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id) ; -------------------------------- +-- ----------------------------- +-- Populate Version Counter -- +-- ----------------------------- + +CREATE TABLE t_alf_version_count +( + id BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL, + store_id BIGINT NOT NULL UNIQUE, + version_count INTEGER NOT NULL, + INDEX fk_alf_vc_store (store_id), + CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id), + PRIMARY KEY (id) +) TYPE=InnoDB; + +INSERT INTO t_alf_version_count + ( + version, store_id, version_count + ) + SELECT + 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 ( @@ -337,9 +371,9 @@ DROP TABLE t_qnames_dyn; DROP TABLE alf_child_assoc; ALTER TABLE t_alf_child_assoc RENAME TO alf_child_assoc; ------------------------------- +-- ---------------------------- -- Populate the Node Assocs -- ------------------------------- +-- ---------------------------- CREATE TABLE t_alf_node_assoc ( @@ -377,9 +411,9 @@ INSERT INTO t_alf_node_assoc DROP TABLE alf_node_assoc; ALTER TABLE t_alf_node_assoc RENAME TO alf_node_assoc; -------------------------------- +-- ----------------------------- -- Populate the Node Aspects -- -------------------------------- +-- ----------------------------- CREATE TABLE t_alf_node_aspects ( @@ -392,7 +426,7 @@ CREATE TABLE t_alf_node_aspects PRIMARY KEY (node_id, qname_id) ) TYPE=InnoDB; --- Note the omission of sys:referencable and cm:auditable. These are implicit. +-- Note the omission of sys:referencable. This is implicit. -- Query OK, 415051 rows affected (17.59 sec) INSERT INTO t_alf_node_aspects ( @@ -407,8 +441,7 @@ INSERT INTO t_alf_node_aspects WHERE tqn.qname NOT IN ( - '{http://www.alfresco.org/model/system/1.0}referenceable', - '{http://www.alfresco.org/model/content/1.0}auditable' + '{http://www.alfresco.org/model/system/1.0}referenceable' ) ; @@ -416,9 +449,9 @@ INSERT INTO t_alf_node_aspects 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 ( @@ -462,9 +495,9 @@ DROP TABLE avm_aspects; DROP TABLE avm_aspects_new; ALTER TABLE t_avm_aspects RENAME TO avm_aspects; ------------------------------------- +-- ---------------------------------- -- Migrate Sundry Property Tables -- ------------------------------------- +-- ---------------------------------- -- Create temporary mapping for property types CREATE TABLE t_prop_types @@ -493,47 +526,6 @@ INSERT INTO t_prop_types values ('PATH', 16); INSERT INTO t_prop_types values ('LOCALE', 17); INSERT INTO t_prop_types values ('VERSION_NUMBER', 18); --- Modify the avm_node_properties_new table -CREATE TABLE t_avm_node_properties_new -( - node_id BIGINT NOT NULL, - actual_type_n INTEGER NOT NULL, - persisted_type_n INTEGER NOT NULL, - multi_valued BIT NOT NULL, - boolean_value BIT, - long_value BIGINT, - float_value FLOAT, - double_value DOUBLE PRECISION, - string_value TEXT, - serializable_value BLOB, - qname_id BIGINT NOT NULL, - INDEX fk_avm_nprop_n (node_id), - INDEX fk_avm_nprop_qn (qname_id), - 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) -) TYPE=InnoDB; -INSERT INTO t_avm_node_properties_new - ( - 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, - tqn.qname_id, - ptypes_actual.type_id, ptypes_persisted.type_id, - 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 - JOIN t_qnames tqn ON (p.qname = tqn.qname) - JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) - JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) -; -DROP TABLE avm_node_properties_new; -ALTER TABLE t_avm_node_properties_new RENAME TO avm_node_properties_new; - -- Modify the avm_store_properties table CREATE TABLE t_avm_store_properties ( @@ -576,8 +568,7 @@ INSERT INTO t_avm_store_properties DROP TABLE avm_store_properties; ALTER TABLE t_avm_store_properties RENAME TO avm_store_properties; --- Modify the avm_node_properties table --- This table is old, so the data will be extracte and it will be replaced +-- Modify the avm_node_properties_new table CREATE TABLE t_avm_node_properties ( node_id BIGINT NOT NULL, @@ -591,8 +582,30 @@ CREATE TABLE t_avm_node_properties string_value TEXT, serializable_value BLOB, qname_id BIGINT NOT NULL, + INDEX fk_avm_nprop_n (node_id), + INDEX fk_avm_nprop_qn (qname_id), + 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) ) TYPE=InnoDB; +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, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + 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 + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) +; INSERT INTO t_avm_node_properties ( node_id, @@ -610,34 +623,19 @@ INSERT INTO t_avm_node_properties JOIN t_qnames tqn ON (p.qname = tqn.qname) JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) -; --- Copy values to new table. Duplicates are avoided just in case. -INSERT INTO avm_node_properties_new - ( - 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 - t_avm_node_properties p - LEFT OUTER JOIN avm_node_properties_new pnew ON (pnew.node_id = p.node_id AND pnew.qname_id = p.qname_id) + LEFT OUTER JOIN t_avm_node_properties tanp ON (tqn.qname_id = tanp.qname_id) WHERE - pnew.qname_id is null + tanp.qname_id IS NULL ; -DROP TABLE t_avm_node_properties; + +DROP TABLE avm_node_properties_new; DROP TABLE avm_node_properties; -ALTER TABLE avm_node_properties_new RENAME TO avm_node_properties; +ALTER TABLE t_avm_node_properties RENAME TO avm_node_properties; -------------------- +-- ----------------- -- Build Locales -- -------------------- +-- ----------------- CREATE TABLE alf_locale ( @@ -659,9 +657,9 @@ INSERT INTO alf_locale (locale_str) JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) ; ---------------------------------- +-- ------------------------------- -- Migrate ADM Property Tables -- ---------------------------------- +-- ------------------------------- CREATE TABLE t_alf_node_properties ( @@ -686,8 +684,7 @@ CREATE TABLE t_alf_node_properties PRIMARY KEY (node_id, qname_id, list_index, locale_id) ) TYPE=InnoDB; --- Copy all simple values over --- Query OK, 2905008 rows affected (7 min 11.49 sec) +-- Copy values over INSERT INTO t_alf_node_properties ( node_id, qname_id, list_index, locale_id, @@ -708,14 +705,69 @@ INSERT INTO t_alf_node_properties JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = np.actual_type) JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = np.persisted_type) WHERE - np.attribute_value is null AND - tqn.qname NOT IN - ( - '{http://www.alfresco.org/model/content/1.0}created', - '{http://www.alfresco.org/model/content/1.0}creator', - '{http://www.alfresco.org/model/content/1.0}modified', - '{http://www.alfresco.org/model/content/1.0}modifier' - ) + np.attribute_value IS NULL +; +-- Update cm:auditable properties on the nodes +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 = 'FILLER-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 = 'FILLER-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 = 'FILLER-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 = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modified' +); +-- Remove the unused cm:auditable properties +DELETE t_alf_node_properties + FROM t_alf_node_properties + JOIN alf_qname ON (t_alf_node_properties.qname_id = alf_qname.id) + JOIN alf_namespace ON (alf_qname.ns_id = alf_namespace.id) + WHERE + alf_namespace.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + alf_qname.local_name IN ('creator', 'created', 'modifier', 'modified') ; -- Copy all MLText values over @@ -789,9 +841,15 @@ DELETE alf_attributes ; DROP TABLE t_del_attributes; --------------------- +-- --------------------------------------------------- +-- Remove the FILLER- values from the namespace uri -- +-- --------------------------------------------------- +UPDATE alf_namespace SET uri = '.empty' WHERE uri = 'FILLER-'; +UPDATE alf_namespace SET uri = SUBSTR(uri, 8) WHERE uri LIKE 'FILLER-%'; + +-- ------------------ -- Final clean up -- --------------------- +-- ------------------ DROP TABLE t_qnames; DROP TABLE t_prop_types; DROP TABLE alf_node_status; @@ -802,14 +860,175 @@ ALTER TABLE t_alf_node RENAME TO alf_node; DROP TABLE alf_store; ALTER TABLE t_alf_store RENAME TO alf_store; + +-- ------------------------------------- +-- Modify index and constraint names -- +-- ------------------------------------- +ALTER TABLE alf_attributes DROP INDEX fk_attributes_n_acl, DROP FOREIGN KEY fk_attributes_n_acl; -- (optional) +ALTER TABLE alf_attributes + ADD INDEX fk_alf_attr_acl (acl_id) +; + +ALTER TABLE alf_audit_date DROP INDEX adt_woy_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_date_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_y_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_q_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_m_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_dow_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_doy_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_dom_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_hy_idx; -- (optional) +ALTER TABLE alf_audit_date DROP INDEX adt_wom_idx; -- (optional) +ALTER TABLE alf_audit_date + ADD INDEX idx_alf_adtd_woy (week_of_year), + ADD INDEX idx_alf_adtd_q (quarter), + ADD INDEX idx_alf_adtd_wom (week_of_month), + ADD INDEX idx_alf_adtd_dom (day_of_month), + ADD INDEX idx_alf_adtd_doy (day_of_year), + ADD INDEX idx_alf_adtd_dow (day_of_week), + ADD INDEX idx_alf_adtd_m (month), + ADD INDEX idx_alf_adtd_hy (half_year), + ADD INDEX idx_alf_adtd_fy (full_year), + ADD INDEX idx_alf_adtd_dat (date_only) +; + +ALTER TABLE alf_audit_fact DROP INDEX adt_user_idx; -- (optional) +ALTER TABLE alf_audit_fact DROP INDEX adt_store_idx; -- (optional) +ALTER TABLE alf_audit_fact + DROP INDEX FKEAD18174A0F9B8D9, DROP FOREIGN KEY FKEAD18174A0F9B8D9, + DROP INDEX FKEAD1817484342E39, DROP FOREIGN KEY FKEAD1817484342E39, + DROP INDEX FKEAD18174F524CFD7, DROP FOREIGN KEY FKEAD18174F524CFD7 +; +ALTER TABLE alf_audit_fact + ADD INDEX idx_alf_adtf_ref (store_protocol, store_id, node_uuid), + ADD INDEX idx_alf_adtf_usr (user_id), + ADD INDEX fk_alf_adtf_src (audit_source_id), + ADD CONSTRAINT fk_alf_adtf_src FOREIGN KEY (audit_source_id) REFERENCES alf_audit_source (id), + ADD INDEX fk_alf_adtf_date (audit_date_id), + ADD CONSTRAINT fk_alf_adtf_date FOREIGN KEY (audit_date_id) REFERENCES alf_audit_date (id), + ADD INDEX fk_alf_adtf_conf (audit_conf_id), + ADD CONSTRAINT fk_alf_adtf_conf FOREIGN KEY (audit_conf_id) REFERENCES alf_audit_config (id) +; + +ALTER TABLE alf_audit_source DROP INDEX app_source_app_idx; -- (optional) +ALTER TABLE alf_audit_source DROP INDEX app_source_ser_idx; -- (optional) +ALTER TABLE alf_audit_source DROP INDEX app_source_met_idx; -- (optional) +ALTER TABLE alf_audit_source + ADD INDEX idx_alf_adts_met (method), + ADD INDEX idx_alf_adts_ser (service), + ADD INDEX idx_alf_adts_app (application) +; + +ALTER TABLE alf_global_attributes DROP FOREIGN KEY FK64D0B9CF69B9F16A; -- (optional) +ALTER TABLE alf_global_attributes DROP INDEX FK64D0B9CF69B9F16A; -- (optional) +-- alf_global_attributes.attribute is declared unique. Indexes may automatically have been created. +ALTER TABLE alf_global_attributes + ADD INDEX fk_alf_gatt_att (attribute); -- (optional) +ALTER TABLE alf_global_attributes + ADD CONSTRAINT fk_alf_gatt_att FOREIGN KEY (attribute) REFERENCES alf_attributes (id) +; + +ALTER TABLE alf_list_attribute_entries DROP INDEX FKC7D52FB02C5AB86C, DROP FOREIGN KEY FKC7D52FB02C5AB86C; -- (optional) +ALTER TABLE alf_list_attribute_entries DROP INDEX FKC7D52FB0ACD8822C, DROP FOREIGN KEY FKC7D52FB0ACD8822C; -- (optional) +ALTER TABLE alf_list_attribute_entries + ADD INDEX fk_alf_lent_att (attribute_id), + ADD CONSTRAINT fk_alf_lent_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id), + ADD INDEX fk_alf_lent_latt (list_id), + ADD CONSTRAINT fk_alf_lent_latt FOREIGN KEY (list_id) REFERENCES alf_attributes (id) +; + +ALTER TABLE alf_map_attribute_entries DROP INDEX FK335CAE26AEAC208C, DROP FOREIGN KEY FK335CAE26AEAC208C; -- (optional) +ALTER TABLE alf_map_attribute_entries DROP INDEX FK335CAE262C5AB86C, DROP FOREIGN KEY FK335CAE262C5AB86C; -- (optional) +ALTER TABLE alf_map_attribute_entries + ADD INDEX fk_alf_matt_matt (map_id), + ADD CONSTRAINT fk_alf_matt_matt FOREIGN KEY (map_id) REFERENCES alf_attributes (id), + ADD INDEX fk_alf_matt_att (attribute_id), + ADD CONSTRAINT fk_alf_matt_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id) +; + +ALTER TABLE alf_transaction DROP INDEX idx_commit_time_ms; -- (optional) +ALTER TABLE alf_transaction + DROP INDEX FKB8761A3A9AE340B7, DROP FOREIGN KEY FKB8761A3A9AE340B7, + ADD INDEX fk_alf_txn_svr (server_id), + ADD CONSTRAINT fk_alf_txn_svr FOREIGN KEY (server_id) REFERENCES alf_server (id), + ADD INDEX idx_alf_txn_ctms (commit_time_ms) +; + +ALTER TABLE avm_child_entries DROP INDEX fk_avm_ce_child, DROP FOREIGN KEY fk_avm_ce_child; -- (optional) +ALTER TABLE avm_child_entries DROP INDEX fk_avm_ce_parent, DROP FOREIGN KEY fk_avm_ce_parent; -- (optional) +ALTER TABLE avm_child_entries + ADD INDEX fk_avm_ce_child (child_id), + ADD CONSTRAINT fk_avm_ce_child FOREIGN KEY (child_id) REFERENCES avm_nodes (id), + ADD INDEX fk_avm_ce_parent (parent_id), + ADD CONSTRAINT fk_avm_ce_parent FOREIGN KEY (parent_id) REFERENCES avm_nodes (id) +; + +ALTER TABLE avm_history_links DROP INDEX fk_avm_hl_desc, DROP FOREIGN KEY fk_avm_hl_desc; -- (optional) +ALTER TABLE avm_history_links DROP INDEX fk_avm_hl_ancestor, DROP FOREIGN KEY fk_avm_hl_ancestor; -- (optional) +ALTER TABLE avm_history_links DROP INDEX idx_avm_hl_revpk; -- (optional) +ALTER TABLE avm_history_links + ADD INDEX fk_avm_hl_desc (descendent), + ADD CONSTRAINT fk_avm_hl_desc FOREIGN KEY (descendent) REFERENCES avm_nodes (id), + ADD INDEX fk_avm_hl_ancestor (ancestor), + ADD CONSTRAINT fk_avm_hl_ancestor FOREIGN KEY (ancestor) REFERENCES avm_nodes (id), + ADD INDEX idx_avm_hl_revpk (descendent, ancestor) +; + +ALTER TABLE avm_merge_links DROP INDEX fk_avm_ml_to, DROP FOREIGN KEY fk_avm_ml_to; -- (optional) +ALTER TABLE avm_merge_links DROP INDEX fk_avm_ml_from, DROP FOREIGN KEY fk_avm_ml_from; -- (optional) +ALTER TABLE avm_merge_links + ADD INDEX fk_avm_ml_to (mto), + ADD CONSTRAINT fk_avm_ml_to FOREIGN KEY (mto) REFERENCES avm_nodes (id), + ADD INDEX fk_avm_ml_from (mfrom), + ADD CONSTRAINT fk_avm_ml_from FOREIGN KEY (mfrom) REFERENCES avm_nodes (id) +; + +ALTER TABLE avm_nodes DROP INDEX fk_avm_n_acl, DROP FOREIGN KEY fk_avm_n_acl; -- (optional) +ALTER TABLE avm_nodes DROP INDEX fk_avm_n_store, DROP FOREIGN KEY fk_avm_n_store; -- (optional) +ALTER TABLE avm_nodes DROP INDEX idx_avm_n_pi; -- (optional) +ALTER TABLE avm_nodes + ADD INDEX fk_avm_n_acl (acl_id), + ADD CONSTRAINT fk_avm_n_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + ADD INDEX fk_avm_n_store (store_new_id), + ADD CONSTRAINT fk_avm_n_store FOREIGN KEY (store_new_id) REFERENCES avm_stores (id), + ADD INDEX idx_avm_n_pi (primary_indirection) +; + +ALTER TABLE avm_stores DROP INDEX fk_avm_s_root, DROP FOREIGN KEY fk_avm_s_root; -- (optional) +ALTER TABLE avm_stores + ADD INDEX fk_avm_s_acl (acl_id), + ADD CONSTRAINT fk_avm_s_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + ADD INDEX fk_avm_s_root (current_root_id), + ADD CONSTRAINT fk_avm_s_root FOREIGN KEY (current_root_id) REFERENCES avm_nodes (id) +; + +ALTER TABLE avm_version_layered_node_entry DROP INDEX FK182E672DEB9D70C, DROP FOREIGN KEY FK182E672DEB9D70C; -- (optional) +ALTER TABLE avm_version_layered_node_entry + ADD INDEX fk_avm_vlne_vr (version_root_id), + ADD CONSTRAINT fk_avm_vlne_vr FOREIGN KEY (version_root_id) REFERENCES avm_version_roots (id) +; + +ALTER TABLE avm_version_roots DROP INDEX idx_avm_vr_version; -- (optional) +ALTER TABLE avm_version_roots DROP INDEX idx_avm_vr_revuq; -- (optional) +ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_root, DROP FOREIGN KEY fk_avm_vr_root; -- (optional) +ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_store, DROP FOREIGN KEY fk_avm_vr_store; -- (optional) +ALTER TABLE avm_version_roots + ADD INDEX idx_avm_vr_version (version_id), + ADD INDEX idx_avm_vr_revuq (avm_store_id, version_id), + ADD INDEX fk_avm_vr_root (root_id), + ADD CONSTRAINT fk_avm_vr_root FOREIGN KEY (root_id) REFERENCES avm_nodes (id), + ADD INDEX fk_avm_vr_store (avm_store_id), + ADD CONSTRAINT fk_avm_vr_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id) +; + -- -- Record script finish -- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-1-FullDmUpgrade'; +DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Upgrade-From-2.1'; 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-1-FullDmUpgrade', 'Manually executed script upgrade V2.2: ADM ', + 'patch.db-V2.2-Upgrade-From-2.1', 'Manually executed script upgrade V2.2: Upgrade from 2.1', 0, 85, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql new file mode 100644 index 0000000000..3bd927c874 --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql @@ -0,0 +1,583 @@ +-- +-- Title: Upgrade V2.2 SP1 or SP2 +-- Database: MySQL +-- 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 BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL, + protocol VARCHAR(50) NOT NULL, + identifier VARCHAR(100) NOT NULL, + root_node_id BIGINT, + PRIMARY KEY (id), + UNIQUE (protocol, identifier) +) TYPE=InnoDB; + +-- -------------------------- +-- Populate the ADM nodes -- +-- -------------------------- + +CREATE TABLE t_alf_node ( + id BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL, + store_id BIGINT NOT NULL, + uuid VARCHAR(36) NOT NULL, + transaction_id BIGINT NOT NULL, + node_deleted bit NOT NULL, + type_qname_id BIGINT NOT NULL, + acl_id BIGINT, + audit_creator VARCHAR(255), + audit_created VARCHAR(30), + audit_modifier VARCHAR(255), + audit_modified VARCHAR(30), + audit_accessed VARCHAR(30), + INDEX idx_alf_node_del (node_deleted), + INDEX fk_alf_node_acl (acl_id), + INDEX fk_alf_node_tqn (type_qname_id), + INDEX fk_alf_node_txn (transaction_id), + INDEX fk_alf_node_store (store_id), + 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), + UNIQUE (store_id, uuid) +) TYPE=InnoDB; + +-- Fill the store table +INSERT INTO t_alf_store (version, protocol, identifier, root_node_id) + SELECT 1, protocol, identifier, root_node_id FROM alf_store +; + +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 + ) + SELECT + n.id, 1, s.id, n.uuid, nstat.transaction_id, false, n.type_qname_id, n.acl_id, + 'unknown', '2008-09-17T02:23:37.212+01:00', 'unkown', '2008-09-17T02:23:37.212+01:00' + FROM + alf_node n + JOIN alf_node_status nstat ON (nstat.node_id = n.id) + JOIN t_alf_store s ON (s.protocol = nstat.protocol AND s.identifier = nstat.identifier) +; + +-- Hook the store up to the root node +ALTER TABLE t_alf_store + ADD INDEX fk_alf_store_root (root_node_id), + ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id) +; + +-- ----------------------------- +-- Populate Version Counter -- +-- ----------------------------- + +CREATE TABLE t_alf_version_count +( + id BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL, + store_id BIGINT NOT NULL UNIQUE, + version_count INTEGER NOT NULL, + INDEX fk_alf_vc_store (store_id), + CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id), + PRIMARY KEY (id) +) TYPE=InnoDB; + +INSERT INTO t_alf_version_count + ( + version, store_id, version_count + ) + SELECT + 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 BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL, + parent_node_id BIGINT NOT NULL, + type_qname_id BIGINT NOT NULL, + child_node_name VARCHAR(50) NOT NULL, + child_node_name_crc BIGINT NOT NULL, + child_node_id BIGINT NOT NULL, + qname_ns_id BIGINT NOT NULL, + qname_localname VARCHAR(100) NOT NULL, + is_primary BIT, + assoc_index INTEGER, + INDEX idx_alf_cass_qnln (qname_localname), + INDEX fk_alf_cass_pnode (parent_node_id), + INDEX fk_alf_cass_cnode (child_node_id), + INDEX fk_alf_cass_tqn (type_qname_id), + INDEX fk_alf_cass_qnns (qname_ns_id), + 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), + UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc) +) TYPE=InnoDB; + +INSERT INTO t_alf_child_assoc + ( + id, version, + parent_node_id, child_node_id, + child_node_name, child_node_name_crc, + type_qname_id, + qname_ns_id, qname_localname, + is_primary, assoc_index + ) + SELECT + ca.id, 1, + ca.parent_node_id, ca.child_node_id, + ca.child_node_name, child_node_name_crc, + ca.type_qname_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; + +-- ---------------------------- +-- Populate the Node Assocs -- +-- ---------------------------- + +CREATE TABLE t_alf_node_assoc +( + id BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL, + source_node_id BIGINT NOT NULL, + target_node_id BIGINT NOT NULL, + type_qname_id BIGINT NOT NULL, + INDEX fk_alf_nass_snode (source_node_id), + INDEX fk_alf_nass_tnode (target_node_id), + INDEX fk_alf_nass_tqn (type_qname_id), + 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), + UNIQUE (source_node_id, target_node_id, type_qname_id) +) TYPE=InnoDB; + +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.source_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; + +-- ----------------------------- +-- Populate the Node Aspects -- +-- ----------------------------- + +CREATE TABLE t_alf_node_aspects +( + node_id BIGINT NOT NULL, + qname_id BIGINT NOT NULL, + INDEX fk_alf_nasp_n (node_id), + INDEX fk_alf_nasp_qn (qname_id), + 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) +) TYPE=InnoDB; + +-- 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 BIGINT NOT NULL, + qname_id BIGINT NOT NULL, + INDEX fk_avm_nasp_n (node_id), + INDEX fk_avm_nasp_qn (qname_id), + 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) +) TYPE=InnoDB; + +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 BIGINT NOT NULL AUTO_INCREMENT, + avm_store_id BIGINT, + qname_id BIGINT NOT NULL, + actual_type_n integer NOT NULL, + persisted_type_n integer NOT NULL, + multi_valued bit NOT NULL, + boolean_value bit, + long_value BIGINT, + float_value float, + double_value DOUBLE PRECISION, + string_value TEXT, + serializable_value blob, + INDEX fk_avm_sprop_store (avm_store_id), + INDEX fk_avm_sprop_qname (qname_id), + 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) +) TYPE=InnoDB; +INSERT INTO t_avm_store_properties + ( + 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 + 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 BIGINT NOT NULL, + actual_type_n INTEGER NOT NULL, + persisted_type_n INTEGER NOT NULL, + multi_valued BIT NOT NULL, + boolean_value BIT, + long_value BIGINT, + float_value FLOAT, + double_value DOUBLE PRECISION, + string_value TEXT, + serializable_value BLOB, + qname_id BIGINT NOT NULL, + INDEX fk_avm_nprop_n (node_id), + INDEX fk_avm_nprop_qn (qname_id), + 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) +) TYPE=InnoDB; +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 BIGINT NOT NULL AUTO_INCREMENT, + version BIGINT NOT NULL DEFAULT 1, + locale_str VARCHAR(20) NOT NULL, + PRIMARY KEY (id), + UNIQUE (locale_str) +) TYPE=InnoDB; + +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 (locale_str) + 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) +; + +-- ------------------------------- +-- Migrate ADM Property Tables -- +-- ------------------------------- + +CREATE TABLE t_alf_node_properties +( + node_id BIGINT NOT NULL, + qname_id BIGINT NOT NULL, + locale_id BIGINT NOT NULL, + list_index smallint NOT NULL, + actual_type_n INTEGER NOT NULL, + persisted_type_n INTEGER NOT NULL, + boolean_value BIT, + long_value BIGINT, + float_value FLOAT, + double_value DOUBLE PRECISION, + string_value TEXT, + serializable_value BLOB, + INDEX fk_alf_nprop_n (node_id), + INDEX fk_alf_nprop_qn (qname_id), + INDEX fk_alf_nprop_loc (locale_id), + 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) +) TYPE=InnoDB; + +-- Copy 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, 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 cm:auditable properties on the nodes +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 t_alf_node_properties + FROM t_alf_node_properties + JOIN alf_qname ON (t_alf_node_properties.qname_id = alf_qname.id) + JOIN alf_namespace ON (alf_qname.ns_id = alf_namespace.id) + WHERE + 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 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 BIGINT NOT NULL, + PRIMARY KEY (id) +); +INSERT INTO t_del_attributes + SELECT id FROM alf_attributes WHERE type = 'M' +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_map_attribute_entries ma ON (ma.attribute_id = t_del_attributes.id) +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_list_attribute_entries la ON (la.attribute_id = t_del_attributes.id) +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_global_attributes ga ON (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 alf_map_attribute_entries + FROM alf_map_attribute_entries + JOIN t_del_attributes t ON (alf_map_attribute_entries.map_id = t.id) +; +DELETE alf_attributes + FROM alf_attributes + JOIN t_del_attributes t ON (alf_attributes.id = t.id) +; +DROP TABLE t_del_attributes; + +-- ------------------ +-- Final clean up -- +-- ------------------ +DROP TABLE alf_node_status; +ALTER TABLE alf_store DROP FOREIGN KEY 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; + + +-- +-- 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', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-1-drop-indexes-and-constraints.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-1-drop-indexes-and-constraints.sql deleted file mode 100644 index b899367eeb..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-1-drop-indexes-and-constraints.sql +++ /dev/null @@ -1,211 +0,0 @@ --- --- Title: Remote all pre-2.2 indexes and constraints --- Database: Oracle --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - -DROP INDEX fk_alf_ace_ctx; -ALTER TABLE alf_access_control_entry DROP CONSTRAINT fk_alf_ace_ctx; - -DROP INDEX fk_alf_ace_perm; -ALTER TABLE alf_access_control_entry DROP CONSTRAINT fk_alf_ace_perm; - -DROP INDEX fk_alf_ace_auth; -ALTER TABLE alf_access_control_entry DROP CONSTRAINT fk_alf_ace_auth; - -DROP INDEX fk_alf_acl_acs; -ALTER TABLE alf_access_control_list DROP CONSTRAINT fk_alf_acl_acs; - --- -DROP INDEX idx_alf_acl_inh; - -DROP INDEX fk_alf_aclm_acl; -ALTER TABLE alf_acl_member DROP CONSTRAINT fk_alf_aclm_acl; - -DROP INDEX fk_alf_aclm_ace; -ALTER TABLE alf_acl_member DROP CONSTRAINT fk_alf_aclm_ace; - --- Table might not exist -DROP INDEX fk_attr_n_acl; -- (optional) -ALTER TABLE alf_attributes DROP CONSTRAINT fk_attributes_n_acl; -- (optional) - -DROP INDEX adt_woy_idx; -- (optional) - -DROP INDEX adt_date_idx; -- (optional) - -DROP INDEX adt_y_idx; -- (optional) - -DROP INDEX adt_q_idx; -- (optional) - -DROP INDEX adt_m_idx; -- (optional) - -DROP INDEX adt_dow_idx; -- (optional) - -DROP INDEX adt_doy_idx; -- (optional) - -DROP INDEX adt_dom_idx; -- (optional) - -DROP INDEX adt_hy_idx; -- (optional) - -DROP INDEX adt_wom_idx; -- (optional) - -DROP INDEX adt_user_idx; -- (optional) - -DROP INDEX adt_store_idx; -- (optional) - -DROP INDEX FKEAD18174A0F9B8D9; -ALTER TABLE alf_audit_fact DROP CONSTRAINT FKEAD18174A0F9B8D9; - -DROP INDEX FKEAD1817484342E39; -ALTER TABLE alf_audit_fact DROP CONSTRAINT FKEAD1817484342E39; - -DROP INDEX FKEAD18174F524CFD7; -ALTER TABLE alf_audit_fact DROP CONSTRAINT FKEAD18174F524CFD7; - -DROP INDEX app_source_app_idx; -- (optional) - -DROP INDEX app_source_ser_idx; -- (optional) - -DROP INDEX app_source_met_idx; -- (optional) - -DROP INDEX idx_alf_auth_aut; - -DROP INDEX fk_alf_autha_ali; -ALTER TABLE alf_authority_alias DROP CONSTRAINT fk_alf_autha_ali; - -DROP INDEX fk_alf_autha_aut; -ALTER TABLE alf_authority_alias DROP CONSTRAINT fk_alf_autha_aut; - -DROP INDEX FKFFC5468E8E50E582; -ALTER TABLE alf_child_assoc DROP CONSTRAINT FKFFC5468E8E50E582; - -DROP INDEX FKFFC5468E74173FF4; -ALTER TABLE alf_child_assoc DROP CONSTRAINT FKFFC5468E74173FF4; - -ALTER TABLE alf_global_attributes DROP CONSTRAINT FK64D0B9CF69B9F16A; -- (optional) -DROP INDEX FK64D0B9CF69B9F16A; --(optional) - -DROP INDEX FKC7D52FB02C5AB86C; -- (optional) -ALTER TABLE alf_list_attribute_entries DROP CONSTRAINT FKC7D52FB02C5AB86C; -- (optional) - -DROP INDEX FKC7D52FB0ACD8822C; -- (optional) -ALTER TABLE alf_list_attribute_entries DROP CONSTRAINT FKC7D52FB0ACD8822C; -- (optional) - -DROP INDEX FK335CAE26AEAC208C; -- (optional) -ALTER TABLE alf_map_attribute_entries DROP CONSTRAINT FK335CAE26AEAC208C; -- (optional) - -DROP INDEX FK335CAE262C5AB86C; -- (optional) -ALTER TABLE alf_map_attribute_entries DROP CONSTRAINT FK335CAE262C5AB86C; -- (optional) - -DROP INDEX FK60EFB626B9553F6C; -ALTER TABLE alf_node DROP CONSTRAINT FK60EFB626B9553F6C; - -DROP INDEX FK60EFB626D24ADD25; -ALTER TABLE alf_node DROP CONSTRAINT FK60EFB626D24ADD25; - -DROP INDEX FKD654E027F2C8017; -ALTER TABLE alf_node_aspects DROP CONSTRAINT FKD654E027F2C8017; - -DROP INDEX FKE1A550BCB69C43F3; -ALTER TABLE alf_node_assoc DROP CONSTRAINT FKE1A550BCB69C43F3; - -DROP INDEX FKE1A550BCA8FC7769; -ALTER TABLE alf_node_assoc DROP CONSTRAINT FKE1A550BCA8FC7769; - -DROP INDEX FK7D4CF8EC7F2C8017; -ALTER TABLE alf_node_properties DROP CONSTRAINT FK7D4CF8EC7F2C8017; - -DROP INDEX FK7D4CF8EC40E780DC; -- (optional) -ALTER TABLE alf_node_properties DROP CONSTRAINT FK7D4CF8EC40E780DC; -- (optional) - -DROP INDEX FK71C2002B7F2C8017; -ALTER TABLE alf_node_status DROP CONSTRAINT FK71C2002B7F2C8017; - -DROP INDEX FK71C2002B9E57C13D; -ALTER TABLE alf_node_status DROP CONSTRAINT FK71C2002B9E57C13D; - -DROP INDEX FKBD4FF53D22DBA5BA; -ALTER TABLE alf_store DROP CONSTRAINT FKBD4FF53D22DBA5BA; - -DROP INDEX idx_commit_time_ms; -- (optional) - -DROP INDEX FKB8761A3A9AE340B7; -ALTER TABLE alf_transaction DROP CONSTRAINT FKB8761A3A9AE340B7; - -DROP INDEX fk_avm_asp_node; -- (optional) -ALTER TABLE avm_aspects DROP CONSTRAINT fk_avm_asp_node; --(optional) - -DROP INDEX FKD3FD9F95EDCD4A96; -- (optional) -ALTER TABLE avm_aspects_new DROP CONSTRAINT FKD3FD9F95EDCD4A96; -- (optional) - -DROP INDEX fk_avm_ce_child; -- (optional) -ALTER TABLE avm_child_entries DROP CONSTRAINT fk_avm_ce_child; --(optional) - -DROP INDEX fk_avm_ce_parent; -- (optional) -ALTER TABLE avm_child_entries DROP CONSTRAINT fk_avm_ce_parent; --(optional) - -DROP INDEX fk_avm_hl_desc; -- (optional) -ALTER TABLE avm_history_links DROP CONSTRAINT fk_avm_hl_desc; --(optional) - -DROP INDEX fk_avm_hl_ancestor; -- (optional) -ALTER TABLE avm_history_links DROP CONSTRAINT fk_avm_hl_ancestor; --(optional) - -DROP INDEX idx_avm_hl_revpk; -- (optional) - -DROP INDEX fk_avm_ml_to; -- (optional) -ALTER TABLE avm_merge_links DROP CONSTRAINT fk_avm_ml_to; --(optional) - -DROP INDEX fk_avm_ml_from; -- (optional) -ALTER TABLE avm_merge_links DROP CONSTRAINT fk_avm_ml_from; --(optional) - -DROP INDEX idx_avm_np_name; --(optional) - -DROP INDEX fk_avm_np_node; --(optional) -ALTER TABLE avm_node_properties DROP CONSTRAINT fk_avm_np_node; --(optional) - -DROP INDEX FK44A37C8A6BD529F3; --(optional) -ALTER TABLE avm_node_properties_new DROP CONSTRAINT FK44A37C8A6BD529F3; --(optional) - -DROP INDEX fk_avm_n_acl; --(optional) -ALTER TABLE avm_nodes DROP CONSTRAINT fk_avm_n_acl; --(optional) - -DROP INDEX fk_avm_n_store; --(optional) -ALTER TABLE avm_nodes DROP CONSTRAINT fk_avm_n_store; --(optional) - -DROP INDEX idx_avm_n_pi; --(optional) - -DROP INDEX idx_avm_sp_name; --(optional) - -DROP INDEX fk_avm_sp_store; --(optional) -ALTER TABLE avm_store_properties DROP CONSTRAINT fk_avm_sp_store; --(optional) - -DROP INDEX fk_avm_s_root; --(optional) -ALTER TABLE avm_stores DROP CONSTRAINT fk_avm_s_root; --(optional) - -DROP INDEX FK182E672DEB9D70C; --(optional) -ALTER TABLE avm_version_layered_node_entry DROP CONSTRAINT FK182E672DEB9D70C; --(optional) - -DROP INDEX idx_avm_vr_version; --(optional) - -DROP INDEX idx_avm_vr_revuq; --(optional) - -DROP INDEX fk_avm_vr_root; --(optional) -ALTER TABLE avm_version_roots DROP CONSTRAINT fk_avm_vr_root; --(optional) - -DROP INDEX fk_avm_vr_store; --(optional) -ALTER TABLE avm_version_roots DROP CONSTRAINT fk_avm_vr_store; --(optional) - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-1-DropIndexesAndConstraints'; -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-1-DropIndexesAndConstraints', 'Manually executed script upgrade V2.2: Remove pre-2.2 indexes and constraints', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-1-mltext.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-1-mltext.sql deleted file mode 100644 index 35857f5bb9..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-1-mltext.sql +++ /dev/null @@ -1,177 +0,0 @@ --- --- Title: Pull MLText Values into Node Properties --- Database: Oracle --- Since: V2.2 Schema 90 --- Author: Derek Hulley --- --- MLText values must be pulled back from attributes into localizable properties. --- Several statements are not relevant to upgrades from below 77. These are optional. --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - -CREATE TABLE alf_locale -( - id NUMBER(19,0) DEFAULT 0 NOT NULL, - version NUMBER(19,0) DEFAULT 1 NOT NULL, - locale_str VARCHAR2(20 CHAR) NOT NULL, - UNIQUE (locale_str) -); - -INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default'); - -INSERT INTO alf_locale (locale_str) -( - 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) -); -- (OPTIONAL) -UPDATE alf_locale SET id = hibernate_sequence.nextval WHERE id != 1; -ALTER TABLE alf_locale ADD PRIMARY KEY (id); - --- Create a temporary table to hold the attribute_value information that needs replacing -CREATE TABLE t_alf_node_properties -( - node_id NUMBER(19,0) NOT NULL, - qname_id NUMBER(19,0) NOT NULL, - list_index NUMBER(10,0) NOT NULL, - locale_id NUMBER(19,0) NOT NULL, - actual_type_n NUMBER(10,0) NOT NULL, - persisted_type_n NUMBER(10,0) NOT NULL, - boolean_value NUMBER(1,0), - long_value NUMBER(19,0), - float_value FLOAT, - double_value DOUBLE PRECISION, - string_value VARCHAR2(1024 char), - serializable_value BLOB, - CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES alf_node, - CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname, - CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale, - 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 all simple 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, 1, - np.actual_type_n, np.persisted_type_n, - np.boolean_value, np.long_value, np.float_value, np.double_value, - np.string_value, - TO_LOB(np.serializable_value) - FROM alf_node_properties np - WHERE - np.attribute_value is null -; - --- 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, - 0, 0, 0, 0, - a2.string_value, - TO_LOB(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 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; - --- Clean up unused attribute values - -CREATE TABLE t_del_attributes -( - id NUMBER(19, 0) NOT NULL, - PRIMARY KEY (id) -); -INSERT INTO t_del_attributes -( - SELECT id FROM alf_attributes WHERE type = 'M' -) -; -DELETE - FROM t_del_attributes t - WHERE t.id = - ( - SELECT ma.attribute_id FROM alf_map_attribute_entries ma WHERE ma.attribute_id = t.id - ) -; -DELETE - FROM t_del_attributes t - WHERE t.id = - ( - SELECT la.attribute_id FROM alf_list_attribute_entries la WHERE la.attribute_id = t.id - ) -; -DELETE - FROM t_del_attributes t - WHERE t.id = - ( - SELECT ga.attribute FROM alf_global_attributes ga WHERE ga.attribute = t.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 ma - WHERE ma.map_id = - ( - SELECT t.id FROM t_del_attributes t WHERE t.id = ma.map_id - ) -; -DELETE - FROM alf_attributes a - WHERE a.id = - ( - SELECT t.id FROM t_del_attributes t WHERE t.id = a.id - ) -; -DROP TABLE t_del_attributes; - - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-1-MLText'; -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-1-MLText', 'Manually executed script upgrade V2.2: Moved MLText values', - 0, 90, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' - ); \ No newline at end of file diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-2-move-qnames.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-2-move-qnames.sql deleted file mode 100644 index 9bee01dc22..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-2-move-qnames.sql +++ /dev/null @@ -1,371 +0,0 @@ --- --- Title: Move static QNames and Namsespaces into a separate table --- Database: Oracle --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- --- This script replaces the various static QName and Namespace entries --- with a more efficient FK relationship to the static values. --- - --- Create static namespace and qname tables --- The Primary Key is not added as it's easier to add in afterwards -CREATE TABLE alf_namespace -( - id NUMBER(19,0) DEFAULT 0 NOT NULL, - version number(19,0) NOT NULL, - uri VARCHAR2(100 CHAR) NOT NULL, - UNIQUE (uri) -); - -CREATE TABLE alf_qname -( - id NUMBER(19,0) DEFAULT 0 NOT NULL, - version NUMBER(19,0) NOT NULL, - ns_id NUMBER(19,0) NOT NULL, - local_name VARCHAR2(200 char) NOT NULL, - UNIQUE (ns_id, local_name) -); - --- Create temporary indexes and constraints -CREATE INDEX t_fk_alf_qn_ns on alf_qname (ns_id); - --- Create temporary table for dynamic (child) QNames -CREATE TABLE t_qnames_dyn -( - qname VARCHAR2(255) NOT NULL, - namespace VARCHAR2(255) -); -CREATE INDEX tidx_qnd_qn ON t_qnames_dyn (qname); -CREATE INDEX tidx_qnd_ns ON t_qnames_dyn (namespace); - --- Populate the table with the child association paths -INSERT INTO t_qnames_dyn (qname) -( - SELECT qname FROM alf_child_assoc -); --- Extract the Namespace -UPDATE t_qnames_dyn SET namespace = CONCAT('FILLER-', SUBSTR(qname,2,INSTRC(qname,'}',1)-2)); --- Move the namespaces to the their new home -INSERT INTO alf_namespace (uri, version) -( - SELECT - DISTINCT(x.namespace), 1 - FROM - ( - SELECT t.namespace, n.uri FROM t_qnames_dyn t LEFT OUTER JOIN alf_namespace n ON (n.uri = t.namespace) - ) x - WHERE - x.uri IS NULL -); --- We can trash the temp table -DROP TABLE t_qnames_dyn; - --- Create temporary table to hold static QNames -CREATE TABLE t_qnames -( - qname VARCHAR2(255) NOT NULL, - namespace VARCHAR2(255), - localname VARCHAR2(255) -); -CREATE INDEX tidx_tqn_qn ON t_qnames (qname); -CREATE INDEX tidx_tqn_ns ON t_qnames (namespace); -CREATE INDEX tidx_tqn_ln ON t_qnames (localname); - --- Populate the table with all known static QNames -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_node -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM alf_node_aspects -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM alf_node_properties -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT name FROM avm_aspects_new -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM avm_node_properties_new -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT qname FROM avm_store_properties -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_node_assoc -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_child_assoc -); -INSERT INTO t_qnames (qname) -( - SELECT DISTINCT type_qname FROM alf_permission -); --- Extract the namespace and localnames from the QNames -UPDATE t_qnames SET namespace = CONCAT('FILLER-', SUBSTR(qname,2,INSTRC(qname,'}',1)-2)); -UPDATE t_qnames SET localname = SUBSTR(qname,INSTRC(qname,'}',1)+1); --- Move the Namespaces to their new home -INSERT INTO alf_namespace (uri, version) -( - SELECT - DISTINCT(x.namespace), 1 - FROM - ( - SELECT t.namespace, n.uri FROM t_qnames t LEFT OUTER JOIN alf_namespace n ON (n.uri = t.namespace) - ) x - WHERE - x.uri IS NULL -); -UPDATE alf_namespace SET id = hibernate_sequence.nextval; -ALTER TABLE alf_namespace ADD PRIMARY KEY (id); - --- Move the Localnames to their new home -INSERT INTO alf_qname (ns_id, local_name, version) -( - SELECT - x.ns_id, x.t_localname, 1 - FROM - ( - SELECT n.id AS ns_id, t.localname AS t_localname, q.local_name AS q_localname - FROM t_qnames t - JOIN alf_namespace n ON (n.uri = t.namespace) - LEFT OUTER JOIN alf_qname q ON (q.local_name = t.localname) - ) x - WHERE - q_localname IS NULL - GROUP BY x.ns_id, x.t_localname -); -UPDATE alf_qname SET id = hibernate_sequence.nextval; -ALTER TABLE alf_qname ADD PRIMARY KEY (id); - --- Check the data -ALTER TABLE alf_qname ADD CONSTRAINT t_fk_alf_qn_ns FOREIGN KEY (ns_id) REFERENCES alf_namespace (id); - --- We can get trash the temp table -DROP TABLE t_qnames; - --- --- DATA REPLACEMENT: alf_node.type_qname --- -ALTER TABLE alf_node ADD ( type_qname_id NUMBER(19,0) NULL ); -UPDATE alf_node n SET n.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = n.type_qname -); -ALTER TABLE alf_node DROP COLUMN type_qname; -ALTER TABLE alf_node MODIFY ( type_qname_id NUMBER(19,0) NOT NULL ); - --- --- DATA REPLACEMENT: alf_node_aspects.qname --- Due to the the potentially-missing primary key on the original table, it is --- possible to have duplicates. These are removed. --- -ALTER TABLE alf_node_aspects DROP PRIMARY KEY; -- (optional) -ALTER TABLE alf_node_aspects ADD ( qname_id NUMBER(19,0) NULL ); -UPDATE alf_node_aspects na SET na.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = na.qname -); -ALTER TABLE alf_node_aspects DROP COLUMN qname; -ALTER TABLE alf_node_aspects MODIFY ( qname_id NUMBER(19,0) NOT NULL); -CREATE TABLE t_dup_aspects -( - node_id NUMBER(19,0) NOT NULL, - qname_id NUMBER(19,0) NOT NULL -); -INSERT INTO t_dup_aspects (node_id, qname_id) -( - SELECT - node_id, qname_id - FROM - alf_node_aspects - GROUP BY - node_id, qname_id - HAVING - count(*) > 1 -); -DELETE alf_node_aspects na WHERE na.rowid IN ( - SELECT ina.rowid FROM alf_node_aspects ina - JOIN t_dup_aspects t ON (ina.node_id = t.node_id AND ina.qname_id = t.qname_id) -); -INSERT INTO alf_node_aspects (node_id, qname_id) -( - SELECT - node_id, qname_id - FROM - t_dup_aspects - GROUP BY - node_id, qname_id -); -DROP TABLE t_dup_aspects; -ALTER TABLE alf_node_aspects ADD PRIMARY KEY (node_id, qname_id); - --- --- DATA REPLACEMENT: alf_node_properties.qname --- -ALTER TABLE alf_node_properties DROP PRIMARY KEY; -ALTER TABLE alf_node_properties ADD ( qname_id NUMBER(19,0) NULL ); -UPDATE alf_node_properties np SET np.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = np.qname -); -ALTER TABLE alf_node_properties DROP COLUMN qname; -ALTER TABLE alf_node_properties MODIFY ( qname_id NUMBER(19,0) NOT NULL); -ALTER TABLE alf_node_properties ADD PRIMARY KEY (node_id, qname_id); - --- --- DATA REPLACEMENT: avm_aspects_new.name (aka qname) --- -ALTER TABLE avm_aspects_new DROP PRIMARY KEY; -ALTER TABLE avm_aspects_new ADD ( qname_id NUMBER(19,0) NULL ); -UPDATE avm_aspects_new na SET na.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = na.name -); -ALTER TABLE avm_aspects_new DROP COLUMN name; -ALTER TABLE avm_aspects_new MODIFY ( qname_id NUMBER(19,0) NOT NULL); -ALTER TABLE avm_aspects_new ADD PRIMARY KEY (id, qname_id); - --- --- DATA REPLACEMENT: avm_node_properties.qname --- --- This table is deprecated and made empty so there is no need to alter it - --- --- DATA REPLACEMENT: avm_node_properties_new.qname --- -ALTER TABLE avm_node_properties_new DROP PRIMARY KEY; -ALTER TABLE avm_node_properties_new ADD ( qname_id NUMBER(19,0) NULL ); -UPDATE avm_node_properties_new np SET np.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = np.qname -); -ALTER TABLE avm_node_properties_new DROP COLUMN qname; -ALTER TABLE avm_node_properties_new MODIFY ( qname_id NUMBER(19,0) NOT NULL); -ALTER TABLE avm_node_properties_new ADD PRIMARY KEY (node_id, qname_id); - --- --- DATA REPLACEMENT: avm_store_properties.qname --- -ALTER TABLE avm_store_properties ADD ( qname_id NUMBER(19,0) NULL ); -UPDATE avm_store_properties np SET np.qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = np.qname -); -ALTER TABLE avm_store_properties DROP COLUMN qname; -ALTER TABLE avm_store_properties MODIFY ( qname_id NUMBER(19,0) NOT NULL); - --- --- DATA REPLACEMENT: alf_child_assoc.type_qname --- -ALTER TABLE alf_child_assoc DROP UNIQUE (parent_node_id, type_qname, child_node_name, child_node_name_crc); -ALTER TABLE alf_child_assoc ADD ( type_qname_id NUMBER(19,0) NULL ); -UPDATE alf_child_assoc ca SET ca.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = ca.type_qname -); -ALTER TABLE alf_child_assoc DROP COLUMN type_qname; -ALTER TABLE alf_child_assoc MODIFY ( type_qname_id NUMBER(19,0) NOT NULL); -ALTER TABLE alf_child_assoc ADD UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc); - --- --- DATA REPLACEMENT: alf_child_assoc.qname --- --- Namespace -ALTER TABLE alf_child_assoc ADD ( qname_ns_id NUMBER(19,0) NULL ); -UPDATE alf_child_assoc ca SET ca.qname_ns_id = -( - SELECT ns.id - FROM alf_namespace ns - WHERE CONCAT('...', SUBSTR(qname,2,INSTRC(qname,'}',1)-2)) = CONCAT('...', SUBSTR(ns.uri, 8)) -); -ALTER TABLE alf_child_assoc MODIFY ( qname_ns_id NUMBER(19,0) NOT NULL); --- LocalName -ALTER TABLE alf_child_assoc ADD ( qname_localname VARCHAR2(200) NULL); -UPDATE alf_child_assoc ca SET ca.qname_localname = SUBSTR(qname,INSTRC(qname,'}',1)+1); -ALTER TABLE alf_child_assoc MODIFY ( qname_localname VARCHAR2(200) NOT NULL); --- Drop old column -ALTER TABLE alf_child_assoc DROP COLUMN qname; - --- --- DATA REPLACEMENT: alf_node_assoc.type_qname --- -ALTER TABLE alf_node_assoc DROP UNIQUE (source_node_id, target_node_id, type_qname); -ALTER TABLE alf_node_assoc ADD ( type_qname_id NUMBER(19,0) NULL ); -UPDATE alf_node_assoc na SET na.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = na.type_qname -); -ALTER TABLE alf_node_assoc DROP COLUMN type_qname; -ALTER TABLE alf_node_assoc MODIFY ( type_qname_id NUMBER(19,0) NOT NULL); -ALTER TABLE alf_node_assoc ADD UNIQUE (source_node_id, target_node_id, type_qname_id); - --- --- DATA REPLACEMENT: alf_permission.type_qname --- -ALTER TABLE alf_permission DROP UNIQUE (type_qname, name); -ALTER TABLE alf_permission ADD ( type_qname_id NUMBER(19,0) NULL ); -UPDATE alf_permission p SET p.type_qname_id = -( - SELECT q.id - FROM alf_qname q - JOIN alf_namespace ns ON (q.ns_id = ns.id) - WHERE CONCAT(CONCAT('{', SUBSTR(ns.uri, 8)), CONCAT('}', q.local_name)) = p.type_qname -); -ALTER TABLE alf_permission DROP COLUMN type_qname; -ALTER TABLE alf_permission MODIFY ( type_qname_id NUMBER(19,0) NOT NULL); -ALTER TABLE alf_permission ADD UNIQUE (type_qname_id, name); - --- Drop the temporary indexes and constraints -DROP INDEX t_fk_alf_qn_ns; -ALTER TABLE alf_qname DROP CONSTRAINT t_fk_alf_qn_ns; - --- Remove the FILLER- values from the namespace uri -UPDATE alf_namespace SET uri = '.empty' WHERE uri = 'FILLER-'; -UPDATE alf_namespace SET uri = SUBSTR(uri, 8) WHERE uri LIKE 'FILLER-%'; - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-2-MoveQNames'; -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-2-MoveQNames', 'Manually executed script upgrade V2.2: Moved static QNames and Namespaces', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-3-proptypes.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-3-proptypes.sql deleted file mode 100644 index dd470d74d3..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9Dialect/upgrade-3-proptypes.sql +++ /dev/null @@ -1,102 +0,0 @@ --- --- Title: Replace property type descriptors with numerical equivalents --- Database: Oracle --- Since: V2.2 Schema 86 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- - --- Create temporary mapping for property types -CREATE TABLE t_prop_types -( - type_name VARCHAR2(15) NOT NULL, - type_id INTEGER NOT NULL, - PRIMARY KEY (type_name) -); -INSERT INTO t_prop_types values ('NULL', 0); -INSERT INTO t_prop_types values ('BOOLEAN', 1); -INSERT INTO t_prop_types values ('INTEGER', 2); -INSERT INTO t_prop_types values ('LONG', 3); -INSERT INTO t_prop_types values ('FLOAT', 4); -INSERT INTO t_prop_types values ('DOUBLE', 5); -INSERT INTO t_prop_types values ('STRING', 6); -INSERT INTO t_prop_types values ('DATE', 7); -INSERT INTO t_prop_types values ('DB_ATTRIBUTE', 8); -INSERT INTO t_prop_types values ('SERIALIZABLE', 9); -INSERT INTO t_prop_types values ('MLTEXT', 10); -INSERT INTO t_prop_types values ('CONTENT', 11); -INSERT INTO t_prop_types values ('NODEREF', 12); -INSERT INTO t_prop_types values ('CHILD_ASSOC_REF', 13); -INSERT INTO t_prop_types values ('ASSOC_REF', 14); -INSERT INTO t_prop_types values ('QNAME', 15); -INSERT INTO t_prop_types values ('PATH', 16); -INSERT INTO t_prop_types values ('LOCALE', 17); -INSERT INTO t_prop_types values ('VERSION_NUMBER', 18); - --- Modify the alf_node_properties table -ALTER TABLE alf_node_properties ADD ( actual_type_n NUMBER(10,0) NULL ); -ALTER TABLE alf_node_properties ADD ( persisted_type_n NUMBER(10,0) NULL ); - -UPDATE alf_node_properties p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE alf_node_properties p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE alf_node_properties DROP COLUMN actual_type; -ALTER TABLE alf_node_properties DROP COLUMN persisted_type; - -ALTER TABLE alf_node_properties MODIFY ( actual_type_n NUMBER(10,0) NOT NULL ); -ALTER TABLE alf_node_properties MODIFY ( persisted_type_n NUMBER(10,0) NOT NULL ); - --- Modify the avm_node_properties_new table -ALTER TABLE avm_node_properties_new ADD ( actual_type_n NUMBER(10,0) NULL ); -ALTER TABLE avm_node_properties_new ADD ( persisted_type_n NUMBER(10,0) NULL ); - -UPDATE avm_node_properties_new p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE avm_node_properties_new p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE avm_node_properties_new DROP COLUMN actual_type; -ALTER TABLE avm_node_properties_new DROP COLUMN persisted_type; - -ALTER TABLE avm_node_properties_new MODIFY ( actual_type_n NUMBER(10,0) NOT NULL ); -ALTER TABLE avm_node_properties_new MODIFY ( persisted_type_n NUMBER(10,0) NOT NULL ); - --- Modify the avm_store_properties table -ALTER TABLE avm_store_properties ADD ( actual_type_n NUMBER(10,0) NULL ); -ALTER TABLE avm_store_properties ADD ( persisted_type_n NUMBER(10,0) NULL ); - -UPDATE avm_store_properties p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE avm_store_properties p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE avm_store_properties DROP COLUMN actual_type; -ALTER TABLE avm_store_properties DROP COLUMN persisted_type; - -ALTER TABLE avm_store_properties MODIFY ( actual_type_n NUMBER(10,0) NOT NULL ); -ALTER TABLE avm_store_properties MODIFY ( persisted_type_n NUMBER(10,0) NOT NULL ); - --- Modify the avm_node_properties table -ALTER TABLE avm_node_properties ADD ( actual_type_n NUMBER(10,0) NULL ); -ALTER TABLE avm_node_properties ADD ( persisted_type_n NUMBER(10,0) NULL ); - -UPDATE avm_node_properties p SET p.actual_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.actual_type); -UPDATE avm_node_properties p SET p.persisted_type_n = (SELECT t.type_id FROM t_prop_types t WHERE t.type_name = p.persisted_type); - -ALTER TABLE avm_node_properties DROP COLUMN actual_type; -ALTER TABLE avm_node_properties DROP COLUMN persisted_type; - -ALTER TABLE avm_node_properties MODIFY ( actual_type_n NUMBER(10,0) NOT NULL ); -ALTER TABLE avm_node_properties MODIFY ( persisted_type_n NUMBER(10,0) NOT NULL ); - --- Remove temporary table -DROP TABLE t_prop_types; - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-3-PropTypes'; -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-3-PropTypes', 'Manually executed script upgrade V2.2: Changed PropertyValue types', - 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' - ); diff --git a/config/alfresco/patch/patch-services-context.xml b/config/alfresco/patch/patch-services-context.xml index 420d4baed0..9bd233460d 100644 --- a/config/alfresco/patch/patch-services-context.xml +++ b/config/alfresco/patch/patch-services-context.xml @@ -1209,124 +1209,50 @@ - - - - - patch.db-V2.2-1-MLText - patch.schemaUpgradeScript.description - 86 - 90 - 91 + 121 + 134 + 135 - classpath:alfresco/dbscripts/upgrade/2.2/${db.script.dialect}/upgrade-1-mltext.sql + classpath:alfresco/dbscripts/upgrade/2.2/${db.script.dialect}/upgrade-from-2.2SP1.sql - + - - - patch.db-V2.2-1-FullDmUpgrade - patch.schemaUpgradeScript.description - 0 - 85 - 91 - - classpath:alfresco/dbscripts/upgrade/2.2/${db.script.dialect}/upgrade-1-fulldm.sql - - + - + @@ -1409,7 +1335,7 @@ - +