mirror of
https://github.com/Alfresco/alfresco-community-repo.git
synced 2025-07-24 17:32:48 +00:00
Merged V2.2 to HEAD
8146: Interim checkin for Oracle upgrade scripts. 8150: AR-1905 8151: AR-1956 8152: Correct I18N when reporting patch description 8153: QName script for Oracle along with fixes for unique constraints on assoc tables 8155: Upgrade scripts for Oracle V2.2 - almost there 8164: AWC-1633: Unable to edit rule added via web service 8166: V2.2 upgrade scripts for MySQL and Oracle 8170: AWC-1515: E-mail doesn't reach user's mail box, if it was created with the help of templates 8174: Fix for AWC-798 8180: Fix for AWC-1843 8183: Fixes for different unique index names on alf_child_assoc 8189: AWC-1719: Need to alllow Rules to account for a space being deleted 8249: Fixed handling of empty namespaces on Oracle 8259: Fixes for null namespaces in QName 8360: Modified alf_audit_date columns and added patch 8404: Fix AR-2133: Fix handling of empty namespaces during upgrade git-svn-id: https://svn.alfresco.com/repos/alfresco-enterprise/alfresco/HEAD/root@8481 c4b6b30b-aa2e-2d43-bbcb-ca4b014f7261
This commit is contained in:
@@ -1,6 +1,6 @@
|
||||
--
|
||||
-- Title: Create additional indexes and constraints
|
||||
-- Database: MySQL
|
||||
-- Database: Generic
|
||||
-- Since: V2.2 Schema 86
|
||||
-- Author: Derek Hulley
|
||||
--
|
||||
@@ -21,9 +21,9 @@ 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 (halfYear);
|
||||
CREATE INDEX idx_alf_adtd_hy ON alf_audit_date (half_year);
|
||||
|
||||
CREATE INDEX idx_alf_adtd_y ON alf_audit_date (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);
|
||||
|
||||
@@ -73,11 +73,11 @@ 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-QNames-4-ExtraIndexesAndConstraints';
|
||||
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-QNames-4-ExtraIndexesAndConstraints', 'Manually executed script upgrade V2.2: Created additional indexes and constraints',
|
||||
'patch.db-V2.2-4-ExtraIndexesAndConstraints', 'Manually executed script upgrade V2.2: Created additional indexes and constraints',
|
||||
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -0,0 +1,108 @@
|
||||
--
|
||||
-- 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);
|
||||
|
||||
CREATE INDEX fk_alf_n_prop ON alf_node_properties (node_id);
|
||||
CREATE INDEX fk_alf_np_attr ON alf_node_properties (attribute_value);
|
||||
|
||||
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, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -11,7 +11,7 @@ CREATE TABLE alf_acl_change_set (
|
||||
id BIGINT NOT NULL AUTO_INCREMENT,
|
||||
version BIGINT NOT NULL,
|
||||
primary key (id)
|
||||
) type=InnoDB;
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
|
||||
-- Add to ACL
|
||||
@@ -44,7 +44,7 @@ CREATE TABLE alf_acl_member (
|
||||
pos INT NOT NULL,
|
||||
primary key (id),
|
||||
unique(acl_id, ace_id, pos)
|
||||
) type=InnoDB;
|
||||
) 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);
|
||||
@@ -92,7 +92,7 @@ CREATE TABLE alf_ace_context (
|
||||
property_context VARCHAR(1024),
|
||||
kvp_context VARCHAR(1024),
|
||||
primary key (id)
|
||||
) type=InnoDB;
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
|
||||
-- Create auth aliases table
|
||||
@@ -103,7 +103,7 @@ CREATE TABLE alf_authority_alias (
|
||||
alias_id BIGINT NOT NULL,
|
||||
primary key (id),
|
||||
UNIQUE (auth_id, alias_id)
|
||||
) type=InnoDB;
|
||||
) 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);
|
||||
@@ -138,9 +138,9 @@ UPDATE alf_acl_member mem
|
||||
|
||||
-- Remove duplicate aces the mysql way (as you can not use the deleted table in the where clause ...)
|
||||
|
||||
CREATE TEMPORARY TABLE tmp_to_delete SELECT ace.id FROM alf_acl_member mem RIGHT OUTER JOIN alf_access_control_entry ace ON mem.ace_id = ace.id WHERE mem.ace_id IS NULL;
|
||||
CREATE TABLE tmp_to_delete SELECT ace.id FROM alf_acl_member mem RIGHT OUTER JOIN alf_access_control_entry ace ON mem.ace_id = ace.id WHERE mem.ace_id IS NULL;
|
||||
DELETE FROM alf_access_control_entry ace USING alf_access_control_entry ace JOIN tmp_to_delete t ON ace.id = t.id;
|
||||
DROP TEMPORARY TABLE tmp_to_delete;
|
||||
DROP TABLE tmp_to_delete;
|
||||
|
||||
-- Add constraint for duplicate acls
|
||||
|
||||
@@ -157,4 +157,4 @@ INSERT INTO alf_applied_patch
|
||||
(
|
||||
'patch.db-V2.2-ACL', 'Manually executed script upgrade V2.2: Update acl schema',
|
||||
0, 84, -1, 85, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
||||
);
|
||||
|
@@ -10,6 +10,13 @@
|
||||
-- to simplify subsequent upgrade scripts.
|
||||
--
|
||||
|
||||
-- Fix alf_audit_date column names
|
||||
|
||||
ALTER TABLE alf_audit_date CHANGE COLUMN halfYear half_year INTEGER NOT NULL;
|
||||
ALTER TABLE alf_audit_date CHANGE COLUMN year full_year INTEGER NOT NULL;
|
||||
|
||||
-- create other new tables
|
||||
|
||||
create table avm_aspects (
|
||||
id bigint not null auto_increment,
|
||||
node_id bigint,
|
||||
@@ -73,11 +80,11 @@
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-0-CreateMissingTables';
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-0-CreateMissingTables';
|
||||
INSERT INTO alf_applied_patch
|
||||
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
|
||||
VALUES
|
||||
(
|
||||
'patch.db-V2.2-QNames-0-CreateMissingTables', 'Manually executed script upgrade V2.2: Created missing tables',
|
||||
'patch.db-V2.2-0-CreateMissingTables', 'Manually executed script upgrade V2.2: Created missing tables',
|
||||
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
||||
|
@@ -21,6 +21,7 @@ ALTER TABLE alf_acl_member DROP INDEX fk_alf_aclm_acl, DROP FOREIGN KEY fk_alf_a
|
||||
|
||||
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)
|
||||
@@ -153,11 +154,11 @@ ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_store, DROP FOREIGN KEY fk_av
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-1-DropIndexesAndConstraints';
|
||||
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-QNames-1-DropIndexesAndConstraints', 'Manually executed script upgrade V2.2: Remove pre-2.2 indexes and constraints',
|
||||
'patch.db-V2.2-1-DropIndexesAndConstraints', 'Manually executed script upgrade V2.2: Remove pre-2.2 indexes and constraints',
|
||||
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
||||
|
@@ -30,9 +30,8 @@ CREATE TABLE alf_qname
|
||||
UNIQUE (ns_id, local_name)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
-- Create temporary indexes and constraints
|
||||
-- Create temporary index
|
||||
CREATE INDEX t_fk_alf_qn_ns on alf_qname (ns_id);
|
||||
ALTER TABLE alf_qname ADD CONSTRAINT t_fk_alf_qn_ns FOREIGN KEY (ns_id) REFERENCES alf_namespace (id);
|
||||
|
||||
-- Create temporary table for dynamic (child) QNames
|
||||
CREATE TABLE t_qnames_dyn
|
||||
@@ -46,10 +45,10 @@ 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
|
||||
SELECT qname FROM alf_child_assoc
|
||||
);
|
||||
-- Extract the Namespace
|
||||
UPDATE t_qnames_dyn SET namespace = SUBSTR(SUBSTRING_INDEX(qname, '}', 1), 2);
|
||||
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)
|
||||
(
|
||||
@@ -62,7 +61,11 @@ INSERT INTO alf_namespace (uri, version)
|
||||
WHERE
|
||||
x.uri IS NULL
|
||||
);
|
||||
-- We can get trash the temp table
|
||||
|
||||
-- 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
|
||||
@@ -114,7 +117,7 @@ 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 = SUBSTR(SUBSTRING_INDEX(qname, '}', 1), 2);
|
||||
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)
|
||||
@@ -128,6 +131,7 @@ INSERT INTO alf_namespace (uri, version)
|
||||
WHERE
|
||||
x.uri IS NULL
|
||||
);
|
||||
|
||||
-- Move the Localnames to their new home
|
||||
INSERT INTO alf_qname (ns_id, local_name, version)
|
||||
(
|
||||
@@ -144,19 +148,20 @@ INSERT INTO alf_qname (ns_id, local_name, version)
|
||||
q_localname IS NULL
|
||||
GROUP BY x.ns_id, x.t_localname
|
||||
);
|
||||
-- We can get trash the temp table
|
||||
|
||||
-- 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 =
|
||||
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('{', ns.uri, '}', q.local_name) = n.type_qname
|
||||
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;
|
||||
@@ -168,12 +173,12 @@ ALTER TABLE alf_node MODIFY COLUMN type_qname_id BIGINT NOT NULL AFTER uuid;
|
||||
--
|
||||
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 =
|
||||
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('{', ns.uri, '}', q.local_name) = na.qname
|
||||
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;
|
||||
@@ -211,12 +216,12 @@ ALTER TABLE alf_node_aspects ADD PRIMARY KEY (node_id, qname_id);
|
||||
--
|
||||
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 =
|
||||
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('{', ns.uri, '}', q.local_name) = np.qname
|
||||
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;
|
||||
@@ -227,12 +232,12 @@ ALTER TABLE alf_node_properties ADD PRIMARY KEY (node_id, qname_id);
|
||||
--
|
||||
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 =
|
||||
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('{', ns.uri, '}', q.local_name) = na.name
|
||||
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;
|
||||
@@ -248,12 +253,12 @@ ALTER TABLE avm_aspects_new ADD PRIMARY KEY (id, qname_id);
|
||||
--
|
||||
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 =
|
||||
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('{', ns.uri, '}', q.local_name) = np.qname
|
||||
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;
|
||||
@@ -263,12 +268,12 @@ 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 =
|
||||
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('{', ns.uri, '}', q.local_name) = np.qname
|
||||
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;
|
||||
@@ -276,27 +281,31 @@ ALTER TABLE avm_store_properties MODIFY COLUMN qname_id BIGINT NOT NULL AFTER av
|
||||
--
|
||||
-- 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 =
|
||||
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('{', ns.uri, '}', q.local_name) = ca.type_qname
|
||||
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 =
|
||||
UPDATE alf_child_assoc ca SET ca.qname_ns_id =
|
||||
(
|
||||
SELECT ns.id
|
||||
FROM alf_namespace ns
|
||||
WHERE SUBSTR(SUBSTRING_INDEX(qname, '}', 1), 2) = ns.uri
|
||||
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
|
||||
@@ -309,43 +318,53 @@ 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 =
|
||||
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('{', ns.uri, '}', q.local_name) = na.type_qname
|
||||
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 =
|
||||
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('{', ns.uri, '}', q.local_name) = p.type_qname
|
||||
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-QNames-2-MoveQNames';
|
||||
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-QNames-2-MoveQNames', 'Manually executed script upgrade V2.2: Moved static QNames and Namespaces',
|
||||
'patch.db-V2.2-2-MoveQNames', 'Manually executed script upgrade V2.2: Moved static QNames and Namespaces',
|
||||
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
||||
|
@@ -92,11 +92,11 @@ DROP TABLE t_prop_types;
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-3-PropTypes';
|
||||
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-QNames-3-PropTypes', 'Manually executed script upgrade V2.2: Changed PropertyValue types',
|
||||
'patch.db-V2.2-3-PropTypes', 'Manually executed script upgrade V2.2: Changed PropertyValue types',
|
||||
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
||||
|
@@ -0,0 +1,22 @@
|
||||
--
|
||||
-- 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, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -0,0 +1,178 @@
|
||||
--
|
||||
-- Title: Update for permissions schema changes
|
||||
-- Database: Oracle
|
||||
-- Since: V2.2 Schema 85
|
||||
-- Author: Andy Hind
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
|
||||
CREATE TABLE alf_acl_change_set (
|
||||
id NUMBER(19,0) NOT NULL,
|
||||
version NUMBER(19,0) NOT NULL,
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
|
||||
-- Add to ACL
|
||||
ALTER TABLE alf_access_control_list ADD (
|
||||
type NUMBER(10,0) DEFAULT 0 NOT NULL,
|
||||
latest NUMBER(1,0) DEFAULT 1 NOT NULL,
|
||||
acl_id VARCHAR2(36 CHAR) DEFAULT 'UNSET' NOT NULL,
|
||||
acl_version NUMBER(19,0) DEFAULT 1 NOT NULL,
|
||||
inherited_acl NUMBER(19,0),
|
||||
is_versioned NUMBER(1,0) DEFAULT 0 NOT NULL,
|
||||
requires_version NUMBER(1,0) DEFAULT 0 NOT NULL,
|
||||
acl_change_set NUMBER(19,0),
|
||||
inherits_from NUMBER(19,0)
|
||||
);
|
||||
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);
|
||||
|
||||
UPDATE alf_access_control_list acl
|
||||
set acl_id = (acl.id);
|
||||
|
||||
ALTER TABLE alf_access_control_list
|
||||
ADD UNIQUE (acl_id, latest, acl_version);
|
||||
|
||||
-- Create ACL member list
|
||||
CREATE TABLE alf_acl_member (
|
||||
id NUMBER(19,0) NOT NULL,
|
||||
version NUMBER(19,0) NOT NULL,
|
||||
acl_id NUMBER(19,0) NOT NULL,
|
||||
ace_id NUMBER(19,0) NOT NULL,
|
||||
pos NUMBER(10,0) NOT NULL,
|
||||
primary key (id),
|
||||
unique (acl_id, ace_id, pos)
|
||||
);
|
||||
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 UNIQUE (acl_id, permission_id, authority_id);
|
||||
|
||||
-- Extend ACE
|
||||
ALTER TABLE alf_access_control_entry ADD (
|
||||
auth_id NUMBER(19,0) DEFAULT -1 NOT NULL,
|
||||
applies NUMBER(10,0) DEFAULT 0 NOT NULL,
|
||||
context_id NUMBER(19,0)
|
||||
);
|
||||
|
||||
-- remove unused
|
||||
DROP TABLE alf_auth_ext_keys;
|
||||
|
||||
-- remove authority constraint
|
||||
DROP INDEX FKFFF41F99B25A50BF;
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT FKFFF41F99B25A50BF; -- (optional)
|
||||
|
||||
-- restructure authority
|
||||
ALTER TABLE alf_authority DROP PRIMARY KEY;
|
||||
ALTER TABLE alf_authority ADD (
|
||||
id number(19,0) DEFAULT 0 NOT NULL,
|
||||
crc NUMBER(19,0)
|
||||
);
|
||||
UPDATE alf_authority SET id = hibernate_sequence.nextval;
|
||||
ALTER TABLE alf_authority RENAME COLUMN recipient TO authority;
|
||||
ALTER TABLE alf_authority MODIFY (
|
||||
authority VARCHAR(100)
|
||||
);
|
||||
ALTER TABLE alf_authority ADD PRIMARY KEY (id);
|
||||
ALTER TABLE alf_authority 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
|
||||
SET auth_id = (SELECT id FROM alf_authority a WHERE a.authority = ace.authority_id);
|
||||
|
||||
|
||||
-- migrate data - build equivalent ACL entries
|
||||
INSERT INTO alf_acl_member (id, version, acl_id, ace_id, pos)
|
||||
select hibernate_sequence.nextval, 1, acl_id, id, 0 from alf_access_control_entry;
|
||||
|
||||
-- Create ACE context
|
||||
CREATE TABLE alf_ace_context (
|
||||
id NUMBER(19,0) NOT NULL,
|
||||
version NUMBER(19,0) NOT NULL,
|
||||
class_context VARCHAR2(1024 CHAR),
|
||||
property_context VARCHAR2(1024 CHAR),
|
||||
kvp_context VARCHAR2(1024 CHAR),
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
|
||||
-- Create auth aliases table
|
||||
CREATE TABLE alf_authority_alias (
|
||||
id NUMBER(19,0) NOT NULL,
|
||||
version NUMBER(19,0) NOT NULL,
|
||||
auth_id NUMBER(19,0) NOT NULL,
|
||||
alias_id NUMBER(19,0) NOT NULL,
|
||||
PRIMARY KEY (id),
|
||||
UNIQUE (auth_id, alias_id)
|
||||
);
|
||||
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
|
||||
-- finish take out of ACL_ID
|
||||
DROP INDEX FKFFF41F99B9553F6C;
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT FKFFF41F99B9553F6C;
|
||||
DROP INDEX FKFFF41F9960601995;
|
||||
ALTER TABLE alf_access_control_entry DROP CONSTRAINT FKFFF41F9960601995;
|
||||
ALTER TABLE alf_access_control_entry DROP (
|
||||
acl_id,
|
||||
authority_id
|
||||
);
|
||||
ALTER TABLE alf_access_control_entry RENAME COLUMN auth_id TO authority_id;
|
||||
CREATE INDEX fk_alf_ace_auth ON alf_access_control_entry (authority_id);
|
||||
ALTER TABLE alf_access_control_entry ADD CONSTRAINT fk_alf_ace_auth FOREIGN KEY (authority_id) REFERENCES alf_authority (id);
|
||||
CREATE INDEX fk_alf_ace_perm ON alf_access_control_entry (permission_id);
|
||||
ALTER TABLE alf_access_control_entry ADD CONSTRAINT fk_alf_ace_perm FOREIGN KEY (permission_id) REFERENCES alf_permission (id);
|
||||
CREATE INDEX fk_alf_ace_ctx ON alf_access_control_entry (context_id);
|
||||
ALTER TABLE alf_access_control_entry ADD CONSTRAINT fk_alf_ace_ctx FOREIGN KEY (context_id) REFERENCES alf_ace_context (id);
|
||||
|
||||
|
||||
|
||||
-- Update members to point to the first use of an access control entry
|
||||
UPDATE alf_acl_member mem
|
||||
SET ace_id = (SELECT min(ace2.id) FROM alf_access_control_entry ace1
|
||||
JOIN alf_access_control_entry ace2
|
||||
ON ace1.permission_id = ace2.permission_id AND
|
||||
ace1.authority_id = ace2.authority_id AND
|
||||
ace1.allowed = ace2.allowed AND
|
||||
ace1.applies = ace2.applies
|
||||
WHERE ace1.id = mem.ace_id );
|
||||
|
||||
-- Remove duplicate aces the mysql way (as you can not use the deleted table in the where clause ...)
|
||||
|
||||
CREATE TABLE tmp_to_delete (
|
||||
id NUMBER(19,0) NOT NULL,
|
||||
PRIMARY KEY (id)
|
||||
);
|
||||
INSERT INTO tmp_to_delete (
|
||||
SELECT ace.id FROM alf_acl_member mem RIGHT OUTER JOIN alf_access_control_entry ace ON mem.ace_id = ace.id WHERE mem.ace_id IS NULL
|
||||
);
|
||||
DELETE FROM alf_access_control_entry ace WHERE ace.id IN (SELECT id FROM tmp_to_delete);
|
||||
DROP TABLE tmp_to_delete;
|
||||
|
||||
-- Add constraint for duplicate acls
|
||||
|
||||
ALTER TABLE alf_access_control_entry
|
||||
ADD UNIQUE (permission_id, authority_id, allowed, applies, context_id);
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-ACL';
|
||||
INSERT INTO alf_applied_patch
|
||||
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
|
||||
VALUES
|
||||
(
|
||||
'patch.db-V2.2-ACL', 'Manually executed script upgrade V2.2: Update acl schema',
|
||||
0, 84, -1, 85, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -0,0 +1,90 @@
|
||||
--
|
||||
-- Title: Create missing 2.1 tables
|
||||
-- Database: Oracle
|
||||
-- Since: V2.2 Schema 86
|
||||
-- Author: Derek Hulley
|
||||
--
|
||||
-- Please contact support@alfresco.com if you need assistance with the upgrade.
|
||||
--
|
||||
-- Upgrade paths that bypass V2.1 will need to have a some tables added in order
|
||||
-- to simplify subsequent upgrade scripts.
|
||||
--
|
||||
|
||||
-- Fix alf_audit_date column names
|
||||
|
||||
ALTER TABLE alf_audit_date RENAME COLUMN halfYear TO half_year;
|
||||
ALTER TABLE alf_audit_date RENAME COLUMN year TO full_year;
|
||||
|
||||
-- create other new tables
|
||||
|
||||
create table avm_aspects (
|
||||
id number(19,0) not null,
|
||||
node_id number(19,0),
|
||||
qname varchar2(200 char),
|
||||
primary key (id)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_aspects_new (
|
||||
id number(19,0) not null,
|
||||
qname_id number(19,0) not null,
|
||||
primary key (id, qname_id)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_node_properties (
|
||||
id number(19,0) not null,
|
||||
node_id number(19,0),
|
||||
qname varchar2(200 char),
|
||||
actual_type_n number(10,0) not null,
|
||||
persisted_type_n number(10,0) not null,
|
||||
multi_valued number(1,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 long raw,
|
||||
primary key (id)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_node_properties_new (
|
||||
node_id number(19,0) not null,
|
||||
actual_type_n number(10,0) not null,
|
||||
persisted_type_n number(10,0) not null,
|
||||
multi_valued number(1,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 long raw,
|
||||
qname_id number(19,0) not null,
|
||||
primary key (node_id, qname_id)
|
||||
); -- (optional)
|
||||
|
||||
create table avm_store_properties (
|
||||
id number(19,0) not null,
|
||||
avm_store_id number(19,0),
|
||||
qname_id number(19,0) not null,
|
||||
actual_type_n number(10,0) not null,
|
||||
persisted_type_n number(10,0) not null,
|
||||
multi_valued number(1,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 long raw,
|
||||
primary key (id)
|
||||
); -- (optional)
|
||||
|
||||
--
|
||||
-- Record script finish
|
||||
--
|
||||
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-0-CreateMissingTables';
|
||||
INSERT INTO alf_applied_patch
|
||||
(id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report)
|
||||
VALUES
|
||||
(
|
||||
'patch.db-V2.2-0-CreateMissingTables', 'Manually executed script upgrade V2.2: Created missing tables',
|
||||
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -0,0 +1,211 @@
|
||||
--
|
||||
-- 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, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -0,0 +1,371 @@
|
||||
--
|
||||
-- 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, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
@@ -0,0 +1,102 @@
|
||||
--
|
||||
-- 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, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
|
||||
);
|
Reference in New Issue
Block a user