CRM-14197 set entity_id & entity_table to reflect membership on membership transactions
[civicrm-core.git] / CRM / Upgrade / Incremental / sql / 4.5.alpha1.mysql.tpl
... / ...
CommitLineData
1{* file to handle db changes in 4.5.alpha1 during upgrade *}
2{include file='../CRM/Upgrade/4.5.alpha1.msg_template/civicrm_msg_template.tpl'}
3
4ALTER TABLE `civicrm_contact`
5 ADD COLUMN `formal_title` varchar(64) COMMENT 'Formal (academic or similar) title in front of name. (Prof., Dr. etc.)' AFTER `suffix_id`;
6
7ALTER TABLE `civicrm_contact`
8 ADD COLUMN `communication_style_id` int(10) unsigned COMMENT 'Communication style (e.g. formal vs. familiar) to use with this contact. FK to communication styles in civicrm_option_value.' AFTER `formal_title`,
9 ADD INDEX `index_communication_style_id` (`communication_style_id`);
10
11INSERT INTO
12 `civicrm_option_group` (`name`, {localize field='title'}`title`{/localize}, `is_reserved`, `is_active`)
13VALUES
14 ('communication_style', {localize}'{ts escape="sql"}Communication Style{/ts}'{/localize}, 1, 1);
15
16SELECT @option_group_id_communication_style := max(id) from civicrm_option_group where name = 'communication_style';
17
18INSERT INTO
19 `civicrm_option_value` (`option_group_id`, {localize field='label'}`label`{/localize}, `value`, `name`, `grouping`, `filter`, `is_default`, `weight`, `is_optgroup`, `is_reserved`, `is_active`, `component_id`, `visibility_id`)
20VALUES
21 (@option_group_id_communication_style, {localize}'{ts escape="sql"}Formal{/ts}'{/localize}, 1, 'formal' , NULL, 0, 1, 1, 0, 0, 1, NULL, NULL),
22 (@option_group_id_communication_style, {localize}'{ts escape="sql"}Familiar{/ts}'{/localize}, 2, 'familiar', NULL, 0, 0, 2, 0, 0, 1, NULL, NULL);
23
24-- Insert menu item at Administer > Communications, above the various Greeting Formats
25
26SELECT @parent_id := `id` FROM `civicrm_navigation` WHERE `name` = 'Communications' AND `domain_id` = {$domainID};
27SELECT @add_weight := MIN(`weight`) FROM `civicrm_navigation` WHERE `name` IN('Email Greeting Formats', 'Postal Greeting Formats', 'Addressee Formats') AND `parent_id` = @parent_id;
28
29UPDATE `civicrm_navigation`
30SET `weight` = `weight`+1
31WHERE `parent_id` = @parent_id
32AND `weight` >= @add_weight;
33
34INSERT INTO `civicrm_navigation`
35 ( domain_id, url, label, name, permission, permission_operator, parent_id, is_active, has_separator, weight )
36VALUES
37 ( {$domainID}, 'civicrm/admin/options/communication_style&group=communication_style&reset=1', '{ts escape="sql" skip="true"}Communication Style Options{/ts}', 'Communication Style Options', 'administer CiviCRM', '', @parent_id, '1', NULL, @add_weight );
38
39-- CRM-9988 Change world region of Panama country to America South, Central, North and Caribbean
40UPDATE `civicrm_country` SET `region_id` = 2 WHERE `id` = 1166;
41
42SELECT @option_group_id_contact_edit_options := max(id) from civicrm_option_group where name = 'contact_edit_options';
43
44INSERT INTO
45 `civicrm_option_value` (`option_group_id`, {localize field='label'}`label`{/localize}, `value`, `name`, `grouping`, `filter`, `is_default`, `weight`, `is_optgroup`, `is_reserved`, `is_active`, `component_id`, `visibility_id`)
46VALUES
47 (@option_group_id_contact_edit_options, {localize}'{ts escape="sql"}Prefix{/ts}'{/localize} , 12, 'Prefix' , NULL, 2, NULL, 12, 0, 0, 1, NULL, NULL),
48 (@option_group_id_contact_edit_options, {localize}'{ts escape="sql"}Formal Title{/ts}'{/localize}, 13, 'Formal Title', NULL, 2, NULL, 13, 0, 0, 1, NULL, NULL),
49 (@option_group_id_contact_edit_options, {localize}'{ts escape="sql"}First Name{/ts}'{/localize} , 14, 'First Name' , NULL, 2, NULL, 14, 0, 0, 1, NULL, NULL),
50 (@option_group_id_contact_edit_options, {localize}'{ts escape="sql"}Middle Name{/ts}'{/localize} , 15, 'Middle Name' , NULL, 2, NULL, 15, 0, 0, 1, NULL, NULL),
51 (@option_group_id_contact_edit_options, {localize}'{ts escape="sql"}Last Name{/ts}'{/localize} , 16, 'Last Name' , NULL, 2, NULL, 16, 0, 0, 1, NULL, NULL),
52 (@option_group_id_contact_edit_options, {localize}'{ts escape="sql"}Suffix{/ts}'{/localize} , 17, 'Suffix' , NULL, 2, NULL, 17, 0, 0, 1, NULL, NULL);
53
54-- CRM-13857
55ALTER TABLE civicrm_group
56 ADD COLUMN `modified_id` INT(10) unsigned DEFAULT NULL COMMENT 'FK to contact table, modifier of the group.',
57 ADD CONSTRAINT `FK_civicrm_group_modified_id` FOREIGN KEY (`modified_id`) REFERENCES `civicrm_contact`(`id`) ON DELETE SET NULL;
58
59-- CRM-13913
60ALTER TABLE civicrm_word_replacement
61 ALTER COLUMN `is_active` SET DEFAULT 1;
62
63--CRM-13833 Implement Soft Credit Type for Contribution
64INSERT INTO civicrm_option_group
65 (name, {localize field='title'}title{/localize}, is_reserved, is_active) VALUES ('soft_credit_type', {localize}'{ts escape="sql"}Soft Credit Types{/ts}'{/localize}, 1, 1);
66
67SELECT @option_group_id_soft_credit_type := max(id) from civicrm_option_group where name = 'soft_credit_type';
68
69INSERT INTO `civicrm_option_value` (`option_group_id`, {localize field='label'}`label`{/localize}, `value`, `name`, `weight`, `is_default`, `is_active`, `is_reserved`)
70 VALUES
71 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}In Honor of{/ts}'{/localize}, 1, 'in_honor_of', 1, 0, 1, 1),
72 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}In Memory of{/ts}'{/localize}, 2, 'in_memory_of', 2, 0, 1, 1),
73 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Solicited{/ts}'{/localize}, 3, 'solicited', 3, 0, 1, 1),
74 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Household{/ts}'{/localize}, 4, 'household', 4, 0, 1, 0),
75 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Workplace Giving{/ts}'{/localize}, 5, 'workplace', 5, 0, 1, 0),
76 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Foundation Affiliate{/ts}'{/localize}, 6, 'foundation_affiliate', 6, 0, 1, 0),
77 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}3rd-party Service{/ts}'{/localize}, 7, '3rd-party_service', 7, 0, 1, 0),
78 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Donor-advised Fund{/ts}'{/localize}, 8, 'donor-advised_fund', 8, 0, 1, 0),
79 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Matched Gift{/ts}'{/localize}, 9, 'matched_gift', 9, 0, 1, 0),
80 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Personal Campaign Page{/ts}'{/localize}, 10, 'pcp', 10, 0, 1, 1),
81 (@option_group_id_soft_credit_type , {localize}'{ts escape="sql"}Gift{/ts}'{/localize}, 11, 'gift', 11, 0, 1, 1);
82
83ALTER TABLE `civicrm_contribution_soft`
84 ADD COLUMN `soft_credit_type_id` int(10) unsigned COMMENT 'Soft Credit Type ID.Implicit FK to civicrm_option_value where option_group = soft_credit_type.';
85
86INSERT INTO civicrm_contribution_soft(contribution_id, contact_id, amount, currency, soft_credit_type_id)
87SELECT id, honor_contact_id, total_amount, currency, honor_type_id
88FROM civicrm_contribution
89WHERE honor_contact_id IS NOT NULL;
90
91SELECT @sct_pcp_id := value from civicrm_option_value where name = 'pcp' and option_group_id = @option_group_id_soft_credit_type;
92
93UPDATE `civicrm_contribution_soft`
94SET soft_credit_type_id = @sct_pcp_id
95WHERE pcp_id IS NOT NULL;
96
97--CRM-13734 make basic Case Activity Types reserved
98SELECT @option_group_id_activity_type := id from civicrm_option_group where name = 'activity_type';
99SELECT @caseCompId := id FROM `civicrm_component` where `name` like 'CiviCase';
100
101UPDATE `civicrm_option_value`
102SET is_reserved = 1
103WHERE is_reserved = 0 AND option_group_id = @option_group_id_activity_type AND component_id = @caseCompId;
104
105-- CRM-13912
106ALTER TABLE civicrm_action_schedule
107ADD COLUMN `mode` varchar(128) COLLATE utf8_unicode_ci DEFAULT 'Email' COMMENT 'Send the message as email or sms or both.';
108
109INSERT INTO
110civicrm_option_group (name, {localize field='title'}title{/localize}, is_reserved, is_active)
111VALUES
112('msg_mode', {localize}'{ts escape="sql"}Message Mode{/ts}'{/localize}, 1, 1);
113
114SELECT @option_group_id_msg_mode := max(id) from civicrm_option_group where name = 'msg_mode';
115
116INSERT INTO
117civicrm_option_value (option_group_id, {localize field='label'}`label`{/localize}, value, name, is_default, weight, is_reserved, is_active)
118VALUES
119(@option_group_id_msg_mode, {localize}'{ts escape="sql"}Email{/ts}'{/localize}, 'Email', 'Email', 1, 1, 1, 1),
120(@option_group_id_msg_mode, {localize}'{ts escape="sql"}SMS{/ts}'{/localize},'SMS', 'SMS', 0, 2, 1, 1),
121(@option_group_id_msg_mode, {localize}'{ts escape="sql"}User Preference{/ts}'{/localize}, 'User_Preference', 'User Preference', 0, 3, 1, 1);
122
123ALTER TABLE civicrm_action_schedule ADD sms_provider_id int(10) unsigned NULL COMMENT 'FK to civicrm_sms_provider id ';
124ALTER TABLE civicrm_action_schedule ADD CONSTRAINT FK_civicrm_action_schedule_sms_provider_id FOREIGN KEY (`sms_provider_id`) REFERENCES `civicrm_sms_provider` (`id`) ON DELETE SET NULL;
125
126--CRM-13981 migrate 'In Honor of' to Soft Credits
127INSERT INTO `civicrm_uf_group`
128 (`name`, `group_type`, {localize field='title'}`title`{/localize}, `is_cms_user`, `is_reserved`)
129VALUES
130 ('honoree_individual', 'Individual, Contact', {localize}'{ts escape="sql"}Honoree Individual{/ts}'{/localize}, 0, 1);
131
132SELECT @uf_group_id_honoree_individual := id from civicrm_uf_group where name = 'honoree_individual';
133
134INSERT INTO `civicrm_uf_field`
135 (`uf_group_id`, `field_name`, `is_required`, `is_reserved`, `weight`, `visibility`, `in_selector`, `is_searchable`, `location_type_id`, {localize field='label'}`label`{/localize}, field_type)
136VALUES
137 (@uf_group_id_honoree_individual, 'prefix_id', 0, 1, 1, 'User and User Admin Only', 0, 1, NULL, {localize}'{ts escape="sql"}Individual Prefix{/ts}'{/localize}, 'Individual'),
138 (@uf_group_id_honoree_individual, 'first_name', 0, 1, 2, 'User and User Admin Only', 0, 1, NULL, {localize}'{ts escape="sql"}First Name{/ts}'{/localize}, 'Individual'),
139 (@uf_group_id_honoree_individual, 'last_name', 0, 1, 3, 'User and User Admin Only', 0, 1, NULL, {localize}'{ts escape="sql"}Last Name{/ts}'{/localize}, 'Individual'),
140 (@uf_group_id_honoree_individual, 'email', 0, 1, 4, 'User and User Admin Only', 0, 1, 1, {localize}'{ts escape="sql"}Email Address{/ts}'{/localize}, 'Individual');
141
142UPDATE civicrm_uf_join SET uf_group_id = @uf_group_id_honoree_individual WHERE module = 'soft_credit';
143
144{if $multilingual}
145 {foreach from=$locales item=loc}
146 ALTER TABLE civicrm_contribution_page DROP honor_block_title_{$loc};
147 ALTER TABLE civicrm_contribution_page DROP honor_block_text_{$loc};
148 {/foreach}
149{else}
150 ALTER TABLE civicrm_contribution_page DROP honor_block_title;
151 ALTER TABLE civicrm_contribution_page DROP honor_block_text;
152{/if}
153ALTER TABLE civicrm_contribution_page DROP honor_block_is_active;
154
155ALTER TABLE civicrm_contribution DROP FOREIGN KEY `FK_civicrm_contribution_honor_contact_id`;
156ALTER TABLE civicrm_contribution DROP honor_contact_id;
157ALTER TABLE civicrm_contribution DROP honor_type_id;
158
159ALTER TABLE civicrm_pledge DROP FOREIGN KEY `FK_civicrm_pledge_honor_contact_id`;
160ALTER TABLE civicrm_pledge DROP honor_contact_id;
161ALTER TABLE civicrm_pledge DROP honor_type_id;
162
163-- CRM-13964 and CRM-13965
164SELECT @option_group_id_cs := max(id) from civicrm_option_group where name = 'contribution_status';
165SELECT @option_val_id_cs_wt := MAX(weight) FROM civicrm_option_value WHERE option_group_id = @option_group_id_cs;
166SELECT @option_val_id_cs_val := MAX(value) FROM civicrm_option_value WHERE option_group_id = @option_group_id_cs;
167
168INSERT INTO
169 `civicrm_option_value` (`option_group_id`, {localize field='label'}label{/localize}, `value`, `name`, `grouping`, `filter`, `is_default`, `weight`, `is_optgroup`, `is_reserved`, `is_active`, `component_id`, `visibility_id`)
170VALUES
171 (@option_group_id_cs, {localize}'{ts escape="sql"}Partially paid{/ts}'{/localize}, @option_val_id_cs_val+1, 'Partially paid', NULL, 0, NULL, @option_val_id_cs_wt+1, 0, 1, 1, NULL, NULL),
172 (@option_group_id_cs, {localize}'{ts escape="sql"}Pending refund{/ts}'{/localize}, @option_val_id_cs_val+2, 'Pending refund', NULL, 0, NULL, @option_val_id_cs_wt+2, 0, 1, 1, NULL, NULL);
173
174-- participant status adding
175SELECT @participant_status_wt := max(id) from civicrm_participant_status_type;
176
177INSERT INTO civicrm_participant_status_type (name, {localize field='label'}label{/localize}, class, is_reserved, is_active, is_counted, weight, visibility_id)
178VALUES
179 ('Partially paid', {localize}'{ts escape="sql"}Partially paid{/ts}'{/localize}, 'Positive', 1, 1, 1, @participant_status_wt+1, 2),
180 ('Pending refund', {localize}'{ts escape="sql"}Pending refund{/ts}'{/localize}, 'Positive', 1, 1, 1, @participant_status_wt+2, 2);
181
182-- new activity types required for partial payments
183SELECT @option_group_id_act := max(id) from civicrm_option_group where name = 'activity_type';
184SELECT @option_group_id_act_wt := MAX(weight) FROM civicrm_option_value WHERE option_group_id = @option_group_id_act;
185SELECT @option_group_id_act_val := MAX(value) FROM civicrm_option_value WHERE option_group_id = @option_group_id_act;
186SELECT @contributeCompId := max(id) FROM civicrm_component where name = 'CiviContribute';
187
188INSERT INTO
189 `civicrm_option_value` (`option_group_id`, {localize field='label'}`label`{/localize}, `value`, `name`, `grouping`, `filter`, `is_default`, `weight`, {localize field='description'}`description`{/localize}, `is_optgroup`, `is_reserved`, `is_active`, `component_id`, `visibility_id`)
190VALUES
191 (@option_group_id_act, {localize}'{ts escape="sql"}Payment{/ts}'{/localize}, @option_group_id_act_val+1, 'Payment', NULL, 1, NULL, @option_group_id_act_wt+1, {localize}'{ts escape="sql"}Additional payment recorded for event or membership fee.{/ts}'{/localize}, 0, 1, 1, @contributeCompId, NULL),
192 (@option_group_id_act, {localize}'{ts escape="sql"}Refund{/ts}'{/localize}, @option_group_id_act_val+2, 'Refund', NULL, 1, NULL, @option_group_id_act_wt+2, {localize}'{ts escape="sql"}Refund recorded for event or membership fee.{/ts}'{/localize}, 0, 1, 1, @contributeCompId, NULL),
193 (@option_group_id_act, {localize}'{ts escape="sql"}Change Registration{/ts}'{/localize}, @option_group_id_act_val+3, 'Change Registration', NULL, 1, NULL, @option_group_id_act_wt+3, {localize}'{ts escape="sql"}Changes to an existing event registration.{/ts}'{/localize}, 0, 1, 1, @eventCompId, NULL);
194
195-- CRM-13970
196UPDATE civicrm_navigation set url = 'civicrm/admin/options/from_email_address&reset=1' WHERE url LIKE 'civicrm/admin/options/from_email%';
197UPDATE civicrm_navigation set url = CONCAT(SUBSTRING_INDEX(url, '&', 1), '&reset=1') WHERE url LIKE 'civicrm/admin/options/%';
198
199-- CRM-14181
200ALTER TABLE civicrm_acl CHANGE operation operation VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL COMMENT 'What operation does this ACL entry control?';
201ALTER TABLE civicrm_campaign_group CHANGE group_type group_type VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Type of Group.';
202ALTER TABLE `civicrm_acl_contact_cache` CHANGE `operation` `operation` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL COMMENT 'What operation does this user have permission on?';
203ALTER TABLE `civicrm_price_field` CHANGE `html_type` `html_type` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL;
204ALTER TABLE `civicrm_pledge` CHANGE `frequency_unit` `frequency_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'month' COMMENT 'Time units for recurrence of pledge payments.';
205ALTER TABLE `civicrm_membership_type` CHANGE `duration_unit` `duration_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Unit in which membership period is expressed.';
206ALTER TABLE `civicrm_membership_type` CHANGE `period_type` `period_type` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Rolling membership period starts on signup date. Fixed membership periods start on fixed_period_start_day.';
207ALTER TABLE `civicrm_membership_status` CHANGE `start_event` `start_event` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Event when this status starts.';
208ALTER TABLE `civicrm_membership_status` CHANGE `start_event_adjust_unit` `start_event_adjust_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Unit used for adjusting from start_event.';
209ALTER TABLE `civicrm_membership_status` CHANGE `end_event` `end_event` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Event after which this status ends.';
210ALTER TABLE `civicrm_membership_status` CHANGE `end_event_adjust_unit` `end_event_adjust_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Unit used for adjusting from the ending event.';
211ALTER TABLE `civicrm_mailing_job` CHANGE `status` `status` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'The state of this job';
212ALTER TABLE `civicrm_mailing_group` CHANGE `group_type` `group_type` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Are the members of the group included or excluded?.';
213ALTER TABLE `civicrm_mailing` CHANGE `visibility` `visibility` VARCHAR( 40 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'User and User Admin Only' COMMENT 'In what context(s) is the mailing contents visible (online viewing)';
214ALTER TABLE `civicrm_mailing_component` CHANGE `component_type` `component_type` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Type of Component.';
215ALTER TABLE `civicrm_mailing_bounce_type` CHANGE `name` `name` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL COMMENT 'Type of bounce';
216ALTER TABLE `civicrm_participant_status_type` CHANGE `class` `class` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'the general group of status type this one belongs to';
217ALTER TABLE `civicrm_dedupe_rule_group` CHANGE `contact_type` `contact_type` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'The type of contacts this group applies to';
218ALTER TABLE `civicrm_dedupe_rule_group` CHANGE `used` `used` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL COMMENT 'Whether the rule should be used for cases where usage is Unsupervised, Supervised OR General(programatically)';
219ALTER TABLE `civicrm_word_replacement` CHANGE `match_type` `match_type` VARCHAR( 16 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'wildcardMatch';
220ALTER TABLE `civicrm_uf_field` CHANGE `visibility` `visibility` VARCHAR( 32 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'User and User Admin Only' COMMENT 'In what context(s) is this field visible.';
221ALTER TABLE `civicrm_mapping_field` CHANGE `operator` `operator` VARCHAR( 16 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'SQL WHERE operator for search-builder mapping fields (search criteria).';
222ALTER TABLE `civicrm_job` CHANGE `run_frequency` `run_frequency` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'Daily' COMMENT 'Scheduled job run frequency.';
223ALTER TABLE `civicrm_extension` CHANGE `type` `type` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL;
224ALTER TABLE `civicrm_custom_group` CHANGE `style` `style` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Visual relationship between this form and its parent.';
225ALTER TABLE `civicrm_custom_field` CHANGE `data_type` `data_type` VARCHAR( 16 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL COMMENT 'Controls location of data storage in extended_data table.';
226ALTER TABLE `civicrm_custom_field` CHANGE `html_type` `html_type` VARCHAR( 32 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL COMMENT 'HTML types plus several built-in extended types.';
227ALTER TABLE `civicrm_action_schedule` CHANGE `start_action_unit` `start_action_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Time units for reminder.';
228ALTER TABLE `civicrm_action_schedule` CHANGE `repetition_frequency_unit` `repetition_frequency_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Time units for repetition of reminder.';
229ALTER TABLE `civicrm_action_schedule` CHANGE `end_frequency_unit` `end_frequency_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'Time units till repetition of reminder.';
230ALTER TABLE `civicrm_product` CHANGE `period_type` `period_type` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'rolling' COMMENT 'Rolling means we set start/end based on current day, fixed means we set start/end for current year or month(e.g. 1 year + fixed -> we would set start/end for 1/1/06 thru 12/31/06 for any premium chosen in 2006) ';
231ALTER TABLE `civicrm_product` CHANGE `duration_unit` `duration_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'year';
232ALTER TABLE `civicrm_product` CHANGE `frequency_unit` `frequency_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'month' COMMENT 'Frequency unit and interval allow option to store actual delivery frequency for a subscription or service.';
233ALTER TABLE `civicrm_contribution_recur` CHANGE `frequency_unit` `frequency_unit` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'month' COMMENT 'Time units for recurrence of payment.';
234ALTER TABLE `civicrm_subscription_history` CHANGE `method` `method` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'How the (un)subscription was triggered';
235ALTER TABLE `civicrm_subscription_history` CHANGE `status` `status` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'The state of the contact within the group';
236ALTER TABLE `civicrm_relationship_type` CHANGE `contact_type_a` `contact_type_a` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'If defined, contact_a in a relationship of this type must be a specific contact_type.';
237ALTER TABLE `civicrm_relationship_type` CHANGE `contact_type_b` `contact_type_b` VARCHAR( 12 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'If defined, contact_b in a relationship of this type must be a specific contact_type.';
238ALTER TABLE `civicrm_group_contact` CHANGE `status` `status` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL COMMENT 'status of contact relative to membership in group';
239ALTER TABLE `civicrm_group` CHANGE `visibility` `visibility` VARCHAR( 24 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'User and User Admin Only' COMMENT 'In what context(s) is this field visible.';
240ALTER TABLE `civicrm_contact` CHANGE `preferred_mail_format` `preferred_mail_format` VARCHAR( 8 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT 'Both' COMMENT 'What is the preferred mode of sending an email.';
241
242-- CRM-14183
243INSERT INTO civicrm_state_province (country_id, abbreviation, name) VALUES (1157, "PL", "Plateau");
244UPDATE civicrm_state_province SET name = "Abuja Federal Capital Territory" WHERE name = "Abuja Capital Territory";
245
246-- CRM-13992
247ALTER TABLE `civicrm_custom_field`
248 ADD COLUMN `in_selector` tinyint(4) DEFAULT '0' COMMENT 'Should the multi-record custom field values be displayed in tab table listing';
249UPDATE civicrm_custom_field cf
250 LEFT JOIN civicrm_custom_group cg
251 ON cf.custom_group_id = cg.id
252 SET cf.in_selector = 1
253 WHERE cg.is_multiple = 1 AND cf.html_type != 'TextArea';
254ALTER TABLE `civicrm_custom_group`
255 CHANGE COLUMN `style` `style` varchar(15) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT 'Visual relationship between this form and its parent.';
256
257-- Add "developer" help menu
258SELECT @parent_id := `id` FROM `civicrm_navigation` WHERE `name` = 'Help' AND `domain_id` = {$domainID};
259
260INSERT INTO civicrm_navigation
261( domain_id, url, label, name, permission, permission_operator, parent_id, is_active, has_separator, weight )
262VALUES
263( {$domainID}, NULL, '{ts escape="sql" skip="true"}Developer{/ts}', 'Developer', 'administer CiviCRM', '', @parent_id, '1', NULL, 5 );
264
265SET @devellastID:=LAST_INSERT_ID();
266INSERT INTO civicrm_navigation
267( domain_id, url, label, name, permission, permission_operator, parent_id, is_active, has_separator, weight )
268VALUES
269( {$domainID}, 'civicrm/api/explorer', '{ts escape="sql" skip="true"}API Explorer{/ts}','API Explorer', 'administer CiviCRM', '', @devellastID, '1', NULL, 1 ),
270( {$domainID}, 'http://wiki.civicrm.org/confluence/display/CRMDOC/Develop', '{ts escape="sql" skip="true"}Developer Docs{/ts}', 'Developer Docs', 'administer CiviCRM', '', @devellastID, '1', NULL, 3 );
271
272-- CRM-14435
273ALTER TABLE `civicrm_mail_settings`
274 ADD CONSTRAINT `FK_civicrm_mail_settings_domain_id` FOREIGN KEY (`domain_id`) REFERENCES `civicrm_domain` (`id`) ON DELETE CASCADE;
275
276-- CRM-14436
277ALTER TABLE `civicrm_mailing`
278 ADD COLUMN `hash` varchar(16) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT 'Key for validating requests related to this mailing.',
279 ADD INDEX `index_hash` (`hash`);
280
281-- CRM-14300
282UPDATE `civicrm_event` SET is_template = 0 WHERE is_template IS NULL;
283ALTER TABLE `civicrm_event`
284 CHANGE is_template is_template tinyint(4) DEFAULT '0' COMMENT 'whether the event has template';
285
286-- CRM-14493
287INSERT INTO civicrm_state_province (country_id, abbreviation, name) VALUES (1085, "61", "Pieria");
288
289-- CRM-14445
290ALTER TABLE `civicrm_option_group`
291 ADD COLUMN `is_locked` int(1) DEFAULT 0 COMMENT 'A lock to remove the ability to add new options via the UI';
292
293UPDATE `civicrm_option_group` SET is_locked = 1 WHERE name IN ('contribution_status','activity_contacts','advanced_search_options','auto_renew_options','contact_autocomplete_options','batch_status','batch_type','batch_mode','contact_edit_options','contact_reference_options','contact_smart_group_display','contact_view_options','financial_item_status','mapping_type','pcp_status','user_dashboard_options','tag_used_for');
294
295-- CRM-14449
296CREATE TABLE IF NOT EXISTS `civicrm_system_log` (
297`id` INT(11) NOT NULL AUTO_INCREMENT COMMENT 'Primary Key: ID.',
298`message` VARCHAR(128) NOT NULL COMMENT 'Standardized message',
299`context` LONGTEXT NULL COMMENT 'JSON encoded data',
300`level` VARCHAR(9) NOT NULL DEFAULT 'info' COMMENT 'error level per PSR3',
301`timestamp` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Timestamp of when event occurred.',
302`contact_id` INT(11) NULL DEFAULT NULL COMMENT 'Optional Contact ID that created the log. Not an FK as we keep this regardless',
303 hostname VARCHAR(128) NOT NULL COMMENT 'Optional Name of logging host',
304PRIMARY KEY (`id`),
305INDEX `message` (`message`),
306INDEX `contact_id` (`contact_id`),
307INDEX `level` (`level`)
308)
309COMMENT='Table that contains logs of all system events.'
310COLLATE='utf8_general_ci';
311
312-- CRM-14473 civicrm_case_type table creation and migration
313CREATE TABLE IF NOT EXISTS `civicrm_case_type` (
314 `id` int(10) unsigned NOT NULL AUTO_INCREMENT COMMENT 'Autoincremented type id',
315 `name` varchar(64) COLLATE utf8_unicode_ci NOT NULL COMMENT 'Machine name for Case Type',
316 {localize field='title'}title varchar(64) COLLATE utf8_unicode_ci NOT NULL COMMENT 'Natural language name for Case Type'{/localize},
317 {localize field='description'}description varchar(255) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT 'Description of the Case Type'{/localize},
318 `is_active` tinyint(4) DEFAULT NULL COMMENT 'Is this entry active?',
319 `is_reserved` tinyint(4) DEFAULT NULL COMMENT 'Is this case type a predefined system type?',
320 `weight` int(11) NOT NULL DEFAULT '1' COMMENT 'Ordering of the case types',
321 `xml_definition` blob COMMENT 'xml definition of case type',
322 PRIMARY KEY (`id`),
323 UNIQUE KEY `case_type_name` (`name`)
324) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1;
325
326SELECT @option_group_id_case_type := max(id) from civicrm_option_group where name = 'case_type';
327
328INSERT IGNORE INTO civicrm_case_type
329 (name, {localize field='title'}title{/localize}, {localize field='description'}description{/localize}, is_active, is_reserved, weight)
330 SELECT
331 name,
332 {localize field='label'}label{/localize},
333 {localize field='description'}description{/localize},
334 is_active,
335 is_reserved,
336 weight
337 FROM civicrm_option_value
338 WHERE
339 option_group_id = @option_group_id_case_type;
340
341-- Replace the pseudo-fk to ov.value with a reference to civicrm_case_type.id
342UPDATE civicrm_case
343 SET case_type_id = (
344 SELECT civicrm_case_type.id FROM civicrm_case_type
345 JOIN civicrm_option_value
346 ON civicrm_option_value.name = civicrm_case_type.name
347 WHERE
348 civicrm_option_value.option_group_id = @option_group_id_case_type
349 AND civicrm_option_value.value = replace(civicrm_case.case_type_id, 0x01, '')
350 );
351
352ALTER TABLE civicrm_case
353 MODIFY case_type_id int(10) unsigned COLLATE utf8_unicode_ci NULL COMMENT 'FK to civicrm_case_type.id',
354 ADD CONSTRAINT FK_civicrm_case_case_type_id FOREIGN KEY (case_type_id) REFERENCES civicrm_case_type (id) ON DELETE SET NULL;
355
356DELETE FROM civicrm_option_value WHERE option_group_id = @option_group_id_case_type;
357
358DELETE FROM civicrm_option_group WHERE id = @option_group_id_case_type;
359
360-- CRM-14611
361{if $multilingual}
362 {foreach from=$locales item=locale}
363 ALTER TABLE civicrm_survey ADD title_{$locale} varchar(255);
364 UPDATE civicrm_survey SET title_{$locale} = title;
365
366 ALTER TABLE civicrm_survey ADD instructions_{$locale} TEXT;
367 UPDATE civicrm_survey SET instructions_{$locale} = instructions;
368 {/foreach}
369
370 ALTER TABLE civicrm_survey DROP title;
371 ALTER TABLE civicrm_survey DROP instructions;
372{/if}
373
374-- CRM-11182 -- Make event confirmation page optional
375 ALTER TABLE civicrm_event
376 ADD COLUMN is_confirm_enabled tinyint(4) DEFAULT '1';
377
378 UPDATE civicrm_event
379 SET is_confirm_enabled = 1
380 WHERE is_monetary = 1;
381
382 UPDATE civicrm_event
383 SET is_confirm_enabled = 0
384 WHERE is_monetary = 0;
385
386-- CRM-11182
387ALTER TABLE civicrm_event
388 ADD COLUMN dedupe_rule_group_id int(10) unsigned DEFAULT NULL COMMENT 'Rule to use when matching registrations for this event',
389 ADD CONSTRAINT `FK_civicrm_event_dedupe_rule_group_id` FOREIGN KEY (`dedupe_rule_group_id`) REFERENCES `civicrm_dedupe_rule_group` (`id`);
390
391-- CRM-9288
392SELECT @option_web_id := id FROM civicrm_option_group WHERE name = 'website_type';
393
394SELECT @website_default := value FROM civicrm_option_value WHERE option_group_id = @option_web_id and is_default = 1;
395
396SELECT @website_work := value FROM civicrm_option_value WHERE option_group_id = @option_web_id and name= 'Work';
397
398UPDATE civicrm_option_value
399SET is_default = 1 WHERE option_group_id = @option_web_id and value = IFNULL(@website_default , @website_work);
400
401SELECT @website_default := value FROM civicrm_option_value WHERE option_group_id = @option_web_id and is_default = 1;
402
403ALTER TABLE civicrm_uf_field
404 ADD COLUMN `website_type_id` int(10) unsigned DEFAULT NULL COMMENT 'Website Type Id, if required' AFTER phone_type_id,
405 ADD INDEX `IX_website_type_id` (`website_type_id`);
406
407UPDATE civicrm_uf_field
408SET website_type_id = @website_default,
409field_name = 'url' WHERE field_name LIKE 'url%';
410
411SELECT @website_value := max(cast(value as UNSIGNED)) FROM civicrm_option_value WHERE option_group_id = @option_web_id;
412SELECT @website_weight := max(weight) FROM civicrm_option_value WHERE option_group_id = @option_web_id;
413
414INSERT INTO civicrm_option_value(option_group_id, {localize field='label'}label{/localize}, name, value, weight)
415SELECT @option_web_id, {localize}website{/localize}, website, (@website_value := @website_value + 1), (@website_weight := @website_weight + 1) FROM (
416SELECT 'Google+' AS website
417 UNION ALL
418SELECT 'Instagram' AS website
419 UNION ALL
420SELECT 'LinkedIn' AS website
421 UNION ALL
422SELECT 'Pinterest' AS website
423 UNION ALL
424SELECT 'Tumblr' AS website
425 UNION ALL
426SELECT 'SnapChat' AS website
427 UNION ALL
428SELECT 'Vine' AS website
429) AS temp
430LEFT JOIN civicrm_option_value co ON LOWER(co.name) = LOWER(temp.website)
431AND option_group_id = @option_web_id
432WHERE co.id IS NULL;
433
434-- CRM-14627 civicrm navigation inconsistent
435UPDATE civicrm_navigation
436SET civicrm_navigation.url = CONCAT(SUBSTRING(url FROM 1 FOR LOCATE('&', url) - 1), '?', SUBSTRING(url FROM LOCATE('&', url) + 1))
437WHERE civicrm_navigation.url LIKE "%&%" AND civicrm_navigation.url NOT LIKE "%?%";
438
439-- CRM-14639
440
441SELECT @option_grant_status := id FROM civicrm_option_group WHERE name = 'grant_status';
442UPDATE civicrm_option_value
443SET
444{if !$multilingual}
445 label =
446 CASE
447 WHEN lower(name) = 'granted'
448 THEN 'Paid'
449 WHEN lower(name) = 'approved'
450 THEN 'Eligible'
451 WHEN lower(name) = 'rejected'
452 THEN 'Ineligible'
453 ELSE 'Submitted'
454 END,
455{else}
456 {foreach from=$locales item=locale}
457 label_{$locale} =
458 CASE
459 WHEN lower(name) = 'granted'
460 THEN 'Paid'
461 WHEN lower(name) = 'approved'
462 THEN 'Eligible'
463 WHEN lower(name) = 'rejected'
464 THEN 'Ineligible'
465 ELSE 'Submitted'
466 END,
467 {/foreach}
468{/if}
469name =
470CASE
471 WHEN lower(name) = 'granted'
472 THEN 'Paid'
473 WHEN lower(name) = 'approved'
474 THEN 'Eligible'
475 WHEN lower(name) = 'rejected'
476 THEN 'Ineligible'
477 ELSE 'Submitted'
478END
479WHERE option_group_id = @option_grant_status and LOWER(name) IN ('granted', 'pending', 'approved', 'rejected');
480
481SELECT @grant_value := max(cast(value as UNSIGNED)) FROM civicrm_option_value WHERE option_group_id = @option_grant_status;
482SELECT @grant_weight := max(weight) FROM civicrm_option_value WHERE option_group_id = @option_grant_status;
483
484INSERT INTO civicrm_option_value(option_group_id, {localize field='label'}label{/localize}, name, value, weight)
485SELECT @option_grant_status, {localize}grantstatus{/localize}, grantstatus, @grant_value := @grant_value + 1, @grant_weight := @grant_weight + 1 FROM (
486SELECT 'Submitted' AS grantstatus
487 UNION ALL
488SELECT 'Approved for Payment' AS grantstatus
489 UNION ALL
490SELECT 'Eligible' AS grantstatus
491 UNION ALL
492SELECT 'Awaiting Information' AS grantstatus
493 UNION ALL
494SELECT 'Withdrawn' AS grantstatus
495) AS temp
496LEFT JOIN civicrm_option_value co ON LOWER(co.name) = LOWER(temp.grantstatus)
497AND option_group_id = @option_grant_status
498WHERE co.id IS NULL;
499
500-- Fix trailing single quote in grant status label
501{if !$multilingual}
502 UPDATE civicrm_option_value v
503 INNER JOIN civicrm_option_group g
504 ON v.option_group_id = g.id AND g.name = 'grant_status'
505 SET label = 'Awaiting Information'
506 WHERE v.label = 'Awaiting Information\'' and v.name = 'Awaiting Information';
507{else}
508 UPDATE civicrm_option_value v
509 INNER JOIN civicrm_option_group g
510 ON v.option_group_id = g.id AND g.name = 'grant_status'
511 SET
512 {foreach from=$locales item=locale}
513 v.label_{$locale} = CASE
514 WHEN v.label_{$locale} = 'Awaiting Information\'' THEN 'Awaiting Information'
515 ELSE v.label_{$locale}
516 END,
517 {/foreach}
518 v.name = v.name
519 WHERE v.name = 'Awaiting Information';
520{/if}
521
522-- CRM-14197 Add contribution_id to civicrm_line_item
523
524ALTER TABLE civicrm_line_item ADD contribution_id INT(10) COMMENT 'Contribution ID' NULL AFTER entity_id;
525
526-- FK to civicrm_contribution
527
528ALTER TABLE civicrm_line_item
529ADD CONSTRAINT `FK_civicrm_contribution_id` FOREIGN KEY (`contribution_id`) REFERENCES civicrm_contribution (`id`) ON DELETE SET NULL;
530
531-- store contribution id for participant records
532UPDATE civicrm_line_item li LEFT JOIN civicrm_participant_payment pp ON pp.participant_id = li.entity_id
533SET li.contribution_id = pp.contribution_id
534WHERE li.entity_table = 'civicrm_participant';
535
536-- update membership line items to hold correct entity table & id & contribution id
537UPDATE civicrm_line_item li
538LEFT JOIN civicrm_membership_payment mp ON mp.contribution_id = li.entity_id
539LEFT JOIN civicrm_price_field_value pv ON pv.id = li.price_field_value_id
540SET li.entity_table = 'civicrm_membership', li.contribution_id = mp.contribution_id, li.entity_id = mp.membership_id
541WHERE li.entity_table = 'civicrm_contribution'
542AND pv.membership_type_id IS NOT NULL
543AND membership_id IS NOT NULL;
544
545-- update line items for contributions with contribution id
546UPDATE civicrm_line_item
547SET contribution_id = entity_id
548WHERE contribution_id IS NULL;
549