diff --git a/config/alfresco/bootstrap-context.xml b/config/alfresco/bootstrap-context.xml index 78fe205c41..57c75d76c2 100644 --- a/config/alfresco/bootstrap-context.xml +++ b/config/alfresco/bootstrap-context.xml @@ -66,8 +66,7 @@ - - + diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/AlfrescoSchemaUpdate-2.2-ACL.sql b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/AlfrescoSchemaUpdate-2.2-ACL.sql new file mode 100644 index 0000000000..3fb0396565 --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/AlfrescoSchemaUpdate-2.2-ACL.sql @@ -0,0 +1,192 @@ +-- +-- Title: Update for permissions schema changes +-- Database: SQL Server +-- 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 numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + primary key (id) +); + +-- Add to ACL +ALTER TABLE alf_access_control_list ADD + type INT NOT NULL DEFAULT 0, + latest tinyint NOT NULL DEFAULT 1, + acl_id nvarchar(36) NOT NULL DEFAULT 'UNSET', + acl_version numeric(19,0) NOT NULL DEFAULT 1, + inherited_acl numeric(19,0) null, + is_versioned tinyint NOT NULL DEFAULT 0, + requires_version tinyint NOT NULL DEFAULT 0, + acl_change_set numeric(19,0) null, + inherits_from numeric(19,0) null, + CONSTRAINT fk_alf_acl_acs FOREIGN KEY (acl_change_set) REFERENCES alf_acl_change_set (id); +CREATE INDEX fk_alf_acl_acs ON alf_access_control_list (acl_change_set); +CREATE INDEX idx_alf_acl_inh ON alf_access_control_list (inherits, inherits_from); + +UPDATE alf_access_control_list + set acl_id = id; + +ALTER TABLE alf_access_control_list + ADD UNIQUE (acl_id, latest, acl_version); + +-- restructure authority +CREATE TABLE t_alf_authority ( + id numeric(19,0) identity not null, + version numeric(19,0) not null, + authority nvarchar(100) null, + crc numeric(19,0) null, + primary key (id), + UNIQUE (authority, crc) +); +CREATE INDEX idx_alf_auth_aut ON t_alf_authority (authority); +INSERT INTO t_alf_authority (version, authority) + SELECT version, recipient FROM alf_authority; + +-- Create ACE context +CREATE TABLE alf_ace_context ( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + class_context nvarchar(1024) null, + property_context nvarchar(1024) null, + kvp_context nvarchar(1024) null, + primary key (id) + ); + +-- Extend ACE +create table t_alf_access_control_entry +( + id numeric(19,0) identity not null, + version numeric(19,0) not null, + acl_id numeric(19,0) not null, + permission_id numeric(19,0) not null, + allowed tinyint not null, + authority_id numeric(19,0) NOT NULL DEFAULT -1, + applies INT NOT NULL DEFAULT 0, + context_id numeric(19,0) null + primary key (id) + CONSTRAINT fk_alf_ace_auth FOREIGN KEY (authority_id) REFERENCES t_alf_authority (id), + CONSTRAINT fk_alf_ace_perm FOREIGN KEY (permission_id) REFERENCES alf_permission (id), + CONSTRAINT fk_alf_ace_ctx FOREIGN KEY (context_id) REFERENCES alf_ace_context (id) +); +CREATE INDEX fk_alf_ace_auth ON t_alf_access_control_entry (authority_id); +CREATE INDEX fk_alf_ace_perm ON t_alf_access_control_entry (permission_id); +CREATE INDEX fk_alf_ace_ctx ON t_alf_access_control_entry (context_id); + +-- Create ACL member list +CREATE TABLE alf_acl_member ( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + acl_id numeric(19,0) NOT NULL, + ace_id numeric(19,0) NOT NULL, + pos INT NOT NULL, + CONSTRAINT fk_alf_aclm_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + CONSTRAINT fk_alf_aclm_ace FOREIGN KEY (ace_id) REFERENCES t_alf_access_control_entry (id), + primary key (id), + UNIQUE(acl_id, ace_id, pos) +); +CREATE INDEX fk_alf_aclm_acl ON alf_acl_member (acl_id); +CREATE INDEX fk_alf_aclm_ace ON alf_acl_member (ace_id); + +-- remove unused +DROP TABLE alf_auth_ext_keys; + +-- migrate data - fix up FK refs to authority +INSERT INTO t_alf_access_control_entry (version, acl_id, permission_id, allowed, authority_id) +SELECT ace.version, ace.acl_id, ace.permission_id, ace.allowed, a.id +FROM alf_access_control_entry ace, t_alf_authority a +WHERE a.authority = ace.authority_id; + +-- migrate data - build equivalent ACL entries +INSERT INTO alf_acl_member (version, acl_id, ace_id, pos) + select 1, ace.acl_id, ace.id, 0 from t_alf_access_control_entry ace join alf_access_control_list acl on acl.id = ace.acl_id; + +-- Create auth aliases table +CREATE TABLE alf_authority_alias ( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + auth_id numeric(19,0) NOT NULL, + alias_id numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_autha_ali FOREIGN KEY (alias_id) REFERENCES t_alf_authority (id), + CONSTRAINT fk_alf_autha_aut FOREIGN KEY (auth_id) REFERENCES t_alf_authority (id), + primary key (id), + UNIQUE (auth_id, alias_id) +) ; +CREATE INDEX fk_alf_autha_ali ON alf_authority_alias (alias_id); +CREATE INDEX fk_alf_autha_aut ON alf_authority_alias (auth_id); + +-- Tidy up unused cols on ace table +ALTER TABLE t_alf_access_control_entry DROP + COLUMN acl_id; + +DROP TABLE alf_access_control_entry; +EXEC sp_rename 't_alf_access_control_entry', 'alf_access_control_entry'; + +DROP TABLE alf_authority; +EXEC sp_rename 't_alf_authority', 'alf_authority'; + +CREATE TABLE alf_tmp_min_ace ( + min numeric(19,0) NOT NULL, + permission_id numeric(19,0) NOT NULL, + authority_id numeric(19,0) NOT NULL, + allowed tinyint NOT NULL, + applies INT NOT NULL, + UNIQUE (permission_id, authority_id, allowed, applies) +); + +INSERT INTO alf_tmp_min_ace (min, permission_id, authority_id, allowed, applies) + SELECT + min(ace1.id), + ace1.permission_id, + ace1.authority_id, + ace1.allowed, + ace1.applies + FROM + alf_access_control_entry ace1 + GROUP BY + ace1.permission_id, ace1.authority_id, ace1.allowed, ace1.applies +; + +-- Update members to point to the first use of an access control entry +UPDATE alf_acl_member + SET ace_id = (SELECT help.min FROM alf_access_control_entry ace + JOIN alf_tmp_min_ace help + ON help.permission_id = ace.permission_id AND + help.authority_id = ace.authority_id AND + help.allowed = ace.allowed AND + help.applies = ace.applies + WHERE ace.id = alf_acl_member.ace_id ); + +DROP TABLE alf_tmp_min_ace; + +-- Remove duplicate aces the mysql way (as you can not use the deleted table in the where clause ...) +CREATE TABLE tmp_to_delete ( + id numeric(19,0), + 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 WHERE 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, 119, -1, 120, null, 'UNKOWN', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-0-create-missing-tables.sql b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-0-create-missing-tables.sql new file mode 100644 index 0000000000..9882cb38fd --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-0-create-missing-tables.sql @@ -0,0 +1,94 @@ +-- +-- Title: Create missing 2.1 tables +-- Database: SQL Server +-- 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 + +EXEC sp_rename 'alf_audit_date.halfYear', 'half_year', 'COLUMN'; +EXEC sp_rename 'alf_audit_date.year', 'full_year', 'COLUMN'; + +-- create other new tables + + create table avm_aspects ( + id numeric(19,0) identity not null, + node_id numeric(19,0) null, + qname nvarchar(200) null, + primary key (id) + ); -- (optional) + + create table avm_aspects_new ( + id numeric(19,0) not null, + name nvarchar(200) not null, + primary key (id, name) + ); -- (optional) + + create table avm_node_properties ( + id numeric(19,0) identity not null, + node_id numeric(19,0) null, + qname nvarchar(200) null, + actual_type nvarchar(15) not null, + multi_valued tinyint not null, + persisted_type nvarchar(15) not null, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value float null, + double_value double precision null, + string_value text null, + serializable_value image null, + primary key (id) + ); -- (optional) + + create table avm_node_properties_new ( + node_id numeric(19,0) not null, + actual_type nvarchar(15) not null, + multi_valued tinyint not null, + persisted_type nvarchar(15) not null, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value float null, + double_value double precision null, + string_value text null, + serializable_value image null, + qname nvarchar(200) not null, + primary key (node_id, qname) + ); -- (optional) + + create table avm_store_properties ( + id numeric(19,0) identity not null, + avm_store_id numeric(19,0) null, + qname nvarchar(200) null, + actual_type nvarchar(15) not null, + multi_valued tinyint not null, + persisted_type nvarchar(15) not null, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value float null, + double_value double precision null, + string_value text null, + serializable_value image null, + primary key (id) + ); -- (optional) + +-- Add ACL column for AVM tables +ALTER TABLE avm_stores + ADD acl_id numeric(19,0) null; + +-- +-- Record script finish +-- +DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-0-CreateMissingTables'; +INSERT INTO alf_applied_patch + (id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report) + VALUES + ( + 'patch.db-V2.2-0-CreateMissingTables', 'Manually executed script upgrade V2.2: Created missing tables', + 0, 120, -1, 121, null, 'UNKOWN', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-from-2.1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-from-2.1.sql new file mode 100644 index 0000000000..7c53425fba --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-from-2.1.sql @@ -0,0 +1,1093 @@ +-- +-- Title: Apply schema modifications to upgrade from 2.1 +-- Database: MySQL +-- Since: V2.2 Schema 91 +-- Author: Derek Hulley +-- +-- In order to streamline the upgrade, all modifications to large tables need to +-- be handled in as few steps as possible. This usually involves as few ALTER TABLE +-- statements as possible. The general approach is: +-- Create a table with the correct structure, including indexes and CONSTRAINTs +-- Copy pristine data into the new table +-- Drop the old table +-- Rename the new table +-- +-- Please contact support@alfresco.com if you need assistance with the upgrade. +-- + +-- ------------------------------- +-- Build Namespaces and QNames -- +-- ------------------------------- + +CREATE TABLE alf_namespace +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + uri nvarchar(100) NOT NULL, + PRIMARY KEY (id), + UNIQUE (uri) +); + +CREATE TABLE alf_qname +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + ns_id numeric(19,0) NOT NULL, + local_name nvarchar(200) NOT NULL, + CONSTRAINT fk_alf_qname_ns FOREIGN KEY (ns_id) REFERENCES alf_namespace (id), + PRIMARY KEY (id), + UNIQUE (ns_id, local_name) +); +CREATE INDEX fk_alf_qname_ns ON alf_qname (ns_id); + +-- Create temporary table for dynamic (child) QNames +CREATE TABLE t_qnames_dyn +( + qname nvarchar(255) NOT NULL, + namespace nvarchar(100) null, + namespace_id numeric(19,0) null, + local_name nvarchar(200) null +); +CREATE INDEX tidx_qnd_ns ON t_qnames_dyn (namespace); +CREATE INDEX tidx_qnd_qn ON t_qnames_dyn (qname); + +-- Populate the table with the child association paths +INSERT INTO t_qnames_dyn (qname) +( + SELECT distinct(qname) FROM alf_child_assoc +); + +-- Extract the Namespace +UPDATE t_qnames_dyn SET namespace = 'FILLER-' + SUBSTRING(qname,2,CHARINDEX('}',qname,1)-2); +-- Extract the Localname +UPDATE t_qnames_dyn SET local_name = SUBSTRING(qname,LEN(qname)+2-CHARINDEX('}',REVERSE(qname),1),LEN(qname)); + +-- 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 +); + +-- Record the new namespace IDs +UPDATE t_qnames_dyn SET namespace_id = (SELECT ns.id FROM alf_namespace ns WHERE ns.uri = t_qnames_dyn.namespace); + +-- Recoup some storage +DROP INDEX t_qnames_dyn.tidx_qnd_ns; +ALTER TABLE t_qnames_dyn DROP COLUMN namespace; + +-- Create temporary table to hold static QNames +CREATE TABLE t_qnames +( + qname nvarchar(200) NOT NULL, + namespace nvarchar(100) null, + localname nvarchar(100) null, + qname_id numeric(19,0) null +); +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 s.type_qname FROM alf_node s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM alf_node_aspects s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM alf_node_properties s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_aspects s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.name FROM avm_aspects_new s LEFT OUTER JOIN t_qnames t ON (s.name = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_node_properties s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_node_properties_new s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_store_properties s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.type_qname FROM alf_node_assoc s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.type_qname FROM alf_child_assoc s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.type_qname FROM alf_permission s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); + +-- Extract the namespace and localnames from the QNames +UPDATE t_qnames SET namespace = 'FILLER-' + SUBSTRING(qname,2,CHARINDEX('}',qname,1)-2); +UPDATE t_qnames SET localname = SUBSTRING(qname,LEN(qname)+2-CHARINDEX('}',REVERSE(qname),1),LEN(qname)); + +-- 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 +); + +-- Record the new qname IDs +UPDATE t_qnames SET qname_id = +( + SELECT q.id FROM alf_qname q + JOIN alf_namespace ns ON (q.ns_id = ns.id) + WHERE ns.uri = t_qnames.namespace AND q.local_name = t_qnames.localname +); + +-- ---------------------------- +-- Populate the Permissions -- +-- ---------------------------- + +-- Rebuild the alf_permission table +CREATE TABLE t_alf_permission +( + id numeric(19,0) identity not null, + type_qname_id numeric(19,0) not null, + version numeric(19,0) not null, + name nvarchar(100) not null, + UNIQUE (type_qname_id, name), + CONSTRAINT fk_alf_perm_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (id), +); +CREATE INDEX fk_alf_perm_tqn ON t_alf_permission (type_qname_id); + +INSERT INTO t_alf_permission (type_qname_id, version, name) +( + SELECT q.id, p.version, p.name + FROM alf_qname q, alf_permission p, alf_namespace ns + WHERE '{' + SUBSTRING(ns.uri, 8, LEN(ns.uri)) + '}' + q.local_name = p.type_qname + AND q.ns_id = ns.id +); + +ALTER TABLE alf_access_control_entry DROP CONSTRAINT fk_alf_ace_perm; -- (optional) +DROP TABLE alf_permission; +EXEC sp_rename 't_alf_permission', 'alf_permission'; +ALTER TABLE alf_access_control_entry + ADD CONSTRAINT fk_alf_ace_perm FOREIGN KEY (permission_id) REFERENCES alf_permission; + +-- ------------------- +-- Build new Store -- +-- ------------------- + +CREATE TABLE t_alf_store +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + protocol nvarchar(50) NOT NULL, + identifier nvarchar(100) NOT NULL, + root_node_id numeric(19,0) null, + PRIMARY KEY (id), + UNIQUE (protocol, identifier) +); + +-- -------------------------- +-- Populate the ADM nodes -- +-- -------------------------- + +CREATE TABLE t_alf_node ( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + store_id numeric(19,0) NOT NULL, + uuid nvarchar(36) NOT NULL, + transaction_id numeric(19,0) NOT NULL, + node_deleted tinyint NOT NULL, + type_qname_id numeric(19,0) NOT NULL, + acl_id numeric(19,0) null, + audit_creator nvarchar(255) null, + audit_created nvarchar(30) null, + audit_modifier nvarchar(255) null, + audit_modified nvarchar(30) null, + audit_accessed nvarchar(30) null, + CONSTRAINT fk_alf_node_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + CONSTRAINT fk_alf_node_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id), + CONSTRAINT fk_alf_node_txn FOREIGN KEY (transaction_id) REFERENCES alf_transaction (id), + CONSTRAINT fk_alf_node_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id), + PRIMARY KEY (id), + UNIQUE (store_id, uuid) +); +CREATE INDEX idx_alf_node_del ON t_alf_node (node_deleted); +CREATE INDEX fk_alf_node_acl ON t_alf_node (acl_id); +CREATE INDEX fk_alf_node_tqn ON t_alf_node (type_qname_id); +CREATE INDEX fk_alf_node_txn ON t_alf_node (transaction_id); +CREATE INDEX fk_alf_node_store ON t_alf_node (store_id); + +-- Fill the store table +INSERT INTO t_alf_store (version, protocol, identifier, root_node_id) + SELECT 1, protocol, identifier, root_node_id FROM alf_store +; + +-- Add type_qname index for nodes +CREATE INDEX tidx_node_tqn ON alf_node (type_qname); + +-- Copy data over +SET IDENTITY_INSERT t_alf_node ON; +INSERT INTO t_alf_node + ( + id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, acl_id, + audit_creator, audit_created, audit_modifier, audit_modified + ) + SELECT + n.id, 1, s.id, n.uuid, nstat.transaction_id, 0, q.qname_id, n.acl_id, + null, null, null, null + FROM + alf_node n + JOIN t_qnames q ON (q.qname = n.type_qname) + JOIN alf_node_status nstat ON (nstat.node_id = n.id) + JOIN t_alf_store s ON (s.protocol = nstat.protocol AND s.identifier = nstat.identifier) +; +SET IDENTITY_INSERT t_alf_node OFF; + +-- Hook the store up to the root node +CREATE INDEX fk_alf_store_root ON t_alf_store (root_node_id); +ALTER TABLE t_alf_store + ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id) +; + +-- ----------------------------- +-- Populate Version Counter -- +-- ----------------------------- + +CREATE TABLE t_alf_version_count +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + store_id numeric(19,0) NOT NULL UNIQUE, + version_count int NOT NULL, + CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id), + PRIMARY KEY (id) +); + +INSERT INTO t_alf_version_count + ( + version, store_id, version_count + ) + SELECT + 1, s.id, vc.version_count + FROM + alf_version_count vc + JOIN t_alf_store s ON (s.protocol = vc.protocol AND s.identifier = vc.identifier) +; + +DROP TABLE alf_version_count; +EXEC sp_rename 't_alf_version_count', 'alf_version_count'; + +-- ----------------------------- +-- Populate the Child Assocs -- +-- ----------------------------- + +CREATE TABLE t_alf_child_assoc +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + parent_node_id numeric(19,0) NOT NULL, + type_qname_id numeric(19,0) NOT NULL, + child_node_name nvarchar(50) NOT NULL, + child_node_name_crc numeric(19,0) NOT NULL, + child_node_id numeric(19,0) NOT NULL, + qname_ns_id numeric(19,0) NOT NULL, + qname_localname nvarchar(100) NOT NULL, + is_primary tinyint null, + assoc_index int null, + CONSTRAINT fk_alf_cass_pnode foreign key (parent_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_cass_cnode foreign key (child_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_cass_tqn foreign key (type_qname_id) REFERENCES alf_qname (id), + CONSTRAINT fk_alf_cass_qnns foreign key (qname_ns_id) REFERENCES alf_namespace (id), + PRIMARY KEY (id), + UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc) +); +CREATE INDEX idx_alf_cass_qnln ON t_alf_child_assoc (qname_localname); +CREATE INDEX fk_alf_cass_pnode ON t_alf_child_assoc (parent_node_id); +CREATE INDEX fk_alf_cass_cnode ON t_alf_child_assoc (child_node_id); +CREATE INDEX fk_alf_cass_tqn ON t_alf_child_assoc (type_qname_id); +CREATE INDEX fk_alf_cass_qnns ON t_alf_child_assoc (qname_ns_id); + +SET IDENTITY_INSERT t_alf_child_assoc ON; +INSERT INTO t_alf_child_assoc + ( + id, version, + parent_node_id, child_node_id, + child_node_name, child_node_name_crc, + type_qname_id, + qname_ns_id, qname_localname, + is_primary, assoc_index + ) + SELECT + ca.id, 1, + ca.parent_node_id, ca.child_node_id, + ca.child_node_name, child_node_name_crc, + tqn.qname_id, + tqndyn.namespace_id, tqndyn.local_name, + ca.is_primary, ca.assoc_index + FROM + alf_child_assoc ca + JOIN t_qnames_dyn tqndyn ON (ca.qname = tqndyn.qname) + JOIN t_qnames tqn ON (ca.type_qname = tqn.qname) +; +SET IDENTITY_INSERT t_alf_child_assoc OFF; + +-- Clean up +DROP TABLE t_qnames_dyn; +DROP TABLE alf_child_assoc; +EXEC sp_rename 't_alf_child_assoc', 'alf_child_assoc'; + +-- ---------------------------- +-- Populate the Node Assocs -- +-- ---------------------------- + +CREATE TABLE t_alf_node_assoc +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + source_node_id numeric(19,0) NOT NULL, + target_node_id numeric(19,0) NOT NULL, + type_qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_nass_snode FOREIGN KEY (source_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nass_tnode FOREIGN KEY (target_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (id), + UNIQUE (source_node_id, target_node_id, type_qname_id) +); +CREATE INDEX fk_alf_nass_snode ON t_alf_node_assoc (source_node_id); +CREATE INDEX fk_alf_nass_tnode ON t_alf_node_assoc (target_node_id); +CREATE INDEX fk_alf_nass_tqn ON t_alf_node_assoc (type_qname_id); + +SET IDENTITY_INSERT t_alf_node_assoc ON; +INSERT INTO t_alf_node_assoc + ( + id, version, + source_node_id, target_node_id, + type_qname_id + ) + SELECT + na.id, 1, + na.source_node_id, na.source_node_id, + tqn.qname_id + FROM + alf_node_assoc na + JOIN t_qnames tqn ON (na.type_qname = tqn.qname) +; +SET IDENTITY_INSERT t_alf_node_assoc OFF; + +-- Clean up +DROP TABLE alf_node_assoc; +EXEC sp_rename 't_alf_node_assoc', 'alf_node_assoc'; + +-- ---------------------------- +-- Populate the Usage Deltas -- +-- ---------------------------- + +CREATE TABLE t_alf_usage_delta +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + node_id numeric(19,0) NOT NULL, + delta_size numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_usaged_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id), + PRIMARY KEY (id) +); +CREATE INDEX fk_alf_usaged_n ON t_alf_usage_delta (node_id); + +SET IDENTITY_INSERT t_alf_usage_delta ON; +INSERT INTO t_alf_usage_delta + ( + id, version, + node_id, + delta_size + ) + SELECT + ud.id, 1, + ud.node_id, + ud.delta_size + FROM + alf_usage_delta ud +; -- (optional) +SET IDENTITY_INSERT t_alf_usage_delta OFF; + +-- Clean up +DROP TABLE alf_usage_delta; -- (optional) +EXEC sp_rename 't_alf_usage_delta', 'alf_usage_delta'; + +-- ----------------------------- +-- Populate the Node Aspects -- +-- ----------------------------- + +CREATE TABLE t_alf_node_aspects +( + node_id numeric(19,0) NOT NULL, + qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_nasp_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_alf_nasp_n ON t_alf_node_aspects (node_id); +CREATE INDEX fk_alf_nasp_qn ON t_alf_node_aspects (qname_id); + +-- Note the omission of sys:referencable. This is implicit. +INSERT INTO t_alf_node_aspects + ( + node_id, qname_id + ) + SELECT + na.node_id, + tqn.qname_id + FROM + alf_node_aspects na + JOIN t_qnames tqn ON (na.qname = tqn.qname) + WHERE + tqn.qname NOT IN + ( + '{http://www.alfresco.org/model/system/1.0}referenceable' + ) +; + +-- Clean up +DROP TABLE alf_node_aspects; +EXEC sp_rename 't_alf_node_aspects', 'alf_node_aspects'; + +-- --------------------------------- +-- Populate the AVM Node Aspects -- +-- --------------------------------- + +CREATE TABLE t_avm_aspects +( + node_id numeric(19,0) NOT NULL, + qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_avm_nasp_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nasp_n ON t_avm_aspects (node_id); +CREATE INDEX fk_avm_nasp_qn ON t_avm_aspects (qname_id); + +INSERT INTO t_avm_aspects + ( + node_id, qname_id + ) + SELECT + aspects_old.node_id, + tqn.qname_id + FROM + avm_aspects aspects_old + JOIN t_qnames tqn ON (aspects_old.qname = tqn.qname) +; +INSERT INTO t_avm_aspects + ( + node_id, qname_id + ) + SELECT + anew.id, + tqn.qname_id + FROM + avm_aspects_new anew + JOIN t_qnames tqn ON (anew.name = tqn.qname) + LEFT JOIN avm_aspects aold ON (anew.id = aold.node_id AND anew.name = aold.qname) + WHERE + aold.id IS NULL +; + +-- Clean up +DROP TABLE avm_aspects; +DROP TABLE avm_aspects_new; +EXEC sp_rename 't_avm_aspects', 'avm_aspects'; + +-- ---------------------------------- +-- Migrate Sundry Property Tables -- +-- ---------------------------------- + +-- Create temporary mapping for property types +CREATE TABLE t_prop_types +( + type_name nvarchar(15) NOT NULL, + type_id int 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 avm_store_properties table +CREATE TABLE t_avm_store_properties +( + id numeric(19,0) identity not null, + avm_store_id numeric(19,0), + qname_id numeric(19,0) NOT NULL, + actual_type_n int NOT NULL, + persisted_type_n int NOT NULL, + multi_valued tinyint NOT NULL, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value float null, + double_value DOUBLE PRECISION null, + string_value nvarchar(1024) null, + serializable_value image null, + CONSTRAINT fk_avm_sprop_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id), + CONSTRAINT fk_avm_sprop_qname FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (id) +); +CREATE INDEX fk_avm_sprop_store ON t_avm_store_properties (avm_store_id); +CREATE INDEX fk_avm_sprop_qname ON t_avm_store_properties (qname_id); + +INSERT INTO t_avm_store_properties + ( + avm_store_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.avm_store_id, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value + FROM + avm_store_properties p + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) +; +DROP TABLE avm_store_properties; +EXEC sp_rename 't_avm_store_properties', 'avm_store_properties'; + +-- Modify the avm_node_properties_new table +CREATE TABLE t_avm_node_properties +( + node_id numeric(19,0) NOT NULL, + actual_type_n int NOT NULL, + persisted_type_n int NOT NULL, + multi_valued tinyint NOT NULL, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value FLOAT null, + double_value DOUBLE PRECISION null, + string_value nvarchar(1024) null, + serializable_value image null, + qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_avm_nprop_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nprop_n ON t_avm_node_properties (node_id); +CREATE INDEX fk_avm_nprop_qn ON t_avm_node_properties (qname_id); +INSERT INTO t_avm_node_properties + ( + node_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.node_id, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value + FROM + avm_node_properties_new p + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) +; +INSERT INTO t_avm_node_properties + ( + node_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.node_id, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value + FROM + avm_node_properties p + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) + LEFT OUTER JOIN t_avm_node_properties tanp ON (tqn.qname_id = tanp.qname_id) + WHERE + tanp.qname_id IS NULL +; + +DROP TABLE avm_node_properties_new; +DROP TABLE avm_node_properties; +EXEC sp_rename 't_avm_node_properties', 'avm_node_properties'; + + +-- ----------------- +-- Build Locales -- +-- ----------------- + +CREATE TABLE alf_locale +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL DEFAULT 1, + locale_str nvarchar(20) NOT NULL, + PRIMARY KEY (id), + UNIQUE (locale_str) +); + +SET IDENTITY_INSERT alf_locale ON; +INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default'); +SET IDENTITY_INSERT alf_locale OFF; + +-- Locales come from the attribute table which was used to support MLText persistence +INSERT INTO alf_locale (locale_str) + SELECT DISTINCT(ma.mkey) + FROM alf_node_properties np + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) +; + +-- ------------------------------- +-- Migrate ADM Property Tables -- +-- ------------------------------- + +CREATE TABLE t_alf_node_properties +( + node_id numeric(19,0) NOT NULL, + qname_id numeric(19,0) NOT NULL, + locale_id numeric(19,0) NOT NULL, + list_index int NOT NULL, + actual_type_n int NOT NULL, + persisted_type_n int NOT NULL, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value FLOAT null, + double_value DOUBLE PRECISION null, + string_value nvarchar(1024) null, + serializable_value image null, + CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id), + PRIMARY KEY (node_id, qname_id, list_index, locale_id) +); +CREATE INDEX fk_alf_nprop_n ON t_alf_node_properties (node_id); +CREATE INDEX fk_alf_nprop_qn ON t_alf_node_properties (qname_id); +CREATE INDEX fk_alf_nprop_loc ON t_alf_node_properties (locale_id); + +-- Copy values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, tqn.qname_id, -1, 1, + ptypes_actual.type_id, ptypes_persisted.type_id, + np.boolean_value, np.long_value, np.float_value, np.double_value, + np.string_value, + np.serializable_value + FROM + alf_node_properties np + JOIN t_qnames tqn ON (np.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = np.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = np.persisted_type) + WHERE + np.attribute_value IS NULL +; +-- Update cm:auditable properties on the nodes +UPDATE t_alf_node SET audit_creator = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'creator' +); +UPDATE t_alf_node SET audit_created = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'created' +); +UPDATE t_alf_node SET audit_modifier = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modifier' +); +UPDATE t_alf_node SET audit_modified = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modified' +); +-- Remove the unused cm:auditable properties +DELETE t_alf_node_properties + FROM t_alf_node_properties + JOIN alf_qname ON (t_alf_node_properties.qname_id = alf_qname.id) + JOIN alf_namespace ON (alf_qname.ns_id = alf_namespace.id) + WHERE + alf_namespace.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + alf_qname.local_name IN ('creator', 'created', 'modifier', 'modified') +; + +-- Copy all MLText values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, tqn.qname_id, -1, loc.id, + -1, 0, + 0, 0, 0, 0, + a2.string_value, + a2.serializable_value + FROM + alf_node_properties np + JOIN t_qnames tqn ON (np.qname = tqn.qname) + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) + JOIN alf_locale loc ON (ma.mkey = loc.locale_str) + JOIN alf_attributes a2 ON (ma.attribute_id = a2.id) +; -- (OPTIONAL) +UPDATE t_alf_node_properties + SET actual_type_n = 6, persisted_type_n = 6, serializable_value = NULL + WHERE actual_type_n = -1 AND string_value IS NOT NULL +; +UPDATE t_alf_node_properties + SET actual_type_n = 9, persisted_type_n = 9 + WHERE actual_type_n = -1 AND serializable_value IS NOT NULL +; + +-- Delete the node properties and move the fixed values over +DROP TABLE alf_node_properties; +EXEC sp_rename 't_alf_node_properties', 'alf_node_properties'; + +CREATE TABLE t_del_attributes +( + id numeric(19,0) NOT NULL, + PRIMARY KEY (id) +); +INSERT INTO t_del_attributes + SELECT id FROM alf_attributes WHERE type = 'M' +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_map_attribute_entries ma ON (ma.attribute_id = t_del_attributes.id) +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_list_attribute_entries la ON (la.attribute_id = t_del_attributes.id) +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_global_attributes ga ON (ga.attribute = t_del_attributes.id) +; +INSERT INTO t_del_attributes + SELECT a.id FROM t_del_attributes t + JOIN alf_map_attribute_entries ma ON (ma.map_id = t.id) + JOIN alf_attributes a ON (ma.attribute_id = a.id) +; +DELETE alf_map_attribute_entries + FROM alf_map_attribute_entries + JOIN t_del_attributes t ON (alf_map_attribute_entries.map_id = t.id) +; +DELETE alf_attributes + FROM alf_attributes + JOIN t_del_attributes t ON (alf_attributes.id = t.id) +; +DROP TABLE t_del_attributes; + +-- --------------------------------------------------- +-- Remove the FILLER- values from the namespace uri -- +-- --------------------------------------------------- +UPDATE alf_namespace SET uri = '.empty' WHERE uri = 'FILLER-'; +UPDATE alf_namespace SET uri = SUBSTRING(uri, 8, LEN(uri)) WHERE uri LIKE 'FILLER-%'; + +-- ------------------ +-- Final clean up -- +-- ------------------ +DROP TABLE t_qnames; +DROP TABLE t_prop_types; +DROP TABLE alf_node_status; +DROP INDEX alf_store.FKBD4FF53D22DBA5BA; -- (OPTIONAL) +ALTER TABLE alf_store DROP CONSTRAINT FKBD4FF53D22DBA5BA; -- (OPTIONAL) +ALTER TABLE alf_store DROP CONSTRAINT alf_store_root; -- (OPTIONAL) +DROP TABLE alf_node; +EXEC sp_rename 't_alf_node', 'alf_node'; +DROP TABLE alf_store; +EXEC sp_rename 't_alf_store', 'alf_store'; + + +-- ------------------------------------- +-- Modify index and constraint names -- +-- ------------------------------------- +DROP INDEX alf_attributes.fk_attributes_n_acl; -- (optional) +DROP INDEX alf_attributes.fk_attr_n_acl; -- (optional) +ALTER TABLE alf_attributes DROP CONSTRAINT fk_attributes_n_acl; -- (optional) +CREATE INDEX fk_alf_attr_acl ON alf_attributes (acl_id); + +DROP INDEX alf_audit_date.adt_woy_idx; -- (optional) +DROP INDEX alf_audit_date.adt_date_idx; -- (optional) +DROP INDEX alf_audit_date.adt_y_idx; -- (optional) +DROP INDEX alf_audit_date.adt_q_idx; -- (optional) +DROP INDEX alf_audit_date.adt_m_idx; -- (optional) +DROP INDEX alf_audit_date.adt_dow_idx; -- (optional) +DROP INDEX alf_audit_date.adt_doy_idx; -- (optional) +DROP INDEX alf_audit_date.adt_dom_idx; -- (optional) +DROP INDEX alf_audit_date.adt_hy_idx; -- (optional) +DROP INDEX alf_audit_date.adt_wom_idx; -- (optional) +CREATE INDEX idx_alf_adtd_woy ON alf_audit_date (week_of_year); +CREATE INDEX idx_alf_adtd_q ON alf_audit_date (quarter); +CREATE INDEX idx_alf_adtd_wom ON alf_audit_date (week_of_month); +CREATE INDEX idx_alf_adtd_dom ON alf_audit_date (day_of_month); +CREATE INDEX idx_alf_adtd_doy ON alf_audit_date (day_of_year); +CREATE INDEX idx_alf_adtd_dow ON alf_audit_date (day_of_week); +CREATE INDEX idx_alf_adtd_m ON alf_audit_date (month); +CREATE INDEX idx_alf_adtd_hy ON alf_audit_date (half_year); +CREATE INDEX idx_alf_adtd_fy ON alf_audit_date (full_year); +CREATE INDEX idx_alf_adtd_dat ON alf_audit_date (date_only); + +DROP INDEX alf_audit_fact.adt_user_idx; -- (optional) +DROP INDEX alf_audit_fact.adt_store_idx; -- (optional) +DROP INDEX alf_audit_fact.FKEAD18174A0F9B8D9; +DROP INDEX alf_audit_fact.FKEAD1817484342E39 +DROP INDEX alf_audit_fact.FKEAD18174F524CFD7 +ALTER TABLE alf_audit_fact DROP + CONSTRAINT FKEAD18174A0F9B8D9, + CONSTRAINT FKEAD1817484342E39, + CONSTRAINT FKEAD18174F524CFD7; + +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 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); +ALTER TABLE alf_audit_fact ADD + CONSTRAINT fk_alf_adtf_src FOREIGN KEY (audit_source_id) REFERENCES alf_audit_source (id), + CONSTRAINT fk_alf_adtf_date FOREIGN KEY (audit_date_id) REFERENCES alf_audit_date (id), + CONSTRAINT fk_alf_adtf_conf FOREIGN KEY (audit_conf_id) REFERENCES alf_audit_config (id) +; + +DROP INDEX alf_audit_source.app_source_app_idx; -- (optional) +DROP INDEX alf_audit_source.app_source_ser_idx; -- (optional) +DROP INDEX alf_audit_source.app_source_met_idx; -- (optional) +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); + +ALTER TABLE alf_global_attributes DROP CONSTRAINT FK64D0B9CF69B9F16A; -- (optional) +DROP INDEX alf_global_attributes.FK64D0B9CF69B9F16A; -- (optional) +-- 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) +ALTER TABLE alf_global_attributes + ADD CONSTRAINT fk_alf_gatt_att FOREIGN KEY (attribute) REFERENCES alf_attributes (id) +; + +DROP INDEX alf_list_attribute_entries.FKC7D52FB02C5AB86C; -- (optional) +DROP INDEX alf_list_attribute_entries.FKC7D52FB0ACD8822C; -- (optional) +ALTER TABLE alf_list_attribute_entries DROP CONSTRAINT FKC7D52FB02C5AB86C; -- (optional) +ALTER TABLE alf_list_attribute_entries DROP CONSTRAINT FKC7D52FB0ACD8822C; -- (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); +ALTER TABLE alf_list_attribute_entries ADD + CONSTRAINT fk_alf_lent_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id), + CONSTRAINT fk_alf_lent_latt FOREIGN KEY (list_id) REFERENCES alf_attributes (id) +; + +DROP INDEX alf_map_attribute_entries.FK335CAE26AEAC208C; -- (optional) +ALTER TABLE alf_map_attribute_entries DROP CONSTRAINT FK335CAE26AEAC208C; -- (optional) +DROP INDEX alf_map_attribute_entries.FK335CAE262C5AB86C; -- (optional) +ALTER TABLE alf_map_attribute_entries DROP CONSTRAINT FK335CAE262C5AB86C; -- (optional) +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); +ALTER TABLE alf_map_attribute_entries ADD + CONSTRAINT fk_alf_matt_matt FOREIGN KEY (map_id) REFERENCES alf_attributes (id), + CONSTRAINT fk_alf_matt_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id) +; + +DROP INDEX alf_transaction.idx_commit_time_ms; -- (optional) +DROP INDEX alf_transaction.FKB8761A3A9AE340B7; +ALTER TABLE alf_transaction DROP CONSTRAINT FKB8761A3A9AE340B7; +CREATE INDEX fk_alf_txn_svr ON alf_transaction (server_id); +ALTER TABLE alf_transaction ADD CONSTRAINT fk_alf_txn_svr FOREIGN KEY (server_id) REFERENCES alf_server (id); +CREATE INDEX idx_alf_txn_ctms ON alf_transaction (commit_time_ms); + +DROP INDEX avm_child_entries.fk_avm_ce_child; -- (optional) +ALTER TABLE avm_child_entries DROP CONSTRAINT fk_avm_ce_child; -- (optional) +DROP INDEX avm_child_entries.fk_avm_ce_parent; -- (optional) +ALTER TABLE avm_child_entries DROP CONSTRAINT fk_avm_ce_parent; -- (optional) +CREATE INDEX fk_avm_ce_child ON avm_child_entries (child_id); +CREATE INDEX fk_avm_ce_parent ON avm_child_entries (parent_id); +ALTER TABLE avm_child_entries ADD + CONSTRAINT fk_avm_ce_child FOREIGN KEY (child_id) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_ce_parent FOREIGN KEY (parent_id) REFERENCES avm_nodes (id) +; + +DROP INDEX avm_history_links.fk_avm_hl_desc; -- (optional) +ALTER TABLE avm_history_links DROP CONSTRAINT fk_avm_hl_desc; -- (optional) +DROP INDEX avm_history_links.fk_avm_hl_ancestor; -- (optional) +ALTER TABLE avm_history_links DROP CONSTRAINT fk_avm_hl_ancestor; -- (optional) +DROP INDEX avm_history_links.idx_avm_hl_revpk; -- (optional) +CREATE INDEX fk_avm_hl_desc ON avm_history_links (descendent); +CREATE INDEX fk_avm_hl_ancestor ON avm_history_links (ancestor); +CREATE INDEX idx_avm_hl_revpk ON avm_history_links (descendent, ancestor); +ALTER TABLE avm_history_links ADD + CONSTRAINT fk_avm_hl_desc FOREIGN KEY (descendent) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_hl_ancestor FOREIGN KEY (ancestor) REFERENCES avm_nodes (id) +; + +DROP INDEX avm_merge_links.fk_avm_ml_to; -- (optional) +ALTER TABLE avm_merge_links DROP CONSTRAINT fk_avm_ml_to; -- (optional) +DROP INDEX avm_merge_links.fk_avm_ml_from; -- (optional) +ALTER TABLE avm_merge_links DROP CONSTRAINT fk_avm_ml_from; -- (optional) +CREATE INDEX fk_avm_ml_to ON avm_merge_links (mto); +CREATE INDEX fk_avm_ml_from ON avm_merge_links (mfrom); +ALTER TABLE avm_merge_links ADD + CONSTRAINT fk_avm_ml_to FOREIGN KEY (mto) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_ml_from FOREIGN KEY (mfrom) REFERENCES avm_nodes (id) +; + +DROP INDEX avm_nodes.fk_avm_n_acl; -- (optional) +ALTER TABLE avm_nodes DROP CONSTRAINT fk_avm_n_acl; -- (optional) +DROP INDEX avm_nodes.fk_avm_n_store; -- (optional) +ALTER TABLE avm_nodes DROP CONSTRAINT fk_avm_n_store; -- (optional) +DROP INDEX avm_nodes.idx_avm_n_pi; -- (optional) +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 idx_avm_n_pi ON avm_nodes (primary_indirection); +ALTER TABLE avm_nodes ADD + CONSTRAINT fk_avm_n_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + CONSTRAINT fk_avm_n_store FOREIGN KEY (store_new_id) REFERENCES avm_stores (id) +; + +DROP INDEX avm_stores.fk_avm_s_root; -- (optional) +ALTER TABLE avm_stores DROP CONSTRAINT fk_avm_s_root; -- (optional) +CREATE INDEX fk_avm_s_acl ON avm_stores (acl_id); +CREATE INDEX fk_avm_s_root ON avm_stores (current_root_id); +ALTER TABLE avm_stores ADD + CONSTRAINT fk_avm_s_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + CONSTRAINT fk_avm_s_root FOREIGN KEY (current_root_id) REFERENCES avm_nodes (id) +; + +DROP INDEX avm_version_layered_node_entry.FK182E672DEB9D70C; -- (optional) +ALTER TABLE avm_version_layered_node_entry DROP CONSTRAINT FK182E672DEB9D70C; -- (optional) +CREATE INDEX fk_avm_vlne_vr ON avm_version_layered_node_entry (version_root_id); +ALTER TABLE avm_version_layered_node_entry + ADD CONSTRAINT fk_avm_vlne_vr FOREIGN KEY (version_root_id) REFERENCES avm_version_roots (id) +; + +DROP INDEX avm_version_roots.idx_avm_vr_version; -- (optional) +DROP INDEX avm_version_roots.idx_avm_vr_revuq; -- (optional) +DROP INDEX avm_version_roots.fk_avm_vr_root; -- (optional) +ALTER TABLE avm_version_roots DROP CONSTRAINT fk_avm_vr_root; -- (optional) +DROP INDEX avm_version_roots.fk_avm_vr_store; -- (optional) +ALTER TABLE avm_version_roots DROP CONSTRAINT fk_avm_vr_store; -- (optional) +CREATE INDEX idx_avm_vr_version ON avm_version_roots (version_id); +CREATE INDEX idx_avm_vr_revuq ON avm_version_roots (avm_store_id, version_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); +ALTER TABLE avm_version_roots ADD + CONSTRAINT fk_avm_vr_root FOREIGN KEY (root_id) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_vr_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id) +; + +-- +-- Record script finish +-- +DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Upgrade-From-2.1'; +INSERT INTO alf_applied_patch + (id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report) + VALUES + ( + 'patch.db-V2.2-Upgrade-From-2.1', 'Manually executed script upgrade V2.2: Upgrade from 2.1', + 0, 85, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-from-2.2SP1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-from-2.2SP1.sql new file mode 100644 index 0000000000..95bcc7cc8c --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.alfresco.repo.domain.hibernate.dialect.AlfrescoSQLServerDialect/upgrade-from-2.2SP1.sql @@ -0,0 +1,686 @@ +-- +-- Title: Upgrade V2.2 SP1 or SP2 +-- Database: MySQL +-- Since: V2.2 Schema 91 +-- Author: Derek Hulley +-- +-- MLText values must be pulled back from attributes into localizable properties. +-- NodeStatus has been moved to alf_node. +-- Auditable properties have been moved to alf_node. +-- alf_node contains the old alf_node_status information. +-- +-- Please contact support@alfresco.com if you need assistance with the upgrade. +-- + +-- ------------------- +-- Build new Store -- +-- ------------------- + +CREATE TABLE t_alf_store +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + protocol nvarchar(50) NOT NULL, + identifier nvarchar(100) NOT NULL, + root_node_id numeric(19,0) null, + PRIMARY KEY (id), + UNIQUE (protocol, identifier) +); + +-- -------------------------- +-- Populate the ADM nodes -- +-- -------------------------- + +CREATE TABLE t_alf_node ( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + store_id numeric(19,0) NOT NULL, + uuid nvarchar(36) NOT NULL, + transaction_id numeric(19,0) NOT NULL, + node_deleted tinyint NOT NULL, + type_qname_id numeric(19,0) NOT NULL, + acl_id numeric(19,0) null, + audit_creator nvarchar(255) null, + audit_created nvarchar(30) null, + audit_modifier nvarchar(255) null, + audit_modified nvarchar(30) null, + audit_accessed nvarchar(30) null, + CONSTRAINT fk_alf_node_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id), + CONSTRAINT fk_alf_node_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id), + CONSTRAINT fk_alf_node_txn FOREIGN KEY (transaction_id) REFERENCES alf_transaction (id), + CONSTRAINT fk_alf_node_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id), + PRIMARY KEY (id), + UNIQUE (store_id, uuid) +); +CREATE INDEX idx_alf_node_del ON t_alf_node (node_deleted); +CREATE INDEX fk_alf_node_acl ON t_alf_node (acl_id); +CREATE INDEX fk_alf_node_tqn ON t_alf_node (type_qname_id); +CREATE INDEX fk_alf_node_txn ON t_alf_node (transaction_id); +CREATE INDEX fk_alf_node_store ON t_alf_node (store_id); + +-- Fill the store table +INSERT INTO t_alf_store (version, protocol, identifier, root_node_id) + SELECT 1, protocol, identifier, root_node_id FROM alf_store +; + +-- Copy data over +SET IDENTITY_INSERT t_alf_node ON; +INSERT INTO t_alf_node + ( + id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, acl_id, + audit_creator, audit_created, audit_modifier, audit_modified + ) + SELECT + n.id, 1, s.id, n.uuid, nstat.transaction_id, 0, n.type_qname_id, n.acl_id, + null, null, null, null + FROM + alf_node n + JOIN alf_node_status nstat ON (nstat.node_id = n.id) + JOIN t_alf_store s ON (s.protocol = nstat.protocol AND s.identifier = nstat.identifier) +; +SET IDENTITY_INSERT t_alf_node OFF; + +-- Hook the store up to the root node +CREATE INDEX fk_alf_store_root ON t_alf_store (root_node_id); +ALTER TABLE t_alf_store + ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id) +; + +-- ----------------------------- +-- Populate Version Counter -- +-- ----------------------------- + +CREATE TABLE t_alf_version_count +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + store_id numeric(19,0) NOT NULL UNIQUE, + version_count int NOT NULL, + CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id), + PRIMARY KEY (id) +); + +INSERT INTO t_alf_version_count + ( + version, store_id, version_count + ) + SELECT + 1, s.id, vc.version_count + FROM + alf_version_count vc + JOIN t_alf_store s ON (s.protocol = vc.protocol AND s.identifier = vc.identifier) +; + +DROP TABLE alf_version_count; +EXEC sp_rename 't_alf_version_count', 'alf_version_count'; + +-- ----------------------------- +-- Populate the Child Assocs -- +-- ----------------------------- + +CREATE TABLE t_alf_child_assoc +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + parent_node_id numeric(19,0) NOT NULL, + type_qname_id numeric(19,0) NOT NULL, + child_node_name nvarchar(50) NOT NULL, + child_node_name_crc numeric(19,0) NOT NULL, + child_node_id numeric(19,0) NOT NULL, + qname_ns_id numeric(19,0) NOT NULL, + qname_localname nvarchar(100) NOT NULL, + is_primary tinyint null, + assoc_index int null, + CONSTRAINT fk_alf_cass_pnode foreign key (parent_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_cass_cnode foreign key (child_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_cass_tqn foreign key (type_qname_id) REFERENCES alf_qname (id), + CONSTRAINT fk_alf_cass_qnns foreign key (qname_ns_id) REFERENCES alf_namespace (id), + PRIMARY KEY (id), + UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc) +); +CREATE INDEX idx_alf_cass_qnln ON t_alf_child_assoc (qname_localname); +CREATE INDEX fk_alf_cass_pnode ON t_alf_child_assoc (parent_node_id); +CREATE INDEX fk_alf_cass_cnode ON t_alf_child_assoc (child_node_id); +CREATE INDEX fk_alf_cass_tqn ON t_alf_child_assoc (type_qname_id); +CREATE INDEX fk_alf_cass_qnns ON t_alf_child_assoc (qname_ns_id); + +SET IDENTITY_INSERT t_alf_child_assoc ON; +INSERT INTO t_alf_child_assoc + ( + id, version, + parent_node_id, child_node_id, + child_node_name, child_node_name_crc, + type_qname_id, + qname_ns_id, qname_localname, + is_primary, assoc_index + ) + SELECT + ca.id, 1, + ca.parent_node_id, ca.child_node_id, + ca.child_node_name, child_node_name_crc, + ca.type_qname_id, + ca.qname_ns_id, ca.qname_localname, + ca.is_primary, ca.assoc_index + FROM + alf_child_assoc ca +; +SET IDENTITY_INSERT t_alf_child_assoc OFF; + +-- Clean up +DROP TABLE alf_child_assoc; +EXEC sp_rename 't_alf_child_assoc', 'alf_child_assoc'; + +-- ---------------------------- +-- Populate the Node Assocs -- +-- ---------------------------- + +CREATE TABLE t_alf_node_assoc +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + source_node_id numeric(19,0) NOT NULL, + target_node_id numeric(19,0) NOT NULL, + type_qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_nass_snode FOREIGN KEY (source_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nass_tnode FOREIGN KEY (target_node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (id), + UNIQUE (source_node_id, target_node_id, type_qname_id) +); +CREATE INDEX fk_alf_nass_snode ON t_alf_node_assoc (source_node_id); +CREATE INDEX fk_alf_nass_tnode ON t_alf_node_assoc (target_node_id); +CREATE INDEX fk_alf_nass_tqn ON t_alf_node_assoc (type_qname_id); + +SET IDENTITY_INSERT t_alf_node_assoc ON; +INSERT INTO t_alf_node_assoc + ( + id, version, + source_node_id, target_node_id, + type_qname_id + ) + SELECT + na.id, 1, + na.source_node_id, na.source_node_id, + na.type_qname_id + FROM + alf_node_assoc na +; +SET IDENTITY_INSERT t_alf_node_assoc OFF; + +-- Clean up +DROP TABLE alf_node_assoc; +EXEC sp_rename 't_alf_node_assoc', 'alf_node_assoc'; + +-- ---------------------------- +-- Populate the Usage Deltas -- +-- ---------------------------- + +CREATE TABLE t_alf_usage_delta +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL, + node_id numeric(19,0) NOT NULL, + delta_size numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_usaged_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id), + PRIMARY KEY (id) +); +CREATE INDEX fk_alf_usaged_n ON t_alf_usage_delta (node_id); + +SET IDENTITY_INSERT t_alf_usage_delta ON; +INSERT INTO t_alf_usage_delta + ( + id, version, + node_id, + delta_size + ) + SELECT + ud.id, 1, + ud.node_id, + ud.delta_size + FROM + alf_usage_delta ud +; -- (optional) +SET IDENTITY_INSERT t_alf_usage_delta OFF; + +-- Clean up +DROP TABLE alf_usage_delta; -- (optional) +EXEC sp_rename 't_alf_usage_delta', 'alf_usage_delta'; + +-- ----------------------------- +-- Populate the Node Aspects -- +-- ----------------------------- + +CREATE TABLE t_alf_node_aspects +( + node_id numeric(19,0) NOT NULL, + qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_alf_nasp_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_alf_nasp_n ON t_alf_node_aspects (node_id); +CREATE INDEX fk_alf_nasp_qn ON t_alf_node_aspects (qname_id); + +-- Note the omission of sys:referencable. This is implicit. +INSERT INTO t_alf_node_aspects + ( + node_id, qname_id + ) + SELECT + na.node_id, + qname_id + FROM + alf_node_aspects na + JOIN alf_qname qn ON (na.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + ns.uri != 'http://www.alfresco.org/model/system/1.0' OR + qn.local_name != 'referenceable' +; + +-- Clean up +DROP TABLE alf_node_aspects; +EXEC sp_rename 't_alf_node_aspects', 'alf_node_aspects'; + +-- --------------------------------- +-- Populate the AVM Node Aspects -- +-- --------------------------------- + +CREATE TABLE t_avm_aspects +( + node_id numeric(19,0) NOT NULL, + qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_avm_nasp_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nasp_n ON t_avm_aspects (node_id); +CREATE INDEX fk_avm_nasp_qn ON t_avm_aspects (qname_id); + +INSERT INTO t_avm_aspects + ( + node_id, qname_id + ) + SELECT + anew.id, + anew.qname_id + FROM + avm_aspects_new anew +; + +-- Clean up +DROP TABLE avm_aspects; +DROP TABLE avm_aspects_new; +EXEC sp_rename 't_avm_aspects', 'avm_aspects'; + +-- ---------------------------------- +-- Migrate Sundry Property Tables -- +-- ---------------------------------- + +-- Modify the avm_store_properties table +CREATE TABLE t_avm_store_properties +( + id numeric(19,0) identity not null, + avm_store_id numeric(19,0), + qname_id numeric(19,0) NOT NULL, + actual_type_n int NOT NULL, + persisted_type_n int NOT NULL, + multi_valued tinyint NOT NULL, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value float null, + double_value DOUBLE PRECISION null, + string_value nvarchar(1024) null, + serializable_value image null, + CONSTRAINT fk_avm_sprop_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id), + CONSTRAINT fk_avm_sprop_qname FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (id) +); +CREATE INDEX fk_avm_sprop_store ON t_avm_store_properties (avm_store_id); +CREATE INDEX fk_avm_sprop_qname ON t_avm_store_properties (qname_id); + +INSERT INTO t_avm_store_properties + ( + avm_store_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.avm_store_id, + p.qname_id, + p.actual_type_n, p.persisted_type_n, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value + FROM + avm_store_properties p +; +DROP TABLE avm_store_properties; +EXEC sp_rename 't_avm_store_properties', 'avm_store_properties'; + +-- Modify the avm_node_properties_new table +CREATE TABLE t_avm_node_properties +( + node_id numeric(19,0) NOT NULL, + actual_type_n int NOT NULL, + persisted_type_n int NOT NULL, + multi_valued tinyint NOT NULL, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value FLOAT null, + double_value DOUBLE PRECISION null, + string_value nvarchar(1024) null, + serializable_value image null, + qname_id numeric(19,0) NOT NULL, + CONSTRAINT fk_avm_nprop_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id), + CONSTRAINT fk_avm_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nprop_n ON t_avm_node_properties (node_id); +CREATE INDEX fk_avm_nprop_qn ON t_avm_node_properties (qname_id); +INSERT INTO t_avm_node_properties + ( + node_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.node_id, + p.qname_id, + p.actual_type_n, p.persisted_type_n, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, p.serializable_value + FROM + avm_node_properties_new p +; + +DROP TABLE avm_node_properties_new; +DROP TABLE avm_node_properties; +EXEC sp_rename 't_avm_node_properties', 'avm_node_properties'; + + +-- ----------------- +-- Build Locales -- +-- ----------------- + +CREATE TABLE alf_locale +( + id numeric(19,0) identity not null, + version numeric(19,0) NOT NULL DEFAULT 1, + locale_str nvarchar(20) NOT NULL, + PRIMARY KEY (id), + UNIQUE (locale_str) +); + +SET IDENTITY_INSERT alf_locale ON; +INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default'); +SET IDENTITY_INSERT alf_locale OFF; + +-- Locales come from the attribute table which was used to support MLText persistence +INSERT INTO alf_locale (locale_str) + SELECT DISTINCT(ma.mkey) + FROM alf_node_properties np + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) +; + +-- ------------------------------- +-- Migrate ADM Property Tables -- +-- ------------------------------- + +CREATE TABLE t_alf_node_properties +( + node_id numeric(19,0) NOT NULL, + qname_id numeric(19,0) NOT NULL, + locale_id numeric(19,0) NOT NULL, + list_index int NOT NULL, + actual_type_n int NOT NULL, + persisted_type_n int NOT NULL, + boolean_value tinyint null, + long_value numeric(19,0) null, + float_value FLOAT null, + double_value DOUBLE PRECISION null, + string_value nvarchar(1024) null, + serializable_value image null, + CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id), + CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id), + CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id), + PRIMARY KEY (node_id, qname_id, list_index, locale_id) +); +CREATE INDEX fk_alf_nprop_n ON t_alf_node_properties (node_id); +CREATE INDEX fk_alf_nprop_qn ON t_alf_node_properties (qname_id); +CREATE INDEX fk_alf_nprop_loc ON t_alf_node_properties (locale_id); + +-- Copy values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, np.qname_id, -1, 1, + np.actual_type_n, np.persisted_type_n, + np.boolean_value, np.long_value, np.float_value, np.double_value, + np.string_value, + np.serializable_value + FROM + alf_node_properties np + WHERE + np.attribute_value IS NULL +; +-- Update cm:auditable properties on the nodes +UPDATE t_alf_node SET audit_creator = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'creator' +); +UPDATE t_alf_node SET audit_created = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'created' +); +UPDATE t_alf_node SET audit_modifier = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modifier' +); +UPDATE t_alf_node SET audit_modified = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = t_alf_node.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modified' +); +-- Remove the unused cm:auditable properties +DELETE t_alf_node_properties + FROM t_alf_node_properties + JOIN alf_qname ON (t_alf_node_properties.qname_id = alf_qname.id) + JOIN alf_namespace ON (alf_qname.ns_id = alf_namespace.id) + WHERE + alf_namespace.uri = 'http://www.alfresco.org/model/content/1.0' AND + alf_qname.local_name IN ('creator', 'created', 'modifier', 'modified') +; + +-- Copy all MLText values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, np.qname_id, -1, loc.id, + -1, 0, + 0, 0, 0, 0, + a2.string_value, + a2.serializable_value + FROM + alf_node_properties np + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) + JOIN alf_locale loc ON (ma.mkey = loc.locale_str) + JOIN alf_attributes a2 ON (ma.attribute_id = a2.id) +; -- (OPTIONAL) +UPDATE t_alf_node_properties + SET actual_type_n = 6, persisted_type_n = 6, serializable_value = NULL + WHERE actual_type_n = -1 AND string_value IS NOT NULL +; +UPDATE t_alf_node_properties + SET actual_type_n = 9, persisted_type_n = 9 + WHERE actual_type_n = -1 AND serializable_value IS NOT NULL +; + +-- Delete the node properties and move the fixed values over +DROP TABLE alf_node_properties; +EXEC sp_rename 't_alf_node_properties', 'alf_node_properties'; + +CREATE TABLE t_del_attributes +( + id numeric(19,0) NOT NULL, + PRIMARY KEY (id) +); +INSERT INTO t_del_attributes + SELECT id FROM alf_attributes WHERE type = 'M' +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_map_attribute_entries ma ON (ma.attribute_id = t_del_attributes.id) +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_list_attribute_entries la ON (la.attribute_id = t_del_attributes.id) +; +DELETE t_del_attributes + FROM t_del_attributes + JOIN alf_global_attributes ga ON (ga.attribute = t_del_attributes.id) +; +INSERT INTO t_del_attributes + SELECT a.id FROM t_del_attributes t + JOIN alf_map_attribute_entries ma ON (ma.map_id = t.id) + JOIN alf_attributes a ON (ma.attribute_id = a.id) +; +DELETE alf_map_attribute_entries + FROM alf_map_attribute_entries + JOIN t_del_attributes t ON (alf_map_attribute_entries.map_id = t.id) +; +DELETE alf_attributes + FROM alf_attributes + JOIN t_del_attributes t ON (alf_attributes.id = t.id) +; +DROP TABLE t_del_attributes; + +-- ------------------ +-- Final clean up -- +-- ------------------ +DROP TABLE alf_node_status; +ALTER TABLE alf_store DROP CONSTRAINT fk_alf_store_rn; +DROP TABLE alf_node; +EXEC sp_rename 't_alf_node', 'alf_node'; +DROP TABLE alf_store; +EXEC sp_rename 't_alf_store', 'alf_store'; + +-- ---------------- +-- JBPM Differences +-- ---------------- + +-- We need to remove a unique index and unfortunately we don't know its name so let's just rebuild the table! +create table T_JBPM_PROCESSINSTANCE ( + ID_ numeric(19,0) identity not null, + VERSION_ int not null, + KEY_ nvarchar(255) null, + START_ datetime null, + END_ datetime null, + ISSUSPENDED_ tinyint null, + PROCESSDEFINITION_ numeric(19,0) null, + ROOTTOKEN_ numeric(19,0) null, + SUPERPROCESSTOKEN_ numeric(19,0) null, + primary key (ID_), +); +SET IDENTITY_INSERT T_JBPM_PROCESSINSTANCE ON; +INSERT INTO T_JBPM_PROCESSINSTANCE (ID_, VERSION_, KEY_, START_, END_, ISSUSPENDED_, PROCESSDEFINITION_, ROOTTOKEN_, SUPERPROCESSTOKEN_) + SELECT ID_, VERSION_, KEY_, START_, END_, ISSUSPENDED_, PROCESSDEFINITION_, ROOTTOKEN_, SUPERPROCESSTOKEN_ + FROM JBPM_PROCESSINSTANCE +; +SET IDENTITY_INSERT T_JBPM_PROCESSINSTANCE OFF; + +alter table JBPM_JOB drop constraint FK_JOB_PRINST; +alter table JBPM_JOB + add constraint FK_JOB_PRINST foreign key (PROCESSINSTANCE_) references T_JBPM_PROCESSINSTANCE +; +alter table JBPM_MODULEINSTANCE drop constraint FK_MODINST_PRCINST; +alter table JBPM_MODULEINSTANCE + add constraint FK_MODINST_PRCINST foreign key (PROCESSINSTANCE_) references T_JBPM_PROCESSINSTANCE +; +alter table JBPM_RUNTIMEACTION drop constraint FK_RTACTN_PROCINST; +alter table JBPM_RUNTIMEACTION + add constraint FK_RTACTN_PROCINST foreign key (PROCESSINSTANCE_) references T_JBPM_PROCESSINSTANCE; +alter table JBPM_TASKINSTANCE drop constraint FK_TSKINS_PRCINS; +alter table JBPM_TASKINSTANCE + add constraint FK_TSKINS_PRCINS foreign key (PROCINST_) references T_JBPM_PROCESSINSTANCE; +alter table JBPM_TOKEN drop constraint FK_TOKEN_PROCINST; +alter table JBPM_TOKEN + add constraint FK_TOKEN_PROCINST foreign key (PROCESSINSTANCE_) references T_JBPM_PROCESSINSTANCE; +alter table JBPM_VARIABLEINSTANCE drop constraint FK_VARINST_PRCINST; +alter table JBPM_VARIABLEINSTANCE + add constraint FK_VARINST_PRCINST foreign key (PROCESSINSTANCE_) references T_JBPM_PROCESSINSTANCE; +alter table JBPM_TOKEN drop constraint FK_TOKEN_SUBPI; +alter table JBPM_TOKEN + add constraint FK_TOKEN_SUBPI foreign key (SUBPROCESSINSTANCE_) references T_JBPM_PROCESSINSTANCE; + +DROP TABLE JBPM_PROCESSINSTANCE; +EXEC sp_rename 'T_JBPM_PROCESSINSTANCE', 'JBPM_PROCESSINSTANCE'; + +ALTER TABLE JBPM_PROCESSINSTANCE ADD + constraint FK_PROCIN_PROCDEF foreign key (PROCESSDEFINITION_) references JBPM_PROCESSDEFINITION, + constraint FK_PROCIN_ROOTTKN foreign key (ROOTTOKEN_) references JBPM_TOKEN, + constraint FK_PROCIN_SPROCTKN foreign key (SUPERPROCESSTOKEN_) references JBPM_TOKEN; +create index IDX_PROCIN_ROOTTK on JBPM_PROCESSINSTANCE (ROOTTOKEN_); +create index IDX_PROCIN_SPROCTK on JBPM_PROCESSINSTANCE (SUPERPROCESSTOKEN_); +create index IDX_PROCIN_KEY on JBPM_PROCESSINSTANCE (KEY_); +create index IDX_PROCIN_PROCDEF on JBPM_PROCESSINSTANCE (PROCESSDEFINITION_); + +-- +-- Record script finish +-- +DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Upgrade-From-2.2SP1'; +INSERT INTO alf_applied_patch + (id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report) + VALUES + ( + 'patch.db-V2.2-Upgrade-From-2.2SP1', 'Manually executed script upgrade V2.2: Upgraded V2.2 SP1 or SP2', + 86, 90, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-OrclBLOB.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-OrclBLOB.sql deleted file mode 100644 index 0e0ef4983a..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-OrclBLOB.sql +++ /dev/null @@ -1,21 +0,0 @@ --- --- Title: Change Oracle LONG RAW columns to BLOB --- Database: Generic --- Since: V2.2 Schema 92 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. --- --- No effect on non-Oracle DBs - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-OrclBLOB'; -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-OrclBLOB', 'Did nothing for non-Oracle DB.', - 0, 91, -1, 92, null, 'UNKOWN', 1, 1, 'Script completed' - ); \ No newline at end of file diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-Person.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-Person.sql index ee3adbd85f..15494ee959 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-Person.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Dialect/AlfrescoSchemaUpdate-Person.sql @@ -9,9 +9,9 @@ -- Path was previously unused and unindex - new we use it the index is required. UPDATE - alf_child_assoc c + alf_child_assoc SET - c.qname_ns_id = + qname_ns_id = ( SELECT id @@ -19,7 +19,7 @@ UPDATE alf_namespace n WHERE n.uri = 'http://www.alfresco.org/model/content/1.0'), - c.qname_localname = + qname_localname = ( SELECT p.string_value @@ -28,7 +28,7 @@ UPDATE JOIN alf_qname q on p.qname_id = q.id JOIN alf_namespace n on q.ns_id = n.id WHERE - p.node_id = c.child_node_id AND + p.node_id = alf_child_assoc.child_node_id AND q.local_name ='userName' AND n.uri = 'http://www.alfresco.org/model/content/1.0' ) WHERE exists @@ -39,7 +39,7 @@ UPDATE JOIN alf_qname qq on pp.qname_id = qq.id JOIN alf_namespace nn on qq.ns_id = nn.id WHERE - pp.node_id = c.child_node_id AND + pp.node_id = alf_child_assoc.child_node_id AND qq.local_name ='userName' AND nn.uri = 'http://www.alfresco.org/model/content/1.0' ) diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql index f255056fda..2a8742f046 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.1.sql @@ -902,6 +902,7 @@ ALTER TABLE t_alf_store RENAME TO alf_store; -- Modify index and constraint names -- -- ------------------------------------- ALTER TABLE alf_attributes DROP INDEX fk_attributes_n_acl, DROP FOREIGN KEY fk_attributes_n_acl; -- (optional) +ALTER TABLE alf_attributes DROP INDEX fk_attr_n_acl; -- (optional) ALTER TABLE alf_attributes ADD INDEX fk_alf_attr_acl (acl_id) ; diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql index a2870a876b..b4cfbb5bd7 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.MySQLInnoDBDialect/upgrade-from-2.2SP1.sql @@ -422,7 +422,7 @@ CREATE TABLE t_alf_node_properties node_id BIGINT NOT NULL, qname_id BIGINT NOT NULL, locale_id BIGINT NOT NULL, - list_index smallint NOT NULL, + list_index INTEGER NOT NULL, actual_type_n INTEGER NOT NULL, persisted_type_n INTEGER NOT NULL, boolean_value BIT, @@ -602,7 +602,13 @@ DROP TABLE alf_node; ALTER TABLE t_alf_node RENAME TO alf_node; DROP TABLE alf_store; ALTER TABLE t_alf_store RENAME TO alf_store; +CREATE INDEX idx_alf_auth_aut ON alf_authority (authority); -- (optional) +-- ---------------- +-- JBPM Differences +-- ---------------- +ALTER TABLE jbpm_processinstance DROP INDEX key_; -- (optional) +CREATE INDEX idx_procin_key ON jbpm_processinstance (key_); -- (optional) -- -- Record script finish diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-2.2-ACL.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-2.2-ACL.sql index a5c92950e4..e480a9a4a4 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-2.2-ACL.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-2.2-ACL.sql @@ -77,7 +77,7 @@ ALTER TABLE alf_authority ADD ( 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) + authority VARCHAR(100 char) NULL ); ALTER TABLE alf_authority ADD PRIMARY KEY (id); ALTER TABLE alf_authority ADD UNIQUE (authority, crc); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-OrclBLOB.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-OrclBLOB.sql deleted file mode 100644 index 556d918402..0000000000 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/AlfrescoSchemaUpdate-OrclBLOB.sql +++ /dev/null @@ -1,27 +0,0 @@ --- --- Title: Change Oracle LONG RAW columns to BLOB --- Database: Generic --- Since: V2.2 Schema 92 --- Author: Derek Hulley --- --- Please contact support@alfresco.com if you need assistance with the upgrade. - --- TODO: This needs to be replaced with a creation of new tables, copying values over with TO_LOB and then --- renaming the values back. - -ALTER TABLE alf_attributes MODIFY (serializable_value BLOB NULL); -ALTER TABLE avm_node_properties MODIFY (serializable_value BLOB NULL); -ALTER TABLE avm_node_properties_new MODIFY (serializable_value BLOB NULL); -ALTER TABLE avm_store_properties MODIFY (serializable_value BLOB NULL); - --- --- Record script finish --- -DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-OrclBLOB'; -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-OrclBLOB', 'Modified serializable_value columns from LONG RAW to BLOB.', - 0, 91, -1, 92, null, 'UNKOWN', 1, 1, 'Script completed' - ); \ No newline at end of file diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-0-create-missing-tables.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-0-create-missing-tables.sql index dcd48b015e..1e12e440d7 100644 --- a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-0-create-missing-tables.sql +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-0-create-missing-tables.sql @@ -12,8 +12,8 @@ -- 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; +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 @@ -22,21 +22,21 @@ ALTER TABLE alf_audit_date RENAME COLUMN year TO full_year; node_id number(19,0), qname varchar2(200 char), primary key (id) - ); -- (optional) + ); -- (optional) create table avm_aspects_new ( id number(19,0) not null, name varchar2(200 char) not null, primary key (id, name) - ); -- (optional) + ); -- (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, + actual_type varchar2(15 char) not null, multi_valued number(1,0) not null, + persisted_type varchar2(15 char) not null, boolean_value number(1,0), long_value number(19,0), float_value float, @@ -44,13 +44,13 @@ ALTER TABLE alf_audit_date RENAME COLUMN year TO full_year; string_value varchar2(1024 char), serializable_value long raw, primary key (id) - ); -- (optional) + ); -- (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, + actual_type varchar2(15 char) not null, multi_valued number(1,0) not null, + persisted_type varchar2(15 char) not null, boolean_value number(1,0), long_value number(19,0), float_value float, @@ -59,15 +59,15 @@ ALTER TABLE alf_audit_date RENAME COLUMN year TO full_year; serializable_value long raw, qname varchar2(200 char) not null, primary key (node_id, qname) - ); -- (optional) + ); -- (optional) create table avm_store_properties ( id number(19,0) not null, avm_store_id number(19,0), - qname varchar2(200 char) not null, - actual_type_n number(10,0) not null, - persisted_type_n number(10,0) not null, + qname varchar2(200 char), + actual_type varchar2(15 char) not null, multi_valued number(1,0) not null, + persisted_type varchar2(15 char) not null, boolean_value number(1,0), long_value number(19,0), float_value float, @@ -75,7 +75,11 @@ ALTER TABLE alf_audit_date RENAME COLUMN year TO full_year; string_value varchar2(1024 char), serializable_value long raw, primary key (id) - ); -- (optional) + ); -- (optional) + +-- Add ACL column for AVM tables +ALTER TABLE avm_stores + ADD (acl_id number(19,0)); -- -- Record script finish diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-from-2.1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-from-2.1.sql new file mode 100644 index 0000000000..05585e8c1e --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-from-2.1.sql @@ -0,0 +1,1142 @@ +-- +-- Title: Apply schema modifications to upgrade from 2.1 +-- Database: Oracle +-- Since: V2.2 Schema 91 +-- Author: Derek Hulley +-- +-- In order to streamline the upgrade, all modifications to large tables need to +-- be handled in as few steps as possible. This usually involves as few ALTER TABLE +-- statements as possible. The general approach is: +-- Create a table with the correct structure, including indexes and CONSTRAINTs +-- Copy pristine data into the new table +-- Drop the old table +-- Rename the new table +-- +-- Please contact support@alfresco.com if you need assistance with the upgrade. +-- + +-- ------------------------------- +-- Build Namespaces and QNames -- +-- ------------------------------- + +-- 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, + PRIMARY KEY (id), + 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, + PRIMARY KEY (id), + UNIQUE (ns_id, local_name) +); +CREATE INDEX fk_alf_qn_ns on alf_qname (ns_id); +ALTER TABLE alf_qname ADD CONSTRAINT fk_alf_qname_ns FOREIGN KEY (ns_id) REFERENCES alf_namespace (id); + +-- Create temporary table for dynamic (child) QNames +CREATE TABLE t_qnames_dyn +( + qname VARCHAR2(255) NOT NULL, + namespace VARCHAR2(255), + namespace_id NUMBER(19,0), + local_name VARCHAR2(200 char) +); +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 distinct qname FROM alf_child_assoc +); +-- Extract the Namespace +UPDATE t_qnames_dyn SET namespace = CONCAT('FILLER-', SUBSTRC(qname,2,INSTRC(qname,'}',1)-2)); +-- Extract the Localname +UPDATE t_qnames_dyn SET local_name = SUBSTRC(qname,INSTRC(qname, '}',-1)+1); +-- Move the namespaces to the their new home +INSERT INTO alf_namespace (id, uri, version) +( + SELECT hibernate_sequence.nextval, y.* FROM + ( + 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 + ) y +); +-- Record the new namespace IDs +UPDATE t_qnames_dyn t SET t.namespace_id = (SELECT ns.id FROM alf_namespace ns WHERE ns.uri = t.namespace); + +-- Recoup some storage +ALTER TABLE t_qnames_dyn DROP COLUMN namespace; + +-- Create temporary table to hold static QNames +CREATE TABLE t_qnames +( + qname VARCHAR2(255) NOT NULL, + namespace VARCHAR2(255), + localname VARCHAR2(255), + qname_id NUMBER(19,0) +); +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 s.type_qname FROM alf_node s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM alf_node_aspects s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM alf_node_properties s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_aspects s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.name FROM avm_aspects_new s LEFT OUTER JOIN t_qnames t ON (s.name = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_node_properties s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_node_properties_new s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.qname FROM avm_store_properties s LEFT OUTER JOIN t_qnames t ON (s.qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.type_qname FROM alf_node_assoc s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.type_qname FROM alf_child_assoc s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); +INSERT INTO t_qnames (qname) +( + SELECT DISTINCT s.type_qname FROM alf_permission s LEFT OUTER JOIN t_qnames t ON (s.type_qname = t.qname) WHERE t.qname IS NULL +); + +-- 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 (id, uri, version) +( + SELECT hibernate_sequence.nextval, y.* FROM + ( + 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 + ) y +); + +-- Move the Localnames to their new home +INSERT INTO alf_qname (id, ns_id, local_name, version) +( + SELECT hibernate_sequence.nextval, y.* + FROM + ( + 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 + ) y +); + +-- Record the new qname IDs +UPDATE t_qnames t SET t.qname_id = +( + SELECT q.id FROM alf_qname q + JOIN alf_namespace ns ON (q.ns_id = ns.id) + WHERE ns.uri = t.namespace AND q.local_name = t.localname +); + +-- ---------------------------- +-- Populate the Permissions -- +-- ---------------------------- + +-- This is a small table so we change it in place +ALTER TABLE alf_permission DROP 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); +CREATE INDEX fk_alf_perm_tqn ON alf_permission (type_qname_id); +ALTER TABLE alf_permission ADD CONSTRAINT fk_alf_perm_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id); + +-- ------------------- +-- Build new Store -- +-- ------------------- + +CREATE TABLE t_alf_store +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + protocol varchar2(50 char) NOT NULL, + identifier varchar2(100 char) NOT NULL, + root_node_id number(19,0), + PRIMARY KEY (id), + UNIQUE (protocol, identifier) +); + +-- -------------------------- +-- Populate the ADM nodes -- +-- -------------------------- + +CREATE TABLE t_alf_node ( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + store_id number(19,0) NOT NULL, + uuid varchar2(36 char) NOT NULL, + transaction_id number(19,0) NOT NULL, + node_deleted NUMBER(1) NOT NULL, + type_qname_id number(19,0) NOT NULL, + acl_id number(19,0), + audit_creator varchar2(255 char), + audit_created varchar2(30 char), + audit_modifier varchar2(255 char), + audit_modified varchar2(30 char), + audit_accessed varchar2(30 char), + PRIMARY KEY (id), + UNIQUE (store_id, uuid) +); +CREATE INDEX idx_alf_node_del on t_alf_node (node_deleted); +CREATE INDEX fk_alf_node_acl on t_alf_node (acl_id); +CREATE INDEX fk_alf_node_tqn on t_alf_node (type_qname_id); +CREATE INDEX fk_alf_node_txn on t_alf_node (transaction_id); +CREATE INDEX fk_alf_node_store on t_alf_node (store_id); +ALTER TABLE t_alf_node + ADD CONSTRAINT fk_alf_node_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id) + ADD CONSTRAINT fk_alf_node_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) + ADD CONSTRAINT fk_alf_node_txn FOREIGN KEY (transaction_id) REFERENCES alf_transaction (id) + ADD CONSTRAINT fk_alf_node_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id) +; + +-- Fill the store table +INSERT INTO t_alf_store (id, version, protocol, identifier, root_node_id) + SELECT hibernate_sequence.nextval, 1, protocol, identifier, root_node_id FROM alf_store +; + +-- Add type_qname index for nodes +CREATE INDEX tidx_node_tqn ON alf_node (type_qname); + +-- Copy data over +INSERT INTO t_alf_node + ( + id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, acl_id, + audit_creator, audit_created, audit_modifier, audit_modified + ) + SELECT + n.id, 1, s.id, n.uuid, nstat.transaction_id, 0, q.qname_id, n.acl_id, + null, null, null, null + FROM + alf_node n + JOIN t_qnames q ON (q.qname = n.type_qname) + JOIN alf_node_status nstat ON (nstat.node_id = n.id) + JOIN t_alf_store s ON (s.protocol = nstat.protocol AND s.identifier = nstat.identifier) +; + +-- Hook the store up to the root node +CREATE INDEX fk_alf_store_root ON t_alf_store (root_node_id); +ALTER TABLE t_alf_store + ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id) +; + +-- ----------------------------- +-- Populate Version Counter -- +-- ----------------------------- + +CREATE TABLE t_alf_version_count +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + store_id number(19,0) NOT NULL UNIQUE, + version_count number(10,0) NOT NULL, + PRIMARY KEY (id) +); + +ALTER TABLE t_alf_version_count + ADD CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id) +; + +INSERT INTO t_alf_version_count + ( + id, version, store_id, version_count + ) + SELECT + hibernate_sequence.nextval, 1, s.id, vc.version_count + FROM + alf_version_count vc + JOIN t_alf_store s ON (s.protocol = vc.protocol AND s.identifier = vc.identifier) +; + +DROP TABLE alf_version_count; +ALTER TABLE t_alf_version_count RENAME TO alf_version_count; + +-- ----------------------------- +-- Populate the Child Assocs -- +-- ----------------------------- + +CREATE TABLE t_alf_child_assoc +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + parent_node_id number(19,0) NOT NULL, + type_qname_id number(19,0) NOT NULL, + child_node_name varchar2(50 char) NOT NULL, + child_node_name_crc number(19,0) NOT NULL, + child_node_id number(19,0) NOT NULL, + qname_ns_id number(19,0) NOT NULL, + qname_localname varchar2(100 char) NOT NULL, + is_primary number(1), + assoc_index number(10,0), + PRIMARY KEY (id), + UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc) +); +CREATE INDEX idx_alf_cass_qnln on t_alf_child_assoc (qname_localname); +CREATE INDEX fk_alf_cass_pnode on t_alf_child_assoc (parent_node_id); +CREATE INDEX fk_alf_cass_cnode on t_alf_child_assoc (child_node_id); +CREATE INDEX fk_alf_cass_tqn on t_alf_child_assoc (type_qname_id); +CREATE INDEX fk_alf_cass_qnns on t_alf_child_assoc (qname_ns_id); +ALTER TABLE t_alf_child_assoc + ADD CONSTRAINT fk_alf_cass_pnode FOREIGN KEY (parent_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_cass_cnode FOREIGN KEY (child_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_cass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) + ADD CONSTRAINT fk_alf_cass_qnns FOREIGN KEY (qname_ns_id) REFERENCES alf_namespace (id) +; + +INSERT INTO t_alf_child_assoc + ( + id, version, + parent_node_id, child_node_id, + child_node_name, child_node_name_crc, + type_qname_id, + qname_ns_id, qname_localname, + is_primary, assoc_index + ) + SELECT + ca.id, 1, + ca.parent_node_id, ca.child_node_id, + ca.child_node_name, child_node_name_crc, + tqn.qname_id, + tqndyn.namespace_id, tqndyn.local_name, + ca.is_primary, ca.assoc_index + FROM + alf_child_assoc ca + JOIN t_qnames_dyn tqndyn ON (ca.qname = tqndyn.qname) + JOIN t_qnames tqn ON (ca.type_qname = tqn.qname) +; + +-- Clean up +DROP TABLE t_qnames_dyn; +DROP TABLE alf_child_assoc; +ALTER TABLE t_alf_child_assoc RENAME TO alf_child_assoc; + +-- ---------------------------- +-- Populate the Node Assocs -- +-- ---------------------------- + +CREATE TABLE t_alf_node_assoc +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + source_node_id number(19,0) NOT NULL, + target_node_id number(19,0) NOT NULL, + type_qname_id number(19,0) NOT NULL, + PRIMARY KEY (id), + UNIQUE (source_node_id, target_node_id, type_qname_id) +); +CREATE INDEX fk_alf_nass_snode on t_alf_node_assoc (source_node_id); +CREATE INDEX fk_alf_nass_tnode on t_alf_node_assoc (target_node_id); +CREATE INDEX fk_alf_nass_tqn on t_alf_node_assoc (type_qname_id); +ALTER TABLE t_alf_node_assoc + ADD CONSTRAINT fk_alf_nass_snode FOREIGN KEY (source_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nass_tnode FOREIGN KEY (target_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) +; + + +INSERT INTO t_alf_node_assoc + ( + id, version, + source_node_id, target_node_id, + type_qname_id + ) + SELECT + na.id, 1, + na.source_node_id, na.source_node_id, + tqn.qname_id + FROM + alf_node_assoc na + JOIN t_qnames tqn ON (na.type_qname = tqn.qname) +; + +-- Clean up +DROP TABLE alf_node_assoc; +ALTER TABLE t_alf_node_assoc RENAME TO alf_node_assoc; + +-- ---------------------------- +-- Populate the Usage Deltas -- +-- ---------------------------- + +CREATE TABLE t_alf_usage_delta +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + node_id number(19,0) NOT NULL, + delta_size number(19,0) NOT NULL, + PRIMARY KEY (id) +); +CREATE INDEX fk_alf_usaged_n on t_alf_usage_delta (node_id); +ALTER TABLE t_alf_usage_delta + ADD CONSTRAINT fk_alf_usaged_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id) +; + +INSERT INTO t_alf_usage_delta + ( + id, version, + node_id, + delta_size + ) + SELECT + ud.id, 1, + ud.node_id, + ud.delta_size + FROM + alf_usage_delta ud +; -- (optional) + +-- Clean up +DROP TABLE alf_usage_delta; -- (optional) +ALTER TABLE t_alf_usage_delta RENAME TO alf_usage_delta; + +-- ----------------------------- +-- Populate the Node Aspects -- +-- ----------------------------- + +CREATE TABLE t_alf_node_aspects +( + node_id number(19,0) NOT NULL, + qname_id number(19,0) NOT NULL, + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_alf_nasp_n on t_alf_node_aspects (node_id); +CREATE INDEX fk_alf_nasp_qn on t_alf_node_aspects (qname_id); +ALTER TABLE t_alf_node_aspects + ADD CONSTRAINT fk_alf_nasp_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +-- Note the omission of sys:referencable. This is implicit. +INSERT INTO t_alf_node_aspects + ( + node_id, qname_id + ) + SELECT + na.node_id, + tqn.qname_id + FROM + alf_node_aspects na + JOIN t_qnames tqn ON (na.qname = tqn.qname) + WHERE + tqn.qname NOT IN + ( + '{http://www.alfresco.org/model/system/1.0}referenceable' + ) +; + +-- Clean up +DROP TABLE alf_node_aspects; +ALTER TABLE t_alf_node_aspects RENAME TO alf_node_aspects; + +-- --------------------------------- +-- Populate the AVM Node Aspects -- +-- --------------------------------- + +CREATE TABLE t_avm_aspects +( + node_id number(19,0) NOT NULL, + qname_id number(19,0) NOT NULL, + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nasp_n on t_avm_aspects (node_id); +CREATE INDEX fk_avm_nasp_qn on t_avm_aspects (qname_id); +ALTER TABLE t_avm_aspects + ADD CONSTRAINT fk_avm_nasp_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_avm_aspects + ( + node_id, qname_id + ) + SELECT + aspects_old.node_id, + tqn.qname_id + FROM + avm_aspects aspects_old + JOIN t_qnames tqn ON (aspects_old.qname = tqn.qname) +; +INSERT INTO t_avm_aspects + ( + node_id, qname_id + ) + SELECT + anew.id, + tqn.qname_id + FROM + avm_aspects_new anew + JOIN t_qnames tqn ON (anew.name = tqn.qname) + LEFT JOIN avm_aspects aold ON (anew.id = aold.node_id AND anew.name = aold.qname) + WHERE + aold.id IS NULL +; + +-- Clean up +DROP TABLE avm_aspects; +DROP TABLE avm_aspects_new; +ALTER TABLE t_avm_aspects RENAME TO avm_aspects; + +-- ---------------------------------- +-- Migrate Sundry Property Tables -- +-- ---------------------------------- + +-- Create temporary mapping for property types +CREATE TABLE t_prop_types +( + type_name varchar2(15 char) NOT NULL, + type_id number(10,0) 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 avm_store_properties table +CREATE TABLE t_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) NOT NULL, + boolean_value number(1), + long_value number(19,0), + float_value float, + double_value DOUBLE PRECISION, + string_value varchar2(1024 char), + serializable_value blob, + PRIMARY KEY (id) +); +CREATE INDEX fk_avm_sprop_store on t_avm_store_properties (avm_store_id); +CREATE INDEX fk_avm_sprop_qname on t_avm_store_properties (qname_id); +ALTER TABLE t_avm_store_properties + ADD CONSTRAINT fk_avm_sprop_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id) + ADD CONSTRAINT fk_avm_sprop_qname FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_avm_store_properties + ( + id, + avm_store_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + hibernate_sequence.nextval, + p.avm_store_id, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, TO_LOB(p.serializable_value) + FROM + avm_store_properties p + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) +; +DROP TABLE avm_store_properties; +ALTER TABLE t_avm_store_properties RENAME TO avm_store_properties; + +-- Modify the avm_node_properties_new table +CREATE TABLE t_avm_node_properties +( + node_id 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) NOT NULL, + boolean_value number(1), + long_value number(19,0), + float_value FLOAT, + double_value DOUBLE PRECISION, + string_value varchar2(1024 char), + serializable_value BLOB, + qname_id number(19,0) NOT NULL, + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nprop_n on t_avm_node_properties (node_id); +CREATE INDEX fk_avm_nprop_qn on t_avm_node_properties (qname_id); +ALTER TABLE t_avm_node_properties + ADD CONSTRAINT fk_avm_nprop_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_avm_node_properties + ( + node_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.node_id, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, TO_LOB(p.serializable_value) + FROM + avm_node_properties_new p + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) +; +INSERT INTO t_avm_node_properties + ( + node_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.node_id, + tqn.qname_id, + ptypes_actual.type_id, ptypes_persisted.type_id, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, TO_LOB(p.serializable_value) + FROM + avm_node_properties p + JOIN t_qnames tqn ON (p.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = p.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = p.persisted_type) + LEFT OUTER JOIN t_avm_node_properties tanp ON (tqn.qname_id = tanp.qname_id) + WHERE + tanp.qname_id IS NULL +; + +DROP TABLE avm_node_properties_new; +DROP TABLE avm_node_properties; +ALTER TABLE t_avm_node_properties RENAME TO avm_node_properties; + + +-- ----------------- +-- Build Locales -- +-- ----------------- + +CREATE TABLE alf_locale +( + id number(19,0) NOT NULL, + version number(19,0) DEFAULT 1 NOT NULL, + locale_str varchar2(20 char) NOT NULL, + PRIMARY KEY (id), + UNIQUE (locale_str) +); + +INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default'); + +-- Locales come from the attribute table which was used to support MLText persistence +INSERT INTO alf_locale (id, locale_str) + SELECT hibernate_sequence.nextval, mkey + FROM ( + SELECT DISTINCT(ma.mkey) + FROM alf_node_properties np + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) + ) +; + +-- ------------------------------- +-- Migrate ADM Property Tables -- +-- ------------------------------- + +CREATE TABLE t_alf_node_properties +( + node_id number(19,0) NOT NULL, + qname_id number(19,0) NOT NULL, + locale_id number(19,0) NOT NULL, + list_index number(10,0) NOT NULL, + actual_type_n number(10,0) NOT NULL, + persisted_type_n number(10,0) NOT NULL, + boolean_value number(1), + long_value number(19,0), + float_value FLOAT, + double_value DOUBLE PRECISION, + string_value varchar2(1024 char), + serializable_value BLOB, + PRIMARY KEY (node_id, qname_id, list_index, locale_id) +); +CREATE INDEX fk_alf_nprop_n on t_alf_node_properties (node_id); +CREATE INDEX fk_alf_nprop_qn on t_alf_node_properties (qname_id); +CREATE INDEX fk_alf_nprop_loc on t_alf_node_properties (locale_id); +ALTER TABLE t_alf_node_properties + ADD CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) + ADD CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id) +; + +-- Copy values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, tqn.qname_id, -1, 1, + ptypes_actual.type_id, ptypes_persisted.type_id, + np.boolean_value, np.long_value, np.float_value, np.double_value, + np.string_value, + TO_LOB(np.serializable_value) + FROM + alf_node_properties np + JOIN t_qnames tqn ON (np.qname = tqn.qname) + JOIN t_prop_types ptypes_actual ON (ptypes_actual.type_name = np.actual_type) + JOIN t_prop_types ptypes_persisted ON (ptypes_persisted.type_name = np.persisted_type) + WHERE + np.attribute_value IS NULL +; +-- Update cm:auditable properties on the nodes +UPDATE t_alf_node n SET audit_creator = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'creator' +); +UPDATE t_alf_node n SET audit_created = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'created' +); +UPDATE t_alf_node n SET audit_modifier = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modifier' +); +UPDATE t_alf_node n SET audit_modified = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modified' +); +-- Remove the unused cm:auditable properties +DELETE + FROM t_alf_node_properties + WHERE EXISTS + ( + SELECT 1 + FROM alf_qname, alf_namespace + WHERE t_alf_node_properties.qname_id = alf_qname.id + AND alf_qname.ns_id = alf_namespace.id + AND alf_namespace.uri = 'FILLER-http://www.alfresco.org/model/content/1.0' + AND alf_qname.local_name IN ('creator', 'created', 'modifier', 'modified') + ) +; + +-- Copy all MLText values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, tqn.qname_id, -1, loc.id, + -1, 0, + 0, 0, 0, 0, + a2.string_value, + TO_LOB(a2.serializable_value) + FROM + alf_node_properties np + JOIN t_qnames tqn ON (np.qname = tqn.qname) + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) + JOIN alf_locale loc ON (ma.mkey = loc.locale_str) + JOIN alf_attributes a2 ON (ma.attribute_id = a2.id) +; -- (OPTIONAL) +UPDATE t_alf_node_properties + SET actual_type_n = 6, persisted_type_n = 6, serializable_value = NULL + WHERE actual_type_n = -1 AND string_value IS NOT NULL +; +UPDATE t_alf_node_properties + SET actual_type_n = 9, persisted_type_n = 9 + WHERE actual_type_n = -1 AND serializable_value IS NOT NULL +; + +-- Delete the node properties and move the fixed values over +DROP TABLE alf_node_properties; +ALTER TABLE t_alf_node_properties RENAME TO alf_node_properties; + +CREATE TABLE t_del_attributes +( + id number(19,0) NOT NULL, + PRIMARY KEY (id) +); +INSERT INTO t_del_attributes + SELECT id FROM alf_attributes WHERE type = 'M' +; +DELETE + FROM t_del_attributes + WHERE EXISTS + ( + SELECT 1 FROM alf_map_attribute_entries ma WHERE ma.attribute_id = t_del_attributes.id + ) +; +DELETE + FROM t_del_attributes + WHERE EXISTS + ( + SELECT 1 FROM alf_list_attribute_entries la WHERE la.attribute_id = t_del_attributes.id + ) +; +DELETE + FROM t_del_attributes + WHERE EXISTS + ( + SELECT 1 FROM alf_global_attributes ga WHERE ga.attribute = t_del_attributes.id + ) +; +INSERT INTO t_del_attributes + SELECT a.id FROM t_del_attributes t + JOIN alf_map_attribute_entries ma ON (ma.map_id = t.id) + JOIN alf_attributes a ON (ma.attribute_id = a.id) +; +DELETE + FROM alf_map_attribute_entries + WHERE EXISTS + ( + SELECT 1 FROM t_del_attributes t WHERE alf_map_attribute_entries.map_id = t.id + ) +; +DELETE + FROM alf_attributes + WHERE EXISTS + ( + SELECT 1 FROM t_del_attributes t WHERE alf_attributes.id = t.id + ) +; +DROP TABLE t_del_attributes; + +-- --------------------------------------------------- +-- Remove the FILLER- values from the namespace uri -- +-- --------------------------------------------------- +UPDATE alf_namespace SET uri = '.empty' WHERE uri = 'FILLER-'; +UPDATE alf_namespace SET uri = SUBSTR(uri, 8) WHERE uri LIKE 'FILLER-%'; + +-- ------------------ +-- Final clean up -- +-- ------------------ +DROP TABLE t_qnames; +DROP TABLE t_prop_types; +DROP TABLE alf_node_status; +DROP INDEX FKBD4FF53D22DBA5BA; -- (OPTIONAL) +ALTER TABLE alf_store DROP CONSTRAINT FKBD4FF53D22DBA5BA; -- (OPTIONAL) +ALTER TABLE alf_store DROP CONSTRAINT alf_store_root; -- (OPTIONAL) +DROP TABLE alf_node; +ALTER TABLE t_alf_node RENAME TO alf_node; +DROP TABLE alf_store; +ALTER TABLE t_alf_store RENAME TO alf_store; + + +-- ------------------------------------- +-- Modify index and constraint names -- +-- ------------------------------------- + +-- Since one has to rebuild indexes after changing a column to a BLOB, this +-- is also a good time to remap the BLOB column! +DROP INDEX fk_attributes_n_acl; -- (optional) +DROP INDEX fk_attr_n_acl; -- (optional) +ALTER TABLE alf_attributes DROP CONSTRAINT fk_attributes_n_acl; -- (optional) +DROP INDEX FK64D0B9CF69B9F16A; -- (optional) +ALTER TABLE alf_global_attributes DROP CONSTRAINT 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) +ALTER TABLE alf_attributes DROP PRIMARY KEY DROP INDEX; +ALTER TABLE alf_attributes MODIFY (serializable_value BLOB NULL); -- (optional) +ALTER TABLE alf_attributes ADD PRIMARY KEY (id); +CREATE INDEX fk_alf_attr_acl ON alf_attributes (acl_id); + +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) + +CREATE INDEX idx_alf_adtd_woy ON alf_audit_date (week_of_year); +CREATE INDEX idx_alf_adtd_q ON alf_audit_date (quarter); +CREATE INDEX idx_alf_adtd_wom ON alf_audit_date (week_of_month); +CREATE INDEX idx_alf_adtd_dom ON alf_audit_date (day_of_month); +CREATE INDEX idx_alf_adtd_doy ON alf_audit_date (day_of_year); +CREATE INDEX idx_alf_adtd_dow ON alf_audit_date (day_of_week); +CREATE INDEX idx_alf_adtd_m ON alf_audit_date (month); +CREATE INDEX idx_alf_adtd_hy ON alf_audit_date (half_year); +CREATE INDEX idx_alf_adtd_fy ON alf_audit_date (full_year); +CREATE INDEX idx_alf_adtd_dat ON alf_audit_date (date_only); + +DROP INDEX adt_user_idx; -- (optional) +DROP INDEX adt_store_idx; -- (optional) + +DROP INDEX FKEAD18174A0F9B8D9; +DROP INDEX FKEAD1817484342E39; +DROP INDEX FKEAD18174F524CFD7; + +ALTER TABLE alf_audit_fact + DROP CONSTRAINT FKEAD18174A0F9B8D9 + DROP CONSTRAINT FKEAD1817484342E39 + DROP CONSTRAINT FKEAD18174F524CFD7 +; + +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 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); + +ALTER TABLE alf_audit_fact + ADD CONSTRAINT fk_alf_adtf_src FOREIGN KEY (audit_source_id) REFERENCES alf_audit_source (id) + ADD CONSTRAINT fk_alf_adtf_date FOREIGN KEY (audit_date_id) REFERENCES alf_audit_date (id) + ADD CONSTRAINT fk_alf_adtf_conf FOREIGN KEY (audit_conf_id) REFERENCES alf_audit_config (id) +; + +DROP INDEX app_source_app_idx; -- (optional) +DROP INDEX app_source_ser_idx; -- (optional) +DROP INDEX app_source_met_idx; -- (optional) + +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); + +-- 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) +ALTER TABLE alf_global_attributes + ADD CONSTRAINT fk_alf_gatt_att FOREIGN KEY (attribute) REFERENCES alf_attributes (id) +; + +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); +ALTER TABLE alf_list_attribute_entries + ADD CONSTRAINT fk_alf_lent_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id) + ADD CONSTRAINT fk_alf_lent_latt FOREIGN KEY (list_id) REFERENCES alf_attributes (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); +ALTER TABLE alf_map_attribute_entries + ADD CONSTRAINT fk_alf_matt_matt FOREIGN KEY (map_id) REFERENCES alf_attributes (id) + ADD CONSTRAINT fk_alf_matt_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id) +; + +DROP INDEX idx_commit_time_ms; -- (optional) +DROP INDEX FKB8761A3A9AE340B7; +CREATE INDEX fk_alf_txn_svr ON alf_transaction (server_id); +CREATE INDEX idx_alf_txn_ctms ON alf_transaction (commit_time_ms); +ALTER TABLE alf_transaction DROP CONSTRAINT FKB8761A3A9AE340B7; +ALTER TABLE alf_transaction + ADD CONSTRAINT fk_alf_txn_svr FOREIGN KEY (server_id) REFERENCES alf_server (id) +; +DROP INDEX fk_avm_ce_child; -- (optional) +DROP INDEX fk_avm_ce_parent; -- (optional) +ALTER TABLE avm_child_entries DROP CONSTRAINT fk_avm_ce_child; -- (optional) +ALTER TABLE avm_child_entries DROP CONSTRAINT fk_avm_ce_parent; -- (optional) +CREATE INDEX fk_avm_ce_child ON avm_child_entries (child_id); +CREATE INDEX fk_avm_ce_parent ON avm_child_entries (parent_id); +ALTER TABLE avm_child_entries + ADD CONSTRAINT fk_avm_ce_child FOREIGN KEY (child_id) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_ce_parent FOREIGN KEY (parent_id) REFERENCES avm_nodes (id) +; + +DROP INDEX fk_avm_hl_desc; -- (optional) +DROP INDEX fk_avm_hl_ancestor; -- (optional) +DROP INDEX idx_avm_hl_revpk; -- (optional) +ALTER TABLE avm_history_links DROP CONSTRAINT fk_avm_hl_desc; -- (optional) +ALTER TABLE avm_history_links DROP CONSTRAINT fk_avm_hl_ancestor; -- (optional) +DROP INDEX idx_avm_hl_revpk; -- (optional) +CREATE INDEX fk_avm_hl_desc ON avm_history_links (descendent); +CREATE INDEX fk_avm_hl_ancestor ON avm_history_links (ancestor); +CREATE INDEX idx_avm_hl_revpk ON avm_history_links (descendent, ancestor); +ALTER TABLE avm_history_links + ADD CONSTRAINT fk_avm_hl_desc FOREIGN KEY (descendent) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_hl_ancestor FOREIGN KEY (ancestor) REFERENCES avm_nodes (id) +; + +DROP INDEX fk_avm_ml_to; -- (optional) +DROP INDEX fk_avm_ml_from; -- (optional) +ALTER TABLE avm_merge_links DROP CONSTRAINT fk_avm_ml_to; -- (optional) +ALTER TABLE avm_merge_links DROP CONSTRAINT fk_avm_ml_from; -- (optional) + +CREATE INDEX fk_avm_ml_to ON avm_merge_links (mto); +CREATE INDEX fk_avm_ml_from ON avm_merge_links (mfrom); +ALTER TABLE avm_merge_links + ADD CONSTRAINT fk_avm_ml_to FOREIGN KEY (mto) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_ml_from FOREIGN KEY (mfrom) REFERENCES avm_nodes (id) +; +DROP INDEX fk_avm_n_acl; -- (optional) +DROP INDEX fk_avm_n_store; -- (optional) +DROP INDEX idx_avm_n_pi; -- (optional) +ALTER TABLE avm_nodes DROP CONSTRAINT fk_avm_n_acl; -- (optional) +ALTER TABLE avm_nodes DROP CONSTRAINT fk_avm_n_store; -- (optional) + +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 idx_avm_n_pi ON avm_nodes (primary_indirection); +ALTER TABLE avm_nodes + ADD CONSTRAINT fk_avm_n_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id) + ADD CONSTRAINT fk_avm_n_store FOREIGN KEY (store_new_id) REFERENCES avm_stores (id) +; + +DROP INDEX fk_avm_s_root; -- (optional) +ALTER TABLE avm_stores DROP CONSTRAINT fk_avm_s_root; -- (optional) +CREATE INDEX fk_avm_s_acl ON avm_stores (acl_id); +CREATE INDEX fk_avm_s_root ON avm_stores (current_root_id); +ALTER TABLE avm_stores + ADD CONSTRAINT fk_avm_s_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id) + ADD CONSTRAINT fk_avm_s_root FOREIGN KEY (current_root_id) REFERENCES avm_nodes (id) +; + +DROP INDEX FK182E672DEB9D70C; -- (optional) +ALTER TABLE avm_version_layered_node_entry DROP CONSTRAINT FK182E672DEB9D70C; -- (optional) +CREATE INDEX fk_avm_vlne_vr ON avm_version_layered_node_entry (version_root_id); +ALTER TABLE avm_version_layered_node_entry + ADD CONSTRAINT fk_avm_vlne_vr FOREIGN KEY (version_root_id) REFERENCES avm_version_roots (id) +; + +DROP INDEX idx_avm_vr_version; -- (optional) +DROP INDEX idx_avm_vr_revuq; -- (optional) +DROP INDEX fk_avm_vr_root; -- (optional) +DROP INDEX fk_avm_vr_store; -- (optional) +ALTER TABLE avm_version_roots DROP CONSTRAINT fk_avm_vr_root; -- (optional) +ALTER TABLE avm_version_roots DROP CONSTRAINT fk_avm_vr_store; -- (optional) +CREATE INDEX idx_avm_vr_version ON avm_version_roots (version_id); +CREATE INDEX idx_avm_vr_revuq ON avm_version_roots (avm_store_id, version_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); +ALTER TABLE avm_version_roots + ADD CONSTRAINT fk_avm_vr_root FOREIGN KEY (root_id) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_vr_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id) +; + +-- +-- Record script finish +-- +DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Upgrade-From-2.1'; +INSERT INTO alf_applied_patch + (id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report) + VALUES + ( + 'patch.db-V2.2-Upgrade-From-2.1', 'Manually executed script upgrade V2.2: Upgrade from 2.1', + 0, 85, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-from-2.2SP1.sql b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-from-2.2SP1.sql new file mode 100644 index 0000000000..6cd33ad421 --- /dev/null +++ b/config/alfresco/dbscripts/upgrade/2.2/org.hibernate.dialect.Oracle9iDialect/upgrade-from-2.2SP1.sql @@ -0,0 +1,697 @@ +-- +-- Title: Upgrade V2.2 SP1 or SP2 +-- Database: Oracle +-- Since: V2.2 Schema 91 +-- Author: Derek Hulley +-- +-- MLText values must be pulled back from attributes into localizable properties. +-- NodeStatus has been moved to alf_node. +-- Auditable properties have been moved to alf_node. +-- alf_node contains the old alf_node_status information. +-- +-- Please contact support@alfresco.com if you need assistance with the upgrade. +-- + +-- ------------------- +-- Build new Store -- +-- ------------------- + +CREATE TABLE t_alf_store +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + protocol varchar2(50 char) NOT NULL, + identifier varchar2(100 char) NOT NULL, + root_node_id number(19,0), + PRIMARY KEY (id), + UNIQUE (protocol, identifier) +); + +-- -------------------------- +-- Populate the ADM nodes -- +-- -------------------------- + +CREATE TABLE t_alf_node ( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + store_id number(19,0) NOT NULL, + uuid varchar2(36 char) NOT NULL, + transaction_id number(19,0) NOT NULL, + node_deleted NUMBER(1) NOT NULL, + type_qname_id number(19,0) NOT NULL, + acl_id number(19,0), + audit_creator varchar2(255 char), + audit_created varchar2(30 char), + audit_modifier varchar2(255 char), + audit_modified varchar2(30 char), + audit_accessed varchar2(30 char), + PRIMARY KEY (id), + UNIQUE (store_id, uuid) +); + +CREATE INDEX idx_alf_node_del on t_alf_node (node_deleted); +CREATE INDEX fk_alf_node_acl on t_alf_node (acl_id); +CREATE INDEX fk_alf_node_tqn on t_alf_node (type_qname_id); +CREATE INDEX fk_alf_node_txn on t_alf_node (transaction_id); +CREATE INDEX fk_alf_node_store on t_alf_node (store_id); +ALTER TABLE t_alf_node + ADD CONSTRAINT fk_alf_node_acl FOREIGN KEY (acl_id) REFERENCES alf_access_control_list (id) + ADD CONSTRAINT fk_alf_node_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) + ADD CONSTRAINT fk_alf_node_txn FOREIGN KEY (transaction_id) REFERENCES alf_transaction (id) + ADD CONSTRAINT fk_alf_node_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id) +; + +-- Fill the store table +INSERT INTO t_alf_store (id, version, protocol, identifier, root_node_id) + SELECT hibernate_sequence.nextval, 1, protocol, identifier, root_node_id FROM alf_store +; + +-- Copy data over +INSERT INTO t_alf_node + ( + id, version, store_id, uuid, transaction_id, node_deleted, type_qname_id, acl_id, + audit_creator, audit_created, audit_modifier, audit_modified + ) + SELECT + n.id, 1, s.id, n.uuid, nstat.transaction_id, 0, n.type_qname_id, n.acl_id, + null, null, null, null + FROM + alf_node n + JOIN alf_node_status nstat ON (nstat.node_id = n.id) + JOIN t_alf_store s ON (s.protocol = nstat.protocol AND s.identifier = nstat.identifier) +; + +-- Hook the store up to the root node +CREATE INDEX fk_alf_store_root ON t_alf_store (root_node_id); +ALTER TABLE t_alf_store + ADD CONSTRAINT fk_alf_store_root FOREIGN KEY (root_node_id) REFERENCES t_alf_node (id) +; + +-- ----------------------------- +-- Populate Version Counter -- +-- ----------------------------- + +CREATE TABLE t_alf_version_count +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + store_id number(19,0) NOT NULL UNIQUE, + version_count number(10,0) NOT NULL, + PRIMARY KEY (id) +); +ALTER TABLE t_alf_version_count + ADD CONSTRAINT fk_alf_vc_store FOREIGN KEY (store_id) REFERENCES t_alf_store (id) +; + +INSERT INTO t_alf_version_count + ( + id, version, store_id, version_count + ) + SELECT + hibernate_sequence.nextval, 1, s.id, vc.version_count + FROM + alf_version_count vc + JOIN t_alf_store s ON (s.protocol = vc.protocol AND s.identifier = vc.identifier) +; + +DROP TABLE alf_version_count; +ALTER TABLE t_alf_version_count RENAME TO alf_version_count; + +-- ----------------------------- +-- Populate the Child Assocs -- +-- ----------------------------- + +CREATE TABLE t_alf_child_assoc +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + parent_node_id number(19,0) NOT NULL, + type_qname_id number(19,0) NOT NULL, + child_node_name varchar2(50 char) NOT NULL, + child_node_name_crc number(19,0) NOT NULL, + child_node_id number(19,0) NOT NULL, + qname_ns_id number(19,0) NOT NULL, + qname_localname varchar2(100 char) NOT NULL, + is_primary number(1), + assoc_index number(10,0), + PRIMARY KEY (id), + UNIQUE (parent_node_id, type_qname_id, child_node_name, child_node_name_crc) +); +CREATE INDEX idx_alf_cass_qnln on t_alf_child_assoc (qname_localname); +CREATE INDEX fk_alf_cass_pnode on t_alf_child_assoc (parent_node_id); +CREATE INDEX fk_alf_cass_cnode on t_alf_child_assoc (child_node_id); +CREATE INDEX fk_alf_cass_tqn on t_alf_child_assoc (type_qname_id); +CREATE INDEX fk_alf_cass_qnns on t_alf_child_assoc (qname_ns_id); +ALTER TABLE t_alf_child_assoc + ADD CONSTRAINT fk_alf_cass_pnode FOREIGN KEY (parent_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_cass_cnode FOREIGN KEY (child_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_cass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) + ADD CONSTRAINT fk_alf_cass_qnns FOREIGN KEY (qname_ns_id) REFERENCES alf_namespace (id) +; + +INSERT INTO t_alf_child_assoc + ( + id, version, + parent_node_id, child_node_id, + child_node_name, child_node_name_crc, + type_qname_id, + qname_ns_id, qname_localname, + is_primary, assoc_index + ) + SELECT + ca.id, 1, + ca.parent_node_id, ca.child_node_id, + ca.child_node_name, child_node_name_crc, + ca.type_qname_id, + ca.qname_ns_id, ca.qname_localname, + ca.is_primary, ca.assoc_index + FROM + alf_child_assoc ca +; + +-- Clean up +DROP TABLE alf_child_assoc; +ALTER TABLE t_alf_child_assoc RENAME TO alf_child_assoc; + +-- ---------------------------- +-- Populate the Node Assocs -- +-- ---------------------------- + +CREATE TABLE t_alf_node_assoc +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + source_node_id number(19,0) NOT NULL, + target_node_id number(19,0) NOT NULL, + type_qname_id number(19,0) NOT NULL, + PRIMARY KEY (id), + UNIQUE (source_node_id, target_node_id, type_qname_id) +); +CREATE INDEX fk_alf_nass_snode on t_alf_node_assoc (source_node_id); +CREATE INDEX fk_alf_nass_tnode on t_alf_node_assoc (target_node_id); +CREATE INDEX fk_alf_nass_tqn on t_alf_node_assoc (type_qname_id); +ALTER TABLE t_alf_node_assoc + ADD CONSTRAINT fk_alf_nass_snode FOREIGN KEY (source_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nass_tnode FOREIGN KEY (target_node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nass_tqn FOREIGN KEY (type_qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_alf_node_assoc + ( + id, version, + source_node_id, target_node_id, + type_qname_id + ) + SELECT + na.id, 1, + na.source_node_id, na.source_node_id, + na.type_qname_id + FROM + alf_node_assoc na +; + +-- Clean up +DROP TABLE alf_node_assoc; +ALTER TABLE t_alf_node_assoc RENAME TO alf_node_assoc; + +-- ---------------------------- +-- Populate the Usage Deltas -- +-- ---------------------------- + +CREATE TABLE t_alf_usage_delta +( + id number(19,0) NOT NULL, + version number(19,0) NOT NULL, + node_id number(19,0) NOT NULL, + delta_size number(19,0) NOT NULL, + PRIMARY KEY (id) +); +CREATE INDEX fk_alf_usaged_n on t_alf_usage_delta (node_id); +ALTER TABLE t_alf_usage_delta + ADD CONSTRAINT fk_alf_usaged_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id) +; + +INSERT INTO t_alf_usage_delta + ( + id, version, + node_id, + delta_size + ) + SELECT + ud.id, 1, + ud.node_id, + ud.delta_size + FROM + alf_usage_delta ud +; -- (optional) + +-- Clean up +DROP TABLE alf_usage_delta; -- (optional) +ALTER TABLE t_alf_usage_delta RENAME TO alf_usage_delta; + +-- ----------------------------- +-- Populate the Node Aspects -- +-- ----------------------------- + +CREATE TABLE t_alf_node_aspects +( + node_id number(19,0) NOT NULL, + qname_id number(19,0) NOT NULL, + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_alf_nasp_n on t_alf_node_aspects (node_id); +CREATE INDEX fk_alf_nasp_qn on t_alf_node_aspects (qname_id); +ALTER TABLE t_alf_node_aspects + ADD CONSTRAINT fk_alf_nasp_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +-- Note the omission of sys:referencable. This is implicit. +INSERT INTO t_alf_node_aspects + ( + node_id, qname_id + ) + SELECT + na.node_id, + qname_id + FROM + alf_node_aspects na + JOIN alf_qname qn ON (na.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + ns.uri != 'http://www.alfresco.org/model/system/1.0' OR + qn.local_name != 'referenceable' +; + +-- Clean up +DROP TABLE alf_node_aspects; +ALTER TABLE t_alf_node_aspects RENAME TO alf_node_aspects; + +-- --------------------------------- +-- Populate the AVM Node Aspects -- +-- --------------------------------- + +CREATE TABLE t_avm_aspects +( + node_id number(19,0) NOT NULL, + qname_id number(19,0) NOT NULL, + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nasp_n on t_avm_aspects (node_id); +CREATE INDEX fk_avm_nasp_qn on t_avm_aspects (qname_id); +ALTER TABLE t_avm_aspects + ADD CONSTRAINT fk_avm_nasp_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_nasp_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_avm_aspects + ( + node_id, qname_id + ) + SELECT + anew.id, + anew.qname_id + FROM + avm_aspects_new anew +; + +-- Clean up +DROP TABLE avm_aspects; +DROP TABLE avm_aspects_new; +ALTER TABLE t_avm_aspects RENAME TO avm_aspects; + +-- ---------------------------------- +-- Migrate Sundry Property Tables -- +-- ---------------------------------- + +-- Modify the avm_store_properties table +CREATE TABLE t_avm_store_properties +( + id 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) NOT NULL, + boolean_value number(1), + long_value number(19,0), + float_value float, + double_value DOUBLE PRECISION, + string_value varchar2(1024 char), + serializable_value blob, + PRIMARY KEY (id) +); +CREATE INDEX fk_avm_sprop_store on t_avm_store_properties (avm_store_id); +CREATE INDEX fk_avm_sprop_qname on t_avm_store_properties (qname_id); +ALTER TABLE t_avm_store_properties + ADD CONSTRAINT fk_avm_sprop_store FOREIGN KEY (avm_store_id) REFERENCES avm_stores (id) + ADD CONSTRAINT fk_avm_sprop_qname FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_avm_store_properties + ( + id, + avm_store_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + hibernate_sequence.nextval, + p.avm_store_id, + p.qname_id, + p.actual_type_n, p.persisted_type_n, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, TO_LOB(p.serializable_value) + FROM + avm_store_properties p +; +DROP TABLE avm_store_properties; +ALTER TABLE t_avm_store_properties RENAME TO avm_store_properties; + +-- Modify the avm_node_properties_new table +CREATE TABLE t_avm_node_properties +( + node_id 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) NOT NULL, + boolean_value number(1), + long_value number(19,0), + float_value FLOAT, + double_value DOUBLE PRECISION, + string_value varchar2(1024 char), + serializable_value BLOB, + qname_id number(19,0) NOT NULL, + PRIMARY KEY (node_id, qname_id) +); +CREATE INDEX fk_avm_nprop_n on t_avm_node_properties (node_id); +CREATE INDEX fk_avm_nprop_qn on t_avm_node_properties (qname_id); +ALTER TABLE t_avm_node_properties + ADD CONSTRAINT fk_avm_nprop_n FOREIGN KEY (node_id) REFERENCES avm_nodes (id) + ADD CONSTRAINT fk_avm_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) +; + +INSERT INTO t_avm_node_properties + ( + node_id, + qname_id, + actual_type_n, persisted_type_n, + multi_valued, boolean_value, long_value, float_value, double_value, string_value, serializable_value + ) + SELECT + p.node_id, + p.qname_id, + p.actual_type_n, p.persisted_type_n, + p.multi_valued, p.boolean_value, p.long_value, p.float_value, p.double_value, p.string_value, TO_LOB(p.serializable_value) + FROM + avm_node_properties_new p +; + +DROP TABLE avm_node_properties_new; +DROP TABLE avm_node_properties; +ALTER TABLE t_avm_node_properties RENAME TO avm_node_properties; + + +-- ----------------- +-- Build Locales -- +-- ----------------- + +CREATE TABLE alf_locale +( + id number(19,0) NOT NULL, + version number(19,0) DEFAULT 1 NOT NULL, + locale_str varchar2(20 char) NOT NULL, + PRIMARY KEY (id), + UNIQUE (locale_str) +); + +INSERT INTO alf_locale (id, locale_str) VALUES (1, '.default'); + +-- Locales come from the attribute table which was used to support MLText persistence +INSERT INTO alf_locale (id, locale_str) + SELECT hibernate_sequence.nextval, mkey + FROM ( + SELECT DISTINCT(ma.mkey) + FROM alf_node_properties np + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) + ) +; + +-- ------------------------------- +-- Migrate ADM Property Tables -- +-- ------------------------------- + +CREATE TABLE t_alf_node_properties +( + node_id number(19,0) NOT NULL, + qname_id number(19,0) NOT NULL, + locale_id number(19,0) NOT NULL, + list_index number(10,0) NOT NULL, + actual_type_n number(10,0) NOT NULL, + persisted_type_n number(10,0) NOT NULL, + boolean_value number(1), + long_value number(19,0), + float_value FLOAT, + double_value DOUBLE PRECISION, + string_value varchar2(1024 char), + serializable_value BLOB, + PRIMARY KEY (node_id, qname_id, list_index, locale_id) +); +CREATE INDEX fk_alf_nprop_n on t_alf_node_properties (node_id); +CREATE INDEX fk_alf_nprop_qn on t_alf_node_properties (qname_id); +CREATE INDEX fk_alf_nprop_loc on t_alf_node_properties (locale_id); +ALTER TABLE t_alf_node_properties + ADD CONSTRAINT fk_alf_nprop_n FOREIGN KEY (node_id) REFERENCES t_alf_node (id) + ADD CONSTRAINT fk_alf_nprop_qn FOREIGN KEY (qname_id) REFERENCES alf_qname (id) + ADD CONSTRAINT fk_alf_nprop_loc FOREIGN KEY (locale_id) REFERENCES alf_locale (id) +; + +-- Copy values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, np.qname_id, -1, 1, + np.actual_type_n, np.persisted_type_n, + np.boolean_value, np.long_value, np.float_value, np.double_value, + np.string_value, + TO_LOB(np.serializable_value) + FROM + alf_node_properties np + WHERE + np.attribute_value IS NULL +; +-- Update cm:auditable properties on the nodes +UPDATE t_alf_node n SET audit_creator = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'creator' +); +UPDATE t_alf_node n SET audit_created = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'created' +); +UPDATE t_alf_node n SET audit_modifier = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modifier' +); +UPDATE t_alf_node n SET audit_modified = +( + SELECT + string_value + FROM + t_alf_node_properties np + JOIN alf_qname qn ON (np.qname_id = qn.id) + JOIN alf_namespace ns ON (qn.ns_id = ns.id) + WHERE + np.node_id = n.id AND + ns.uri = 'http://www.alfresco.org/model/content/1.0' AND + qn.local_name = 'modified' +); +-- Remove the unused cm:auditable properties +DELETE + FROM t_alf_node_properties + WHERE EXISTS + ( + SELECT 1 + FROM alf_qname, alf_namespace + WHERE t_alf_node_properties.qname_id = alf_qname.id + AND alf_qname.ns_id = alf_namespace.id + AND alf_namespace.uri = 'http://www.alfresco.org/model/content/1.0' + AND alf_qname.local_name IN ('creator', 'created', 'modifier', 'modified') + ) +; + +-- Copy all MLText values over +INSERT INTO t_alf_node_properties + ( + node_id, qname_id, list_index, locale_id, + actual_type_n, persisted_type_n, + boolean_value, long_value, float_value, double_value, + string_value, + serializable_value + ) + SELECT + np.node_id, np.qname_id, -1, loc.id, + -1, 0, + 0, 0, 0, 0, + a2.string_value, + TO_LOB(a2.serializable_value) + FROM + alf_node_properties np + JOIN alf_attributes a1 ON (np.attribute_value = a1.id) + JOIN alf_map_attribute_entries ma ON (ma.map_id = a1.id) + JOIN alf_locale loc ON (ma.mkey = loc.locale_str) + JOIN alf_attributes a2 ON (ma.attribute_id = a2.id) +; -- (OPTIONAL) +UPDATE t_alf_node_properties + SET actual_type_n = 6, persisted_type_n = 6, serializable_value = NULL + WHERE actual_type_n = -1 AND string_value IS NOT NULL +; +UPDATE t_alf_node_properties + SET actual_type_n = 9, persisted_type_n = 9 + WHERE actual_type_n = -1 AND serializable_value IS NOT NULL +; + +-- Delete the node properties and move the fixed values over +DROP TABLE alf_node_properties; +ALTER TABLE t_alf_node_properties RENAME TO alf_node_properties; + +CREATE TABLE t_del_attributes +( + id number(19,0) NOT NULL, + PRIMARY KEY (id) +); +INSERT INTO t_del_attributes + SELECT id FROM alf_attributes WHERE type = 'M' +; +DELETE + FROM t_del_attributes + WHERE EXISTS + ( + SELECT 1 FROM alf_map_attribute_entries ma WHERE ma.attribute_id = t_del_attributes.id + ) +; +DELETE + FROM t_del_attributes + WHERE EXISTS + ( + SELECT 1 FROM alf_list_attribute_entries la WHERE la.attribute_id = t_del_attributes.id + ) +; +DELETE + FROM t_del_attributes + WHERE EXISTS + ( + SELECT 1 FROM alf_global_attributes ga WHERE ga.attribute = t_del_attributes.id + ) +; +INSERT INTO t_del_attributes + SELECT a.id FROM t_del_attributes t + JOIN alf_map_attribute_entries ma ON (ma.map_id = t.id) + JOIN alf_attributes a ON (ma.attribute_id = a.id) +; +DELETE + FROM alf_map_attribute_entries + WHERE EXISTS + ( + SELECT 1 FROM t_del_attributes t WHERE alf_map_attribute_entries.map_id = t.id + ) +; +DELETE + FROM alf_attributes + WHERE EXISTS + ( + SELECT 1 FROM t_del_attributes t WHERE alf_attributes.id = t.id + ) +; +DROP TABLE t_del_attributes; + +-- ------------------ +-- Final clean up -- +-- ------------------ +DROP TABLE alf_node_status; +ALTER TABLE alf_store DROP CONSTRAINT fk_alf_store_rn; +DROP TABLE alf_node; +ALTER TABLE t_alf_node RENAME TO alf_node; +DROP TABLE alf_store; +ALTER TABLE t_alf_store RENAME TO alf_store; + +-- 2.2.0 ACL fix ups +CREATE INDEX idx_alf_auth_aut ON alf_authority (authority); -- (optional) +ALTER TABLE alf_authority MODIFY (authority VARCHAR(100 char) NULL); -- (optional) + +-- ---------------------------------- +-- Convert alf_attributes to use BLOB +-- ---------------------------------- +-- Changing a column type to a blob disturbs a table's indexes, so we have to rebuild them +ALTER TABLE alf_map_attribute_entries DROP CONSTRAINT fk_alf_matt_att; +ALTER TABLE alf_map_attribute_entries DROP CONSTRAINT fk_alf_matt_matt; +ALTER TABLE alf_global_attributes DROP CONSTRAINT fk_alf_gatt_att; +ALTER TABLE alf_list_attribute_entries DROP CONSTRAINT fk_alf_lent_att; +ALTER TABLE alf_list_attribute_entries DROP CONSTRAINT fk_alf_lent_latt; +ALTER TABLE alf_attributes DROP PRIMARY KEY DROP INDEX; +ALTER TABLE alf_attributes MODIFY (serializable_value BLOB NULL); -- (optional) +ALTER TABLE alf_attributes ADD PRIMARY KEY (id); +ALTER TABLE alf_map_attribute_entries + ADD CONSTRAINT fk_alf_matt_matt FOREIGN KEY (map_id) REFERENCES alf_attributes (id) + ADD CONSTRAINT fk_alf_matt_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id) +; +ALTER TABLE alf_global_attributes + ADD CONSTRAINT fk_alf_gatt_att FOREIGN KEY (attribute) REFERENCES alf_attributes (id) +; +ALTER TABLE alf_list_attribute_entries + ADD CONSTRAINT fk_alf_lent_att FOREIGN KEY (attribute_id) REFERENCES alf_attributes (id) + ADD CONSTRAINT fk_alf_lent_latt FOREIGN KEY (list_id) REFERENCES alf_attributes (id) +; +ALTER INDEX fk_alf_attr_acl REBUILD; + +-- ---------------- +-- JBPM Differences +-- ---------------- +ALTER TABLE jbpm_processinstance DROP UNIQUE (key_, processdefinition_); -- (optional) +CREATE INDEX idx_procin_key ON jbpm_processinstance (key_); -- (optional) + +-- +-- Record script finish +-- +DELETE FROM alf_applied_patch WHERE id = 'patch.db-V2.2-Upgrade-From-2.2SP1'; +INSERT INTO alf_applied_patch + (id, description, fixes_from_schema, fixes_to_schema, applied_to_schema, target_schema, applied_on_date, applied_to_server, was_executed, succeeded, report) + VALUES + ( + 'patch.db-V2.2-Upgrade-From-2.2SP1', 'Manually executed script upgrade V2.2: Upgraded V2.2 SP1 or SP2', + 86, 90, -1, 91, null, 'UNKOWN', 1, 1, 'Script completed' + ); diff --git a/config/alfresco/patch/patch-services-context.xml b/config/alfresco/patch/patch-services-context.xml index ab8f6269aa..3f2545611e 100644 --- a/config/alfresco/patch/patch-services-context.xml +++ b/config/alfresco/patch/patch-services-context.xml @@ -1521,23 +1521,7 @@ - - patch.db-V2.2-OrclBLOB - patch.schemaUpgradeScript.description - 0 - 134 - 135 - - classpath:alfresco/dbscripts/upgrade/2.2/${db.script.dialect}/AlfrescoSchemaUpdate-OrclBLOB.sql - - - - - - - - - + patch.redeploySubmitProcess4 patch.redeploySubmitProcess.description 0 diff --git a/config/alfresco/repository.properties b/config/alfresco/repository.properties index 98ebc23355..df639ee91a 100644 --- a/config/alfresco/repository.properties +++ b/config/alfresco/repository.properties @@ -228,7 +228,7 @@ user.name.caseSensitive=false avm.remote.idlestream.timeout=30000 # ECM content usages/quotas -system.usages.enabled=true +system.usages.enabled=false # Repository endpoint - used by Activity Service repo.remote.endpoint.url=http://localhost:8080/alfresco/service diff --git a/config/alfresco/scheduled-jobs-context.xml b/config/alfresco/scheduled-jobs-context.xml index 0b5ac10ff1..44b5eb0ec2 100644 --- a/config/alfresco/scheduled-jobs-context.xml +++ b/config/alfresco/scheduled-jobs-context.xml @@ -327,10 +327,12 @@ + + 5 @@ -360,9 +362,11 @@ + diff --git a/config/alfresco/usage-services-context.xml b/config/alfresco/usage-services-context.xml index 3c1b2828e6..5e9bb28a49 100644 --- a/config/alfresco/usage-services-context.xml +++ b/config/alfresco/usage-services-context.xml @@ -40,7 +40,7 @@ - + diff --git a/source/java/org/alfresco/repo/site/SiteServiceImpl.java b/source/java/org/alfresco/repo/site/SiteServiceImpl.java index 29335c5a95..d7f99cc3a8 100644 --- a/source/java/org/alfresco/repo/site/SiteServiceImpl.java +++ b/source/java/org/alfresco/repo/site/SiteServiceImpl.java @@ -989,6 +989,7 @@ public class SiteServiceImpl implements SiteService, SiteModel { JSONObject activityData = new JSONObject(); activityData.put("role", role); + activityData.put("memberUserName", userName); activityData.put("memberFirstName", memberFN); activityData.put("memberLastName", memberLN); activityData.put("title", (memberFN + " " + memberLN + " (" + userName + ")").trim());