Project

General

Profile

Exporting Raisers Edge for CiviCRM » History » Version 16

Jon Goldberg, 06/08/2018 08:10 PM

1 5 Jon Goldberg
{{last_updated_at}} by {{last_updated_by}}
2 1 Jon Goldberg
3
{{>toc}}
4
5
# Exporting Raiser's Edge for CiviCRM
6
7
8
There are two basic approaches to exporting RE data.  There's the built-in export tool, and there's direct SQL interaction.  This document will try to cover both approaches where possible.  The Export tool has a lower barrier to entry, but a) there's some data you can't export with the tool, and b) the data will be denormalized, requiring additional transformation compared to extracting normalized SQL data.
9
10
Note that there's a good video on this topic by Young-Jin from Emphanos, LLC, here: http://sf2013.civicrm.org/migrating-raisers-edge-civicrm
11
12
##  Do you use Pentaho Kettle?
13
14
If so, you can use my Raiser's Edge to CiviCRM transforms, available here: https://github.com/PalanteJon/civicrm_kettle_transforms
15
16
## Export tool - general guide.
17
18
The Raiser's Edge Export tool is on the left toolbar when you first enter Raiser's Edge.
19
20
From the tool, you will create a number of exports.  When you first create an export, you'll be asked a number of questions, including Export Type (Constituent, Gift, etc.), a checkbox to include inactive records (check this), and an export file type (select CSV).
21
22
For most export, select Constituent as the Export type.  This is the "base table" - all records will be joined relative to it.
23
24
## Constituent Based Exports
25
26
### Contact Information
27
28
RE differentiates between constituents and non-constituents in their system.  If you create a new contact, they're a constituent - but then you might decide to add a spouse or employer record, which is NOT considered a constituent, and doesn't show up in most queries.  Notably, non-constituents aren't exported when using the Export tool and your base table is "Constituent".
29
30
### SQL
31
32
If extracting directly from SQL, `SELECT * FROM RECORDS`.
33
34
Note that you can extract only constituents by adding `WHERE IS_CONSTITUENT = -1`.  For a Civi migration, I recommend importing all contacts.
35
36
### Export tool (NOTE: This ONLY gets constituents).
37
38
Tab 1. General:
39
- Include all records.
40
- Head of Household processing: Export both constituents separately.
41
- Check all of the "Include these Constitutents": Inactive, deceased, no valid address
42
43
Tab 2: Output.
44
First, expand the "Constituent Information" in the left pane, and add every field to the export.  Do the export (as a CSV).
45
46
### Constituent Codes
47
48
In RE: Found at the bottom of the "Bio 2" tab.
49
In SQL: CONSTITUENT_CODES maps to "GroupContact".  TABLEENTRIES stores the codes ("groups").  In my case, `SELECT *  FROM [CCR_July_snapshot].[dbo].[TABLEENTRIES] WHERE [CODETABLESID] = 43` did the trick.  YMMV - see "deciphering stored procedures" below.
50
51
Export as _one to many_, below.
52
These map to "groups" in Civi - can also be mapped to "tags" if you don't need to track the begin/end date on them.
53
54
No need to export these fields:
55
System Record ID
56
Import ID
57
As of Civi 4.4.6, there's no way to import Group Begin/End dates via API, you need to do it via direct SQL.
58
59
### Solicit Codes
60
61
These can map to groups - but also may map to privacy preferences or custom fields (e.g. Email Only, Do Not Solicit)
62
63
SQL to extract solicit codes:
64 7 Jon Goldberg
```sql
65
SELECT RECORDSID AS external_identifier, LONGDESCRIPTION as solicit_code 
66
FROM CONSTITUENT_SOLICITCODES JOIN TABLEENTRIES ON SOLICIT_CODE = TABLEENTRIES.TABLEENTRIESID 
67
WHERE TABLEENTRIES.ACTIVE = -1
68 1 Jon Goldberg
```
69
70
In my copy of RE, the CODETABLESID is 5044, so to get a list of all solicit codes, use:
71 7 Jon Goldberg
```sql
72
SELECT LONGDESCRIPTION, ACTIVE 
73
FROM TABLEENTRIES 
74
WHERE CODETABLESID = 5044 
75
ORDER BY SEQUENCE;
76 1 Jon Goldberg
```
77
78
### Addresses
79
80
SQL tables: ADDRESS, CONSTIT_ADDRESS
81
82 2 Jon Goldberg
Addresses are a many-to-many relationship in RE.
83
Not all addresses in the database are visible in RE.  Addresses where the `INDICATOR` field is 1 or 7, for instance.  Make sure to look your data over and filter those out accordingly.  Alternatively, you may want to handle them by creating address sharing in Civi.
84
85
Source: http://www.kb.blackbaud.co.uk/articles/Article/41141
86
The address Indicator field is located on the CONSTIT_ADDRESS table and can have the following values: 
87
~~~
88
0 = Alternate
89
1 = Contact
90
2 = Preferred (Primary Address entered on the Bio 1 tab of the constituent record)
91
3 = Business
92
4 = Spouse Business
93
5 = Spouse Preferred
94
6 = Spouse Alternate
95
7 = Relationship
96
~~~
97 3 Jon Goldberg
98
`CONSTIT_ADDRESS.TYPE` and `CONSTIT_ADDRESS.INDICATOR` both have a bearing on location type.  `TYPE` is what appears in the RE UI; however it's calculated based on the indicator.  An indicator of `3` is always a shared address from the relationship to "primary business information".  Adding a work address manually will always give an indicator of `2` if preferred or `0` otherwise.
99 4 Jon Goldberg
100
When you create an address on a related non-constituent, the address's `CONSTIT_ID` is actually the constituent's!  E.g. if John Doe works for Acme Corp, an address added to Acme Corp will have John Doe's `CONSTIT_ID`.  Even more confusing, a blank address with the Acme Corp `CONSTIT_ID` will be created.  To decipher this, you need to look at the `CONSTIT_RELATIONSHIPS.CONSTIT_ADDRESS_ID` field.
101
102
Here's the SQL I use for getting address data in Kettle:
103
104
~~~sql
105
SELECT
106
  ADDRESS_BLOCK
107
, CITY
108
, POST_CODE
109
, "STATE"
110
, CTY.LONGDESCRIPTION as country
111
, ADDRESS_ID
112
, ca.CONSTIT_ID
113
, PREFERRED
114
, LOC_TYPE.LONGDESCRIPTION
115
, ca.DATE_FROM
116
, ca.DATE_TO
117
, SENDMAIL
118
, ca.ID AS CAID
119
, cr.IS_EMPLOYEE
120
, cr.IS_PRIMARY AS IS_RELATIONSHIP_PRIMARY
121
, cr.RELATION_ID
122
, ca.INDICATOR
123
FROM ADDRESS a
124
LEFT JOIN TABLEENTRIES AS CTY ON CTY.TABLEENTRIESID = COUNTRY
125
JOIN CONSTIT_ADDRESS ca ON a.ID = ca.ADDRESS_ID
126
LEFT JOIN TABLEENTRIES AS LOC_TYPE ON ca."TYPE" = LOC_TYPE.TABLEENTRIESID
127
LEFT JOIN RECORDS r ON ca.CONSTIT_ID = r.ID
128
-- This next join is needed to handle address sharing with the business
129
LEFT JOIN CONSTIT_RELATIONSHIPS cr ON ca.ID = cr.CONSTIT_ADDRESS_ID AND ca.CONSTIT_ID = cr.CONSTIT_ID
130
WHERE INDICATOR <> 7 AND ADDRESS_BLOCK IS NOT NULL
131
~~~
132 2 Jon Goldberg
133
### Primary Business Information 
134 1 Jon Goldberg
From "Bio 1", if you press the "Business" button, you can add a related business and its address - but if you check the "Primary Business Information" box, the address will actually have a `CONSTIT_ID` tied to the original contact.  Very confusing!  To properly migrate this address, you'll need to link the address using the `CONSTIT_RELATIONSHIP` table.
135
136
### Phones/E-mail/websites
137 6 Jon Goldberg
138 1 Jon Goldberg
Email and websites are stored in the `PHONES` table along with phone numbers.
139 6 Jon Goldberg
140
In older versions of RE (possibly up to 7.93), phones were tied to addresses, not contacts.  In current versions this is no longer true, but the fields are still present, which is a red herring.
141 1 Jon Goldberg
142
Notes:
143
* You can NOT have duplicate phone types in RE, so no need to try and catch multiple "Home" numbers!
144
* Oh - except that one contact can have two home phone numbers on two different addresses.
145
* Don't forget to filter out duplicate numbers/e-mails/etc. when someone puts the same phone number on two different addresses.
146 6 Jon Goldberg
147
This SQL gets me a useful list of phones and e-mail for further processing in Kettle (for RE 7.96):
148
149 1 Jon Goldberg
```sql
150 6 Jon Goldberg
SELECT DISTINCT
151 1 Jon Goldberg
PHONES.CONSTIT_ID
152
, NUM
153 6 Jon Goldberg
, DO_NOT_CALL
154
, LONGDESCRIPTION AS location_type
155
, PHONES."SEQUENCE"
156
, PHONES.PHONESID
157
FROM PHONES
158
LEFT JOIN TABLEENTRIES ON PHONETYPEID = TABLEENTRIESID
159
LEFT JOIN RECORDS r ON r.ID = PHONES.CONSTIT_ID
160
WHERE PHONES.INACTIVE = 0
161
AND CONSTIT_RELATIONSHIPS_ID IS NULL
162
--Sequence so we get primary number correct
163 1 Jon Goldberg
ORDER BY PHONES.PHONESID, PHONES."SEQUENCE"
164
```
165
166
### Relationships
167
168
Relevant SQL table: CONSTIT_RELATIONSHIPS
169
170
Relationships are different in Civi and RE in the following significant ways:
171
* Relationships don't have to have a relationship type.
172
* The A-B relationship doesn't have to have the same relationship type as B-A (e.g. if my relationship is "parent", the reciprocal relationship could be "son" or "daughter".
173
* Related contacts need not have their own constituent record (though they can).  If they don't have their own constituent record, they nevertheless have a record in RECORDS, they're just not a constituent.
174
* There need not be a relationship type at all.  This doesn't make sense, except that:
175
* There are hardcoded fields for IS_SPOUSE, HON_MEM_ACKNOWLEDGE, IS_HEADOFHOUSEHOLD, and SOFTCREDIT_GIFTS.
176
177
Because relationships aren't necessarily reciprocal, I find it helpful to take my list of invalid relationships and do BOTH of the following:
178
* Look up the RELATIONSHIP_TYPE against the `name_b_a` field in `civicrm_relationship_type`.
179
* Look up the RECIP_RELATIONSHIP_TYPE against both `name_a_b` and `name_b_a` in `civicrm_relationship_type`.
180
181
### Solicitor Relationships
182
183
Solicitor relationships are stored in a different table.  I used this SQL to extract them:
184 8 Jon Goldberg
```sql
185 1 Jon Goldberg
SELECT
186
CONSTIT_ID
187
, SOLICITOR_ID
188
, TABLEENTRIES.LONGDESCRIPTION as solicitor_type
189
, AMOUNT
190
, NOTES
191
, cs."SEQUENCE" as weight
192
FROM CONSTIT_SOLICITORS cs
193
LEFT JOIN TABLEENTRIES ON cs.SOLICITOR_TYPE = TABLEENTRIES.TABLEENTRIESID
194
ORDER BY weight
195
```
196
197
### Attributes
198
199
Attributes are the RE equivalent of custom fields.  However, unlike custom fields, they can also have a "date" value and a "comments" value.  While this can be replicated in Civi via multi-record custom field groups, ideally the data is evaluated attribute by attribute.
200
201
Valuable information about the setup of the attributes is available in RE from *Config > Attributes*.
202
203
* The analogous field to `civicrm_custom_field` is `AttributeTypes`.
204
* `AttributeTypes.CODETABLESID` gives a lookup for the RE "option group" that contains valid options for that attribute.
205
* All constituent attribute data is stored in the table `ConstituentAttributes`.  Note that it's stored in a Key-Value Pair-style table - you'll need to do a bunch of SQL queries, or run a Kettle "Row Denormaliser" step to get this data in order.
206
 
207
Here's my preliminary SQL to export attributes from RE:
208 9 Jon Goldberg
```sql
209 1 Jon Goldberg
SELECT
210
ca.PARENTID as external_identifier
211
, ca.ATTRIBUTETYPESID
212
, at.DESCRIPTION as Category
213
, TABLEENTRIES.LONGDESCRIPTION as Description
214
, TEXT
215
, NUM
216
, DATETIME
217
, CURRENCY
218
, "BOOLEAN"
219
, COMMENTS
220
, ca.ATTRIBUTEDATE
221
FROM ConstituentAttributes ca
222
JOIN AttributeTypes at ON ca.ATTRIBUTETYPESID = at.ATTRIBUTETYPESID
223
LEFT JOIN TABLEENTRIES ON ca.TABLEENTRIESID = TABLEENTRIES.TABLEENTRIESID
224
```
225
226
*note:*  In the SQL above, "PARENTID" and not "ConstitID" is the correct foreign key to link this to the contact.
227
228
To get a list of option values out of RE for the attributes, use this SQL:
229 9 Jon Goldberg
```sql
230 1 Jon Goldberg
SELECT
231
DESCRIPTION
232
, at.CODETABLESID
233
, LONGDESCRIPTION
234
FROM TABLEENTRIES te 
235
LEFT JOIN AttributeTypes at ON te.CODETABLESID = at.CODETABLESID
236
ORDER BY DESCRIPTION
237
```
238
239
Attributes can be multi-record custom fields by their nature, so you have to account for that.  Here's some alpha-grade SQL for sussing out which fields have multi-record custom fields:
240 9 Jon Goldberg
```sql
241 1 Jon Goldberg
SELECT ATTRIBUTETYPESID, PARENTID, COUNT(LONGDESCRIPTION)
242
FROM ConstituentAttributes ca
243
JOIN TABLEENTRIES te ON ca.TABLEENTRIESID = te.TABLEENTRIESID
244
GROUP BY PARENTID, ATTRIBUTETYPESID
245
HAVING COUNT(LONGDESCRIPTION) > 1
246
ORDER BY ATTRIBUTETYPESID
247
```
248
249
*note:*  In Civi 4.5+, you could conceivable use "EntityRef" functionality to facilitate chained selects of OptionValue lists.  That would let you create a multi-record custom field group that would very closely map how Attributes work in RE - but you'd have all the disadvantages of multi-record custom fields.
250
251
### Salutations/addressee info
252
253
RE stores contact salutations and addressee info in two places.
254
255
Primary salutations/addressess are stored on the `RECORDS` table.  `PRIMARY_ADDRESSEE_ID`, `PRIMARY_ADDRESSEE`, and `PRIMARY_ADDRESSEE_EDIT`, `PRIMARY_SALUTATION_ID`,  `PRIMARY_SALUTATION`,  `PRIMARY_SALUTATION_EDIT`.
256
257
An unlimited number of non-primary salutations can be stored in the `CONSTITUENT_SALUTATION` table.
258
259
Salutation options values are stored in the SALUTATION table, in the format "CODE1, CODE2, CODE3, etc.".  Each code refers to an id in the SALUTATION_FIELDS table, which contains tokens (e.g. "First Name", "Spouse Last Name") as well as common words like "And".
260
261
Note that  `PRIMARY_ADDRESSEE` is more akin to `addressee_display` in Civi, in that it stores the calculated display ID.  Also note that when `PRIMARY_ADDRESSEE_EDIT` is -1 (true), that's the equivalent of a custom addressee in Civi, and the value stored in  `PRIMARY_ADDRESSEE_ID` must be ignored.
262
263
### Other constituent tables:
264
265
Skip these tables:
266
* Spouse
267
* Gifts
268
* First Gift, Last gift, Largest Gift
269
* Actions
270
* First Action, Last Action
271
* Summary Information
272
273
## Contribution-related exports
274
275
### Contributions/Gifts
276
277
Contributions (in RE parlance: Gifts) are complicated beasts!
278
279
Here are some relevant database tables and their equivalent in Civi:
280
GIFT	civicrm_contribution
281
GiftSplit	civicrm_line_item
282
CAMPAIGN	Roughly maps to Campaign.  Your mapping may vary and/or include custom fields.
283
APPEAL	Also roughly maps to Campaign (or Source).  Your mapping may vary and/or include custom fields.
284
FUND	Roughly maps to Financial Type, but you might choose to import as a custom field instead.
285
286
See "Campaigns, Appeals, Packages" below for more.
287
288
Finally, note that RE has a concept of an "Adjustment".  If a gift has already been posted to the accounting software, you can't simply change the amount.  You create an adjustment, which has the updated data, and the two gift records are linked via the AdjustmentId.  This is also how pledge installments are written off (see "Pledges" below).
289
290
Note that gift type is hardcoded into a function called "TranslateGiftType) - so you may want to include that function in your SQL, e.g.:
291 10 Jon Goldberg
```sql
292 1 Jon Goldberg
SELECT
293
gs.GiftId
294
, g.CONSTIT_ID
295
, gs.Amount
296
, g.DTE as gift_date
297
, FUND.DESCRIPTION as fund
298
, CAMPAIGN.DESCRIPTION as campaign
299
, APPEAL.DESCRIPTION as appeal
300
, g.PAYMENT_TYPE
301
, g.ACKNOWLEDGE_FLAG
302
, g.CHECK_NUMBER
303
, g.CHECK_DATE
304
, g.BATCH_NUMBER
305
, g.ANONYMOUS
306
, gst.LONGDESCRIPTION as giftsubtype
307
, g.TYPE
308
, DBO.TranslateGiftType(g.TYPE) as type2
309
FROM GiftSplit gs
310
LEFT JOIN FUND on gs.FundId = FUND.id
311
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
312
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
313
LEFT JOIN GIFT g on gs.GiftId = g.ID
314
LEFT JOIN TABLEENTRIES gst on g.GIFTSUBTYPE = gst.TABLEENTRIESID
315
```
316
317
(See here: http://www.re-decoded.com/2013/07/payment-type-or-payment-method-id-reference/#more-714)
318
319
Payment Type is also hard-coded, it seems:
320
1	Cash
321
2	Personal Check
322
3	Business Check
323
4	Credit Card
324
5 	Standing Order
325
6	Direct Debit
326
7	Voucher
327
8	Other
328
329
### Soft Credits
330
331
Stored in GIFTSOFTCREDIT.  RE does NOT have the concept of a soft credit type - which is fine.
332 11 Jon Goldberg
```sql
333 1 Jon Goldberg
SELECT
334
, GiftId
335
, ConstitId
336
, Amount
337
, 'Soft Credit' as soft_credit_type
338
FROM GiftSoftCredit
339
```
340
341
### Solicitor, Gift
342
343
(Important!  Gift solicitors are different from Contact Solicitors)
344
345
I imported these as soft credits, but a different TYPE of soft credit.  Here's the SQL I used to get the data out of RE:
346 12 Jon Goldberg
```sql
347 1 Jon Goldberg
SELECT
348
ParentId as gift_id
349
, SolicitorId as soft_creditee_external_identifier
350
, Amount
351
, 'Solicitor' as soft_credit_type
352
FROM GiftSolicitor
353
```
354
355
### In Honor/Memorial Of (aka Tributes)
356
357
As of CiviCRM 4.5, In Honor/Memorial of is considered a form of soft credit.  In RE, they're still separate, and are called Tributes.  The structure is a little more complex - the table structure is Constituent <-> Tribute <-> Gift_Tribute <-> Gift.  Civi is Contact <-> Soft Credit <-> Contribution.  
358
359
Here is some preliminary SQL that pulls tribute data suitable for transformation and import to Civi as ContributionSoft entities.  Note that CiviCRM doesn't have a concept of a "Description" but does have the concept of a PCP Note, so I'm importing the description there - in the future, I could see the argument for Civi exposing the PCP Note as a description.
360
361
SELECT
362 13 Jon Goldberg
```sql
363 1 Jon Goldberg
gt.GIFT_ID
364
, gt.TRIBUTE_TYPE
365
, t.DESCRIPTION
366
, t.RECORDS_ID as tributee_extenal_identifier
367
, te.LONGDESCRIPTION as tribute_type
368
FROM GIFT_TRIBUTE gt
369
JOIN TRIBUTE t ON gt.TRIBUTE_ID = t.ID
370
LEFT JOIN TABLEENTRIES te on gt.TRIBUTE_TYPE = te.TABLEENTRIESID
371
```
372
373
### Pledges
374
375
Here are the relevant tables and their equivalents in Civi:
376
GIFT
377
Installment
378
InstallmentPayment
379
380
`GIFT` is equivalent to `civicrm_contribution` AND to `civicrm_pledge`.  Pledges and contributions are stored in the same table - so a pledge paid in six installments will have SEVEN records in the `GIFT` field.  Many organizations will specify a pledge in the Gift Type field - you can also tell by the presence of the `INSTALLMENT_FREQUENCY`, `NUMBER_OF_INSTALLMENTS`, `FrequencyDescription`, `REMIND_FLAG`, `NextTransactionDate` and the `Schedule*` fields.  Note that some of these might also be used for recurring contributions.  
381
382
`Installment` and `InstallmentPayment` are, when combined, the equivalent of the `civicrm_pledge_payment` table.  `civicrm_pledge_payment` has a field `scheduled_amount` and `actual_amount`.  RE's model is somewhat superior in that it allows partial payments on a pledge installment.
383
384
*Notes:* When creating pledges in CiviCRM via API, the open pledge payments are simultaneously created.  To import pledge payments from RE, you first want to delete the auto-generated pledge payments, then import your own pledge payments.  Finally, when importing pledge payments, the status of the parent pledge isn't updated.  So you'll probably want some SQL to indicate whether the pledges are pending, complete or canceled, depending on the status of the pledge payments.  Finally, watch out for adjustments, which is how some or all pledge installments might be marked as "Written Off" in RE.
385
386
The INSTALLMENT_FREQUENCY list is hard-coded:
387 14 Jon Goldberg
```
388
1 Annually
389
2 Every 6 Months
390
3 Every 3 Months
391
4 Every 2 Months
392
5 Every Month
393
6 Due Twice/Month
394
9 Irregular
395
10 Single Installment
396
```
397 1 Jon Goldberg
398
Some SQL:
399 14 Jon Goldberg
```sql
400 1 Jon Goldberg
/* Find all GIFT records with one or more associated Installment records.  These are pledges OR recurring gifts. */
401
SELECT DISTINCT
402
g.CONSTIT_ID
403
, g.ID as GiftId
404
, g.Amount
405
, g.DTE as receive_date
406
, FUND.DESCRIPTION as fund
407
, FUND.FUND_ID
408
, CAMPAIGN.DESCRIPTION as campaign
409
, APPEAL.DESCRIPTION as appeal
410
, g.PAYMENT_TYPE
411
, g.ACKNOWLEDGEDATE
412
, DBO.TranslateGiftType(g.TYPE) as type
413
, g.REF as note
414
,DATE_1ST_PAY
415
,g.DATEADDED
416
,g.DATECHANGED
417
,INSTALLMENT_FREQUENCY
418
,NUMBER_OF_INSTALLMENTS
419
,POST_DATE
420
,POST_STATUS
421
,REMIND_FLAG
422
,Schedule_Month
423
,Schedule_DayOfMonth
424
,Schedule_MonthlyDayOfWeek
425
,Schedule_Spacing
426
,Schedule_MonthlyType
427
,Schedule_MonthlyOrdinal
428
,Schedule_WeeklyDayOfWeek
429
,Schedule_DayOfMonth2
430
,Schedule_SMDayType1
431
,Schedule_SMDayType2
432
,NextTransactionDate
433
,Schedule_EndDate
434
,FrequencyDescription
435
, r.CONSTITUENT_ID
436
FROM Gift g
437
LEFT JOIN GiftSplit gs on g.ID = gs.GiftId
438
LEFT JOIN FUND on gs.FundId = FUND.id
439
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
440
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
441
LEFT JOIN RECORDS r ON g.CONSTIT_ID = r.ID
442
JOIN Installment i ON g.ID = i.PledgeId
443
```
444
445
Find pledge payments:
446 14 Jon Goldberg
```sql
447 1 Jon Goldberg
/* Find all pledge installments, and their related payments if they exist. */
448
SELECT
449
i.InstallmentId
450
, i.PledgeId
451
, i.AdjustmentId
452
, i.Amount as scheduled_amount
453
, i.Dte
454
, ip.Amount as actual_amount
455
, ip.PaymentId
456
, g.CONSTIT_ID
457
, g.RECEIPT_AMOUNT
458
, g.DTE as receive_date
459
, g.TYPE
460
, DBO.TranslateGiftType(g.TYPE) as type
461
FROM Installment i
462
LEFT JOIN InstallmentPayment ip ON i.InstallmentId = ip.InstallmentId
463
LEFT JOIN GIFT g ON ip.PaymentId = g.ID
464
/* Adjustments are stored in here too - when an adjustment happens, the pledge ID of the original value is blanked */
465
WHERE i.PledgeId IS NOT NULL 
466
ORDER BY i.AdjustmentId
467
/* Write-off Types: Covenant WriteOff, MG Write Off, Write Off */
468
```
469
470
## Campaigns, Appeals, Packages
471
472
RE's model for campaigns is hierarchical and more sophisticated than CiviCRM's.  A campaign (e.g. "Capital fundraising FY2017") can consist of several appeals (e.g. "Capital fundraising FY 2017 Spring Mailing").  Appeals will generally correspond to a particular action, especially a postal mailing.  Campaigns and Appeals _can_ be linked in a many-to-many relationship, but this is rare.  The 1-to-many is by far the most common approach.  Finally, an appeal can consist of "packages", which is a segment of your appeal.  For instance, a single mailing ("appeal") could go out to major donors, regular donors and non-donors.  You might also A/B test envelopes vs. postcards in the same mailing.  This would result in a total of six "packages" for a single appeal.  RE can track goals for each separately, and easily report on "number solicited" by package vs. number of gifts received.
473
474
## Actions
475
476
Actions fill the same purpose as Activities in CiviCRM, but are architected quite differently - in some ways better, some ways worse.  I don't have as much concrete info here, but here's a decent start at extracting Actions data via SQL:
477 15 Jon Goldberg
```sql
478 1 Jon Goldberg
SELECT
479
  a.ADDED_BY
480
, a.AUTO_REMIND
481
, a.RECORDS_ID as external_identifier
482
, cr.RELATION_ID as action_contact_id
483
, a.DTE as activity_date_time
484
, LETTER.LONGDESCRIPTION as letter
485
, a.PRIORITY as priority_id
486
, a.REMIND_VALUE
487
, a.CATEGORY
488
, a.Completed
489
, a.COMPLETED_DATE
490
, a.FUND_ID
491
, a.FOLLOWUPTO_ID
492
, a.TRACKACTION_ID
493
, a.PhoneNumber as phone_number
494
, a.Remind_Frequency
495
, a.WORDDOCNAME
496
, a.APPEAL_ID
497
, a.APPEAL_LETTER_CODE
498
, a.OUTLOOK_EMAIL_SUBJECT
499
, STATUS.LONGDESCRIPTION as status
500
, TYPE.LONGDESCRIPTION as type
501
, LOCATION.LONGDESCRIPTION as location
502
, ActionNotepad.ActualNotes
503
, CAMPAIGN.DESCRIPTION as campaign
504
FROM ACTIONS a
505
LEFT JOIN TABLEENTRIES as STATUS ON a.STATUS = STATUS.TABLEENTRIESID
506
LEFT JOIN TABLEENTRIES as TYPE ON a.[TYPE] = [TYPE].TABLEENTRIESID
507
LEFT JOIN TABLEENTRIES as LOCATION ON a.[Location] = LOCATION.TABLEENTRIESID 
508
LEFT JOIN TABLEENTRIES as LETTER on a.[LETTER_CODE] = LETTER.TABLEENTRIESID
509
LEFT JOIN ActionNotepad ON a.ID = ActionNotepad.ParentId
510
LEFT JOIN CAMPAIGN on a.CAMPAIGN_ID = CAMPAIGN.id
511
LEFT JOIN CONSTIT_RELATIONSHIPS cr on a.CONTACT_ID = cr.ID
512
```
513
514
"Category" and "Action type" both roughly map to "Activity Type".  Same for "status" and "COMPLETED" and "COMPLETED_DATE" mapping to "activity_status".  RE lets you designate a related Campaign, Fund and Proposal; out of the box, Civi only supports Campaign.  The auto-reminder is more flexible than you can get with scheduled reminders in Civi without getting very complicated.  "Solicitors" can't be mapped to a contact reference lookup, because more than one can be stored.
515
516
*Note:* The SQL above presumes only one note per action.  If you have multiple notes per action, the action will be represented with multiple records, one per associated note.  I'll try to provide SQL for extracting the notes separately at a later date.
517
518
## Action Notes
519
520
Action Notes are stored in their own table.  This maps to "Details" on a Civi activity, but you can log multiple notes per action in RE.  Here's the SQL I used to extract them in preparation:
521 16 Jon Goldberg
```sql
522 1 Jon Goldberg
SELECT
523
  NotesID
524
, Title
525
, Description
526
, Author
527
, ActualNotes
528
, ParentId
529
, NotepadDate
530
, TABLEENTRIES.LONGDESCRIPTION as Type
531
  FROM ActionNotepad
532
  LEFT JOIN TABLEENTRIES ON ActionNotepad.NoteTypeId = TABLEENTRIES.TABLEENTRIESID
533
ORDER BY ParentId, ActionNotepad."SEQUENCE"
534
```
535
536
## Events
537
538
Events are stored fairly similarly to CiviCRM, except:
539
* locations are stored on the event record itself (which I'm not dealing with).
540
* There's fields for storing data about classes.  I haven't delved into this - I suspect that this may tie into recurring events.
541
* "Event Category" and "Event Type" might both map to Civi's "Event Type".  This isn't the case for me.
542
* Events need not have begin/end dates.  While this is technically true for Civi, you're buying yourself a whole lot of trouble.  I'm pulling in "DATE_ADDED" to substitute in for START_DATE where none exists.
543
544
Here's some SQL to pull in the most relevant data:
545
```
546
SELECT
547
  se.CAPACITY
548
, se.END_DATE
549
, se.ID
550
, se.NAME
551
, se.START_DATE
552
, se.DATE_ADDED
553
, te.LONGDESCRIPTION as activity_type
554
, se.INACTIVE
555
, se.DISPLAYONCALENDAR
556
, CAMPAIGN.DESCRIPTION as campaign
557
, se.DESCRIPTION
558
FROM SPECIAL_EVENT se
559
LEFT JOIN CAMPAIGN on se.CAMPAIGN_ID = CAMPAIGN.id 
560
LEFT JOIN TABLEENTRIES te ON se.TYPEID = te.TABLEENTRIESID
561
```
562
563
## Notes
564
565
RE notes (stored in the "ConstituentNotepad" table) can store quite a bit of data that Civi notes can not.  They can store formatting (but with proprietary format tags, not HTML), inline photos, etc, and contain fields for date of note (separate from "Date Added" and "Date Changed"), the type of note, etc.  Fortunately, they store plain-text versions of formatted notes in their own field.  "Notes" is formatted; "ActualNotes" is plain text (except, well, where it isn't). 
566
567
I've resolved this by removing notes over a certain length (above 15K and I assume you're a photo) and concatenating the fields I want to keep (e.g. Note Type and Description) with the ActualNotes field.
568
569
It may be possible to export the photos in the Notes using the techniques described below under "Media".
570
571
Here's the SQL I'm currently using to extract notes before doing transforms in Kettle:
572
```
573
SELECT
574
Title as subject
575
, Description
576
, Author
577
, ActualNotes
578
, ParentId
579
, cn.DateChanged
580
, LONGDESCRIPTION as NoteType
581
FROM ConstituentNotepad cn
582
LEFT JOIN TABLEENTRIES ON NoteTypeId = TABLEENTRIESID
583
```
584
585
## Media
586
587
### Exporting from RE
588
589
The files stored on the "Media" tab are held in the [dbo].[MEDIA] table in MS SQL.  Assuming embedded and not linked data, the files are stored in the MS Access OLE format.  It's relatively difficult to extract data from the OLE wrapper, though searching for `extract access ole` on any search engine will give you lots of options in a variety of languages.  Blackbaud even has code to do it "here":https://kb.blackbaud.com/articles/Article/58559, if you feel like using VBA.
590
591
I opted to use a commercial software package from Yohz Software called "SQL Image Viewer":http://www.yohz.com/siv_details.htm.  If you use this tool, enter the command: ```
592
SELECT OBJECT FROM [dbo].[MEDIA]
593
```
594
595
Then press "Execute Query", then press "Export" when it's done.  This exports about 200 items/minute on a computer with a very slow hard drive.
596
597
If you want to decode the OLE containers on your own, there's the "bcp":https://msdn.microsoft.com/en-us/library/ms162802.aspx CLI tool that installs with MS SQL, and you can run a SQL query from SQL Server Management Studio that extracts your OLE containers; see "here":http://dba.stackexchange.com/questions/80817/how-to-export-an-image-column-to-files-in-sql-server.  I experimented with this strategy, and this CLI command extracted an Access OLE container:
598
```
599
bcp "SELECT OBJECT FROM [July_Snapshot].[dbo].[media] WHERE ID = 1210 " queryout "C:\Users\Jon\Desktop\temp\test.ole" -T -N -S HOSTNAME\RE_EXPRESS
600
```
601
602
### Importing into CiviCRM
603
604
The approach I took was to copy all the files into the "custom files" directory as specified in *Administer > System Settings > Directories*.  Then I used the Attachment entity of the API to import the file to an activity.  For the Media tab, I created activities especially to import the media onto.
605
606
Here's an example of the correct usage of the API to add in image "drill.jpg" to an activity with an ID of 628:
607
```
608
$result = civicrm_api3('Attachment', 'create', array(
609
  'sequential' => 1,
610
  'name' => "drill.jpg",
611
  'mime_type' => "image/jpeg",
612
  'entity_id' => 628,
613
  'entity_table' => "civicrm_activity",
614
  'options' => array('move-file' => "/home/jon/local/civicrm-buildkit/build/d46/sites/default/files/civicrm/custom/drill.jpg"),
615
));
616
```
617
618
Note that Civi will rename your files with random characters at the end, so this action is not idempotent.  Keep a reserve copy of your exported RE media to roll back to!
619
620
If you use the API CSV import tool, your CSVs should look like this:
621
```
622
"name",entity_id,"entity_table","mime_type","options.move-file"
623
"100.png",87511,"civicrm_activity","image/png","/home/jon/local/lccr/wp-content/plugins/files/civicrm/custom/100.png"
624
"1000.pdf",88411,"civicrm_activity","application/pdf","/home/jon/local/lccr/wp-content/plugins/files/civicrm/custom/1000.pdf"
625
```
626
627
## And More
628
629
### Tables that Civi doesn't have a direct counterpart for
630
631
* Aliases (stores Maiden Name and d/b/a - unsure how to import into Civi just yet)
632
* Solicitor Goals - Can be found on an RE contact record on "Bio 1" tab by clicking "Details" next to "Is a Solicitor" checkbox.  Don't know how to use them.
633
634
635
Open each CSV file in Excel or similar.  Sort each field by ascending AND descending to see if any data is stored in that field.  If every record has no data or the same data, delete it - it's not being tracked in the current system.  If you see only one or two records with a particular field, they're also probably fine to go, but check with the client first.
636
637
638
Next, strip out all of the constituent information except for primary/foreign keys.  I like to keep in First/Middle/Last name just for human readability though.  So leave in those three fields, plus any field with the word "ID" in it.  This is your base constituent info, and will be in every other export you do.
639
640
Now comes the fun part!  Export each table, one at a time, by adding those fields to an export that already includes the base constituent info.
641
642
For one-to-many relationships, the system will ask you how many instances of the information to export.  I default to 12, then look over the data to see how many are actually used, then re-export with a higher or lower number.
643
644
I also remove records that don't contain the relevant data.  For instance, when exporting Solicit Codes, I sort by the first Solicit Code.  Then I scroll down past the folks that have Solicit Codes to those who have none, and delete the rows for folks who have none.
645
646
Note that for simplicity's sake, RE contains many views of the tables that, if you export them all, you'll have redundant data.  There's no need to export "First Gift", "Last Gift", or "Largest Gift" - simply export all gifts.  Likewise for "Preferred Address".
647
648
When exporting one-to-many tables that themselves contain one-to-many tables (e.g. Addresses contains Phones), do NOT select 12 of each!  That means you're exporting 144 phone numbers per record.  First determine the maximum number of addresses being tracked, re-export with that number, THEN export with phone numbers.  Also, it's reasonable to export with 5 phone numbers per address.
649
650
NOTE: Letters sent is incomplete, there's more than 12 letters to some folks!
651
652
GIFTS is related to constituent on the last column (Constituent System Record ID)
653
654
### Code Tables/Option Groups/Option Values
655
656
If you're extracting data from the SQL back-end, you'll see that the RE equivalent to Civi option groups is "code tables".  There's two functions that handle lookups: dbo.GetTableEntryDescription and dbo.GetTableEntryDescSlim.  To determine where the data is being accessed by the function, see "Deciphering MS SQL", below.  Use the "lTableNumber" passed to those functions and you'll find your data in dbo.CODETABLES (comparable to civicrm_option_group), dbo.CODETABLEMAP and dbo.TABLEENTRIES (comparable to civicrm_option_value).
657
658
## Deciphering MS SQL
659
660
SQL Server Profiler is a tool that lets you spy on SQL statements passed to MS SQL, which is good for determining where certain data lives.  However, RE depends on functions and stored procedures, so sometimes the SQL won't tell you exactly where to look.
661
662
### Looking Up Functions
663
664
These are embedded in SQL and have a nomenclature like: dbo.GetTableEntryDescSlim. Find them in SQL Server Management Studio: database > Programmability > Functions > Scalar-valued Functions.
665
666
### Looking Up Stored Procedures
667
668
If, in the profiler, taking a certain action shows a command like this:
669
These have a syntax like:
670
```
671
exec sp_execute 48,43,'Acknowledgee'
672
```
673
674
You're dealing with a stored procedure.  You need to find the corresponding `exec sp_prepexec` command (in this case, the one with a 48).  In this case, it looks like:
675
```
676
declare `p1 int
677
set `p1=48
678
exec sp_prepexec `p1 output,N'`P1 int,`P2 varchar(255)',N'SELECT  Top 1 TABLEENTRIESID  FROM DBO.TABLEENTRIES WHERE CODETABLESID = `P1 AND LONGDESCRIPTION = `P2  ',43,'Acknowledgee'
679
select `p1
680
```
681
682
Note that there's a tool called "SQL Hunting Dog", a free plug-in for SQL Server Management Studio, which makes locating stored procedures, etc. easier.
683
684
685
### Addressee/Postal Greeting/E-mail greeting
686
687
RE has a much wider variety of greeting formats out-of-the-box.  The "spouse ID" is stored on the record to enable quick lookups of addressee greetings that include the spouse.
688
689
It's likely that you'll want to map existing RE greetings to Civi greetings.  Here is some SQL that will show you how the current greetings in RE are constructed:
690
```<code class="sql">
691
/****** Script for SelectTopNRows command from SSMS  ******/
692
SELECT s.ID
693
, sf1.FIELDNAME as FIELD1
694
, sf2.FIELDNAME as FIELD2
695
, sf3.FIELDNAME as FIELD3
696
, sf4.FIELDNAME as FIELD4
697
, sf5.FIELDNAME as FIELD5
698
, sf6.FIELDNAME as FIELD6
699
, sf7.FIELDNAME as FIELD7
700
, sf8.FIELDNAME as FIELD8
701
, sf9.FIELDNAME as FIELD9
702
, sf10.FIELDNAME as FIELD10     
703
, sf11.FIELDNAME as FIELD11
704
, sf12.FIELDNAME as FIELD12
705
, sf13.FIELDNAME as FIELD13
706
, sf14.FIELDNAME as FIELD14
707
, sf15.FIELDNAME as FIELD15
708
, sf16.FIELDNAME as FIELD16
709
, sf17.FIELDNAME as FIELD17
710
, sf18.FIELDNAME as FIELD18
711
, sf19.FIELDNAME as FIELD19
712
, sf20.FIELDNAME as FIELD20
713
  FROM SALUTATIONS s
714
  LEFT JOIN SALUTATION_FIELDS sf1 on CODE1 = sf1.ID
715
  LEFT JOIN SALUTATION_FIELDS sf2 on CODE2 = sf2.ID
716
  LEFT JOIN SALUTATION_FIELDS sf3 on CODE3 = sf3.ID
717
  LEFT JOIN SALUTATION_FIELDS sf4 on CODE4 = sf4.ID
718
  LEFT JOIN SALUTATION_FIELDS sf5 on CODE5 = sf5.ID
719
  LEFT JOIN SALUTATION_FIELDS sf6 on CODE6 = sf6.ID
720
  LEFT JOIN SALUTATION_FIELDS sf7 on CODE7 = sf7.ID
721
  LEFT JOIN SALUTATION_FIELDS sf8 on CODE8 = sf8.ID
722
  LEFT JOIN SALUTATION_FIELDS sf9 on CODE9 = sf9.ID
723
  LEFT JOIN SALUTATION_FIELDS sf10 on CODE10 = sf10.ID
724
  LEFT JOIN SALUTATION_FIELDS sf11 on CODE11 = sf11.ID
725
  LEFT JOIN SALUTATION_FIELDS sf12 on CODE12 = sf12.ID
726
  LEFT JOIN SALUTATION_FIELDS sf13 on CODE13 = sf13.ID
727
  LEFT JOIN SALUTATION_FIELDS sf14 on CODE14 = sf14.ID
728
  LEFT JOIN SALUTATION_FIELDS sf15 on CODE15 = sf15.ID
729
  LEFT JOIN SALUTATION_FIELDS sf16 on CODE16 = sf16.ID
730
  LEFT JOIN SALUTATION_FIELDS sf17 on CODE17 = sf17.ID
731
  LEFT JOIN SALUTATION_FIELDS sf18 on CODE18 = sf18.ID
732
  LEFT JOIN SALUTATION_FIELDS sf19 on CODE19 = sf19.ID
733
  LEFT JOIN SALUTATION_FIELDS sf20 on CODE20 = sf20.ID
734
</code>```
735
736
737
### Things I see that RE does better than Civi:
738
739
* Better greetings/salutations UI out of the box.  In Civi, you must in-line edit the greetings, then press "Edit" next to the greetings, and even then you only see the tokens you'll use.  RE lets you edit with no clicks, and parses the tokens for you.
740
* The equivalent of option values are stored with their id, not their value.  This isn't a big deal, but it DOES make data transformation easier in RE, and I suspect it makes their equivalent of pseudoconstant code easier to read.
741
* There's a lot more data stored in many-to-many tables.  For instance, job titles are stored in the relationship tab, reflecting the fact that someone can have more than one job.