Merged V2.2 to HEAD

7629: QName Refactor Merge 6 of 9
   7630: QName Refactor Merge 7 of 9
   7631: QName Refactor Merge 8 of 9
   7632: QName Refactor Merge 9 of 9


git-svn-id: https://svn.alfresco.com/repos/alfresco-enterprise/alfresco/HEAD/root@8438 c4b6b30b-aa2e-2d43-bbcb-ca4b014f7261
This commit is contained in:
Derek Hulley
2008-03-06 19:11:36 +00:00
parent 00e81c0d66
commit d389ff1936
30 changed files with 805 additions and 746 deletions

View File

@@ -24,9 +24,9 @@ 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,
ADD INDEX FK_ACL_CH_SET (acl_change_set),
ADD CONSTRAINT FOREIGN KEY FK_ACL_CH_SET (acl_change_set) REFERENCES alf_acl_change_set (id);
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);
UPDATE alf_access_control_list acl
set acl_id = (acl.id);
@@ -42,13 +42,12 @@ CREATE TABLE alf_acl_member (
ace_id BIGINT NOT NULL,
pos INT NOT NULL,
primary key (id),
unique(acl_id, ace_id, pos),
index FK_ACL_ID (acl_id),
CONSTRAINT FOREIGN KEY FK_ACL_ID (acl_id) REFERENCES alf_access_control_list (id),
index FK_ACE_ID (ace_id),
CONSTRAINT FOREIGN KEY FK_ACE_ID (ace_id) REFERENCES alf_access_control_entry (id)
unique(acl_id, ace_id, pos)
) type=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;
@@ -63,8 +62,7 @@ ALTER TABLE alf_access_control_entry
DROP TABLE alf_auth_ext_keys;
-- remove authority constraint
ALTER TABLE alf_access_control_entry
DROP FOREIGN KEY FKFFF41F99B25A50BF;
ALTER TABLE alf_access_control_entry DROP INDEX FKFFF41F99B25A50BF, DROP FOREIGN KEY FKFFF41F99B25A50BF;
-- restructure authority
ALTER TABLE alf_authority
@@ -72,7 +70,7 @@ ALTER TABLE alf_authority
ADD COLUMN id BIGINT NOT NULL AUTO_INCREMENT,
CHANGE recipient authority VARCHAR(100),
ADD primary key (id),
ADD CONSTRAINT UNIQUE INDEX U_AUTH (authority);
ADD UNIQUE (authority);
-- migrate data - fix up FK refs to authority
UPDATE alf_access_control_entry ace
@@ -101,23 +99,28 @@ CREATE TABLE alf_authority_alias (
auth_id BIGINT NOT NULL,
alias_id BIGINT NOT NULL,
primary key (id),
INDEX FK_ALIAS_TO_AUTH (alias_id),
CONSTRAINT FOREIGN KEY FK_ALIAS_TO_AUTH (alias_id) REFERENCES alf_authority (id),
INDEX FK_AUTH_TO_AUTH (auth_id),
CONSTRAINT FOREIGN KEY FK_AUTH_TO_AUTH (auth_id) REFERENCES alf_authority (id),
CONSTRAINT UNIQUE INDEX U_AUTH_TO_ALIAS (auth_id, alias_id)
UNIQUE (auth_id, alias_id)
) type=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
-- finish take out of ACL_ID
ALTER TABLE alf_access_control_entry DROP INDEX FKFFF41F99B9553F6C, DROP FOREIGN KEY FKFFF41F99B9553F6C;
ALTER TABLE alf_access_control_entry DROP INDEX FKFFF41F9960601995, DROP FOREIGN KEY FKFFF41F9960601995;
ALTER TABLE alf_access_control_entry DROP COLUMN acl_id, DROP COLUMN authority_id;
ALTER TABLE alf_access_control_entry
DROP FOREIGN KEY FKFFF41F99B9553F6C,
DROP COLUMN acl_id,
DROP COLUMN authority_id,
CHANGE auth_id authority_id BIGINT NOT NULL,
ADD INDEX FK_ACL_TO_AUTH (authority_id),
ADD CONSTRAINT FOREIGN KEY FK_ACL_TO_AUTH (authority_id) REFERENCES alf_authority (id);
CHANGE auth_id authority_id BIGINT NOT NULL;
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

View File

@@ -0,0 +1,83 @@
--
-- Title: Create missing 2.1 tables
-- Database: MySQL
-- 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.
--
create table avm_aspects (
id bigint not null auto_increment,
node_id bigint,
qname varchar(200),
primary key (id)
) type=InnoDB; -- (optional)
create table avm_aspects_new (
id bigint not null,
name varchar(200) not null,
primary key (id, name)
) type=InnoDB; -- (optional)
create table avm_node_properties (
id bigint not null auto_increment,
node_id bigint,
qname varchar(200),
actual_type varchar(15) not null,
multi_valued bit not null,
persisted_type varchar(15) not null,
boolean_value bit,
long_value bigint,
float_value float,
double_value double precision,
string_value text,
serializable_value blob,
primary key (id)
) type=InnoDB; -- (optional)
create table avm_node_properties_new (
node_id bigint not null,
actual_type varchar(15) not null,
multi_valued bit not null,
persisted_type varchar(15) not null,
boolean_value bit,
long_value bigint,
float_value float,
double_value double precision,
string_value text,
serializable_value blob,
qname varchar(200) not null,
primary key (node_id, qname)
) type=InnoDB; -- (optional)
create table avm_store_properties (
id bigint not null auto_increment,
avm_store_id bigint,
qname varchar(200),
actual_type varchar(15) not null,
multi_valued bit not null,
persisted_type varchar(15) not null,
boolean_value bit,
long_value bigint,
float_value float,
double_value double precision,
string_value text,
serializable_value blob,
primary key (id)
) type=InnoDB; -- (optional)
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-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',
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
);

View File

@@ -0,0 +1,149 @@
--
-- 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_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;
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;
ALTER TABLE alf_audit_date DROP INDEX adt_date_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_y_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_q_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_m_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_dow_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_doy_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_dom_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_hy_idx;
ALTER TABLE alf_audit_date DROP INDEX adt_wom_idx;
ALTER TABLE alf_audit_fact DROP INDEX adt_user_idx;
ALTER TABLE alf_audit_fact DROP INDEX adt_store_idx;
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;
ALTER TABLE alf_audit_source DROP INDEX app_source_ser_idx;
ALTER TABLE alf_audit_source DROP INDEX app_source_met_idx;
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;
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;
ALTER TABLE avm_child_entries DROP INDEX fk_avm_ce_parent, DROP FOREIGN KEY fk_avm_ce_parent;
ALTER TABLE avm_history_links DROP INDEX fk_avm_hl_desc, DROP FOREIGN KEY fk_avm_hl_desc;
ALTER TABLE avm_history_links DROP INDEX fk_avm_hl_ancestor, DROP FOREIGN KEY fk_avm_hl_ancestor;
ALTER TABLE avm_merge_links DROP INDEX fk_avm_ml_to, DROP FOREIGN KEY fk_avm_ml_to;
ALTER TABLE avm_merge_links DROP INDEX fk_avm_ml_from, DROP FOREIGN KEY fk_avm_ml_from;
ALTER TABLE avm_node_properties DROP INDEX idx_avm_np_name;
ALTER TABLE avm_node_properties DROP INDEX fk_avm_np_node, DROP FOREIGN KEY fk_avm_np_node;
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;
ALTER TABLE avm_nodes DROP INDEX fk_avm_n_store, DROP FOREIGN KEY fk_avm_n_store;
ALTER TABLE avm_store_properties DROP INDEX idx_avm_sp_name;
ALTER TABLE avm_store_properties DROP INDEX fk_avm_sp_store, DROP FOREIGN KEY fk_avm_sp_store;
ALTER TABLE avm_stores DROP INDEX fk_avm_s_root, DROP FOREIGN KEY fk_avm_s_root;
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;
ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_root, DROP FOREIGN KEY fk_avm_vr_root;
ALTER TABLE avm_version_roots DROP INDEX fk_avm_vr_store, DROP FOREIGN KEY fk_avm_vr_store;
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-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',
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
);

View File

@@ -0,0 +1,304 @@
--
-- 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 indexes and constraints
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
(
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 = 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
);
-- We can get 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 type_qname FROM alf_node
);
INSERT INTO t_qnames (qname)
(
SELECT qname FROM alf_node_aspects
);
INSERT INTO t_qnames (qname)
(
SELECT qname FROM alf_node_properties
);
INSERT INTO t_qnames (qname)
(
SELECT name FROM avm_aspects_new
);
INSERT INTO t_qnames (qname)
(
SELECT qname FROM avm_node_properties_new
);
INSERT INTO t_qnames (qname)
(
SELECT qname FROM avm_store_properties
);
INSERT INTO t_qnames (qname)
(
SELECT type_qname FROM alf_node_assoc
);
INSERT INTO t_qnames (qname)
(
SELECT type_qname FROM alf_child_assoc
);
-- Extract the namespace and localnames from the QNames
UPDATE t_qnames SET namespace = 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 get 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('{', ns.uri, '}', 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
--
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('{', ns.uri, '}', 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;
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('{', ns.uri, '}', 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('{', ns.uri, '}', 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('{', ns.uri, '}', 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('{', ns.uri, '}', 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 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('{', ns.uri, '}', 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;
--
-- 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) = ns.uri
);
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 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('{', ns.uri, '}', 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;
-- 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;
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-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',
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
);

View File

@@ -0,0 +1,102 @@
--
-- 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-QNames-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',
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
);

View File

@@ -0,0 +1,74 @@
--
-- Title: Create additional 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.
--
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 (halfYear);
CREATE INDEX idx_alf_adtd_y ON alf_audit_date (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);
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 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);
CREATE INDEX fk_alf_np_qn ON alf_node_properties (qname_id);
ALTER TABLE alf_node_properties ADD CONSTRAINT fk_alf_np_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (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);
--
-- Record script finish
--
DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-QNames-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',
0, 85, -1, 86, null, 'UNKOWN', 1, 1, 'Script completed'
);