Project

General

Profile

Exporting Raisers Edge for CiviCRM » History » Version 26

Jon Goldberg, 11/12/2018 09:35 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 25 Jon Goldberg
* All constituent attribute data is stored in the table `ConstituentAttributes` for constituents and `RELATIONSHIPATTRIBUTES` for non-constituents.  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 1 Jon Goldberg
 
207
Here's my preliminary SQL to export attributes from RE:
208 9 Jon Goldberg
```sql
209 1 Jon Goldberg
SELECT
210 25 Jon Goldberg
at.DESCRIPTION as Category
211 1 Jon Goldberg
, TABLEENTRIES.LONGDESCRIPTION as Description
212
, TEXT
213
, "BOOLEAN"
214
, COMMENTS
215
, ca.ATTRIBUTEDATE
216 25 Jon Goldberg
, ca.PARENTID
217 1 Jon Goldberg
FROM ConstituentAttributes ca
218
JOIN AttributeTypes at ON ca.ATTRIBUTETYPESID = at.ATTRIBUTETYPESID
219
LEFT JOIN TABLEENTRIES ON ca.TABLEENTRIESID = TABLEENTRIES.TABLEENTRIESID
220 25 Jon Goldberg
-- This UNION adds non-constituent attributes
221
UNION 
222
SELECT
223
at.DESCRIPTION as Category
224
, TABLEENTRIES.LONGDESCRIPTION as Description
225
, TEXT
226
, "BOOLEAN"
227
, COMMENTS
228
, ra.ATTRIBUTEDATE
229
, cr.RELATION_ID AS PARENTID
230
FROM RELATIONSHIPATTRIBUTES ra
231
JOIN AttributeTypes at ON ra.ATTRIBUTETYPESID = at.ATTRIBUTETYPESID
232
LEFT JOIN TABLEENTRIES ON ra.TABLEENTRIESID = TABLEENTRIES.TABLEENTRIESID
233
JOIN CONSTIT_RELATIONSHIPS cr ON ra.PARENTID = cr.ID
234 1 Jon Goldberg
```
235
236
To get a list of option values out of RE for the attributes, use this SQL:
237 9 Jon Goldberg
```sql
238 1 Jon Goldberg
SELECT
239
DESCRIPTION
240
, at.CODETABLESID
241
, LONGDESCRIPTION
242
FROM TABLEENTRIES te 
243
LEFT JOIN AttributeTypes at ON te.CODETABLESID = at.CODETABLESID
244
ORDER BY DESCRIPTION
245
```
246
247
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:
248 9 Jon Goldberg
```sql
249 1 Jon Goldberg
SELECT ATTRIBUTETYPESID, PARENTID, COUNT(LONGDESCRIPTION)
250
FROM ConstituentAttributes ca
251
JOIN TABLEENTRIES te ON ca.TABLEENTRIESID = te.TABLEENTRIESID
252
GROUP BY PARENTID, ATTRIBUTETYPESID
253
HAVING COUNT(LONGDESCRIPTION) > 1
254
ORDER BY ATTRIBUTETYPESID
255
```
256
257 26 Jon Goldberg
*note:*  In Civi 4.5+, you could conceivably 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.
258 1 Jon Goldberg
259
### Salutations/addressee info
260
261
RE stores contact salutations and addressee info in two places.
262
263
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`.
264
265
An unlimited number of non-primary salutations can be stored in the `CONSTITUENT_SALUTATION` table.
266
267
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".
268
269
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.
270
271
### Other constituent tables:
272
273
Skip these tables:
274
* Spouse
275
* Gifts
276
* First Gift, Last gift, Largest Gift
277
* Actions
278
* First Action, Last Action
279
* Summary Information
280
281
## Contribution-related exports
282
283
### Contributions/Gifts
284
285
Contributions (in RE parlance: Gifts) are complicated beasts!
286
287
Here are some relevant database tables and their equivalent in Civi:
288
GIFT	civicrm_contribution
289
GiftSplit	civicrm_line_item
290
CAMPAIGN	Roughly maps to Campaign.  Your mapping may vary and/or include custom fields.
291
APPEAL	Also roughly maps to Campaign (or Source).  Your mapping may vary and/or include custom fields.
292
FUND	Roughly maps to Financial Type, but you might choose to import as a custom field instead.
293
294
See "Campaigns, Appeals, Packages" below for more.
295
296
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).
297
298
Note that gift type is hardcoded into a function called "TranslateGiftType) - so you may want to include that function in your SQL, e.g.:
299 10 Jon Goldberg
```sql
300 1 Jon Goldberg
SELECT
301
gs.GiftId
302
, g.CONSTIT_ID
303
, gs.Amount
304
, g.DTE as gift_date
305
, FUND.DESCRIPTION as fund
306
, CAMPAIGN.DESCRIPTION as campaign
307
, APPEAL.DESCRIPTION as appeal
308
, g.PAYMENT_TYPE
309
, g.ACKNOWLEDGE_FLAG
310
, g.CHECK_NUMBER
311
, g.CHECK_DATE
312
, g.BATCH_NUMBER
313
, g.ANONYMOUS
314
, gst.LONGDESCRIPTION as giftsubtype
315
, g.TYPE
316
, DBO.TranslateGiftType(g.TYPE) as type2
317
FROM GiftSplit gs
318
LEFT JOIN FUND on gs.FundId = FUND.id
319
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
320
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
321
LEFT JOIN GIFT g on gs.GiftId = g.ID
322
LEFT JOIN TABLEENTRIES gst on g.GIFTSUBTYPE = gst.TABLEENTRIESID
323
```
324
325
(See here: http://www.re-decoded.com/2013/07/payment-type-or-payment-method-id-reference/#more-714)
326
327
Payment Type is also hard-coded, it seems:
328
1	Cash
329
2	Personal Check
330
3	Business Check
331
4	Credit Card
332
5 	Standing Order
333
6	Direct Debit
334
7	Voucher
335
8	Other
336
337
### Soft Credits
338
339
Stored in GIFTSOFTCREDIT.  RE does NOT have the concept of a soft credit type - which is fine.
340 11 Jon Goldberg
```sql
341 1 Jon Goldberg
SELECT
342
, GiftId
343
, ConstitId
344
, Amount
345
, 'Soft Credit' as soft_credit_type
346
FROM GiftSoftCredit
347
```
348
349
### Solicitor, Gift
350
351
(Important!  Gift solicitors are different from Contact Solicitors)
352
353
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:
354 12 Jon Goldberg
```sql
355 1 Jon Goldberg
SELECT
356
ParentId as gift_id
357
, SolicitorId as soft_creditee_external_identifier
358
, Amount
359
, 'Solicitor' as soft_credit_type
360
FROM GiftSolicitor
361
```
362
363
### In Honor/Memorial Of (aka Tributes)
364
365
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.  
366
367
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.
368
369
SELECT
370 13 Jon Goldberg
```sql
371 1 Jon Goldberg
gt.GIFT_ID
372
, gt.TRIBUTE_TYPE
373
, t.DESCRIPTION
374
, t.RECORDS_ID as tributee_extenal_identifier
375
, te.LONGDESCRIPTION as tribute_type
376
FROM GIFT_TRIBUTE gt
377
JOIN TRIBUTE t ON gt.TRIBUTE_ID = t.ID
378
LEFT JOIN TABLEENTRIES te on gt.TRIBUTE_TYPE = te.TABLEENTRIESID
379
```
380
381
### Pledges
382
383
Here are the relevant tables and their equivalents in Civi:
384 23 Jon Goldberg
```
385 1 Jon Goldberg
GIFT
386
Installment
387
InstallmentPayment
388 23 Jon Goldberg
```
389 1 Jon Goldberg
390 23 Jon Goldberg
`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.  One will be of Gift Type `Pledge` or `MG Pledge` ("Matching Gift Pledge").  MG Pledges will be on the original donor, with the payment on the matching donor.  You can also tell pledges 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.  
391 1 Jon Goldberg
392
`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.
393
394
*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.
395
396
The INSTALLMENT_FREQUENCY list is hard-coded:
397 14 Jon Goldberg
```
398
1 Annually
399
2 Every 6 Months
400
3 Every 3 Months
401
4 Every 2 Months
402
5 Every Month
403
6 Due Twice/Month
404
9 Irregular
405
10 Single Installment
406
```
407 1 Jon Goldberg
408
Some SQL:
409 14 Jon Goldberg
```sql
410 1 Jon Goldberg
/* Find all GIFT records with one or more associated Installment records.  These are pledges OR recurring gifts. */
411
SELECT DISTINCT
412
g.CONSTIT_ID
413
, g.ID as GiftId
414
, g.Amount
415
, g.DTE as receive_date
416
, FUND.DESCRIPTION as fund
417
, FUND.FUND_ID
418
, CAMPAIGN.DESCRIPTION as campaign
419
, APPEAL.DESCRIPTION as appeal
420
, g.PAYMENT_TYPE
421
, g.ACKNOWLEDGEDATE
422
, DBO.TranslateGiftType(g.TYPE) as type
423
, g.REF as note
424
,DATE_1ST_PAY
425
,g.DATEADDED
426
,g.DATECHANGED
427
,INSTALLMENT_FREQUENCY
428
,NUMBER_OF_INSTALLMENTS
429
,POST_DATE
430
,POST_STATUS
431
,REMIND_FLAG
432
,Schedule_Month
433
,Schedule_DayOfMonth
434
,Schedule_MonthlyDayOfWeek
435
,Schedule_Spacing
436
,Schedule_MonthlyType
437
,Schedule_MonthlyOrdinal
438
,Schedule_WeeklyDayOfWeek
439
,Schedule_DayOfMonth2
440
,Schedule_SMDayType1
441
,Schedule_SMDayType2
442
,NextTransactionDate
443
,Schedule_EndDate
444
,FrequencyDescription
445
, r.CONSTITUENT_ID
446
FROM Gift g
447
LEFT JOIN GiftSplit gs on g.ID = gs.GiftId
448
LEFT JOIN FUND on gs.FundId = FUND.id
449
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
450
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
451
LEFT JOIN RECORDS r ON g.CONSTIT_ID = r.ID
452
JOIN Installment i ON g.ID = i.PledgeId
453
```
454
455
Find pledge payments:
456 14 Jon Goldberg
```sql
457 1 Jon Goldberg
/* Find all pledge installments, and their related payments if they exist. */
458
SELECT
459
i.InstallmentId
460
, i.PledgeId
461
, i.AdjustmentId
462
, i.Amount as scheduled_amount
463
, i.Dte
464
, ip.Amount as actual_amount
465
, ip.PaymentId
466
, g.CONSTIT_ID
467
, g.RECEIPT_AMOUNT
468
, g.DTE as receive_date
469
, g.TYPE
470
, DBO.TranslateGiftType(g.TYPE) as type
471
FROM Installment i
472
LEFT JOIN InstallmentPayment ip ON i.InstallmentId = ip.InstallmentId
473
LEFT JOIN GIFT g ON ip.PaymentId = g.ID
474
/* Adjustments are stored in here too - when an adjustment happens, the pledge ID of the original value is blanked */
475
WHERE i.PledgeId IS NOT NULL 
476
ORDER BY i.AdjustmentId
477
/* Write-off Types: Covenant WriteOff, MG Write Off, Write Off */
478
```
479 23 Jon Goldberg
480 24 Jon Goldberg
#### Matching gifts
481
Gifts are connected to their matching gift via the `GiftMatchingGift` table, and appear in both the matched person's and matcher's "gifts" tab.
482
483 23 Jon Goldberg
#### Pledges as contributions
484
If you're working with an organization that wants to use CiviAccounts, you'll want to track pledges as pending contributions.
485 1 Jon Goldberg
486
## Campaigns, Appeals, Packages
487
488
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.
489
490
## Actions
491
492
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:
493 15 Jon Goldberg
```sql
494 1 Jon Goldberg
SELECT
495
  a.ADDED_BY
496
, a.AUTO_REMIND
497
, a.RECORDS_ID as external_identifier
498
, cr.RELATION_ID as action_contact_id
499
, a.DTE as activity_date_time
500
, LETTER.LONGDESCRIPTION as letter
501
, a.PRIORITY as priority_id
502
, a.REMIND_VALUE
503
, a.CATEGORY
504
, a.Completed
505
, a.COMPLETED_DATE
506
, a.FUND_ID
507
, a.FOLLOWUPTO_ID
508
, a.TRACKACTION_ID
509
, a.PhoneNumber as phone_number
510
, a.Remind_Frequency
511
, a.WORDDOCNAME
512
, a.APPEAL_ID
513
, a.APPEAL_LETTER_CODE
514
, a.OUTLOOK_EMAIL_SUBJECT
515
, STATUS.LONGDESCRIPTION as status
516
, TYPE.LONGDESCRIPTION as type
517
, LOCATION.LONGDESCRIPTION as location
518
, ActionNotepad.ActualNotes
519
, CAMPAIGN.DESCRIPTION as campaign
520
FROM ACTIONS a
521
LEFT JOIN TABLEENTRIES as STATUS ON a.STATUS = STATUS.TABLEENTRIESID
522
LEFT JOIN TABLEENTRIES as TYPE ON a.[TYPE] = [TYPE].TABLEENTRIESID
523
LEFT JOIN TABLEENTRIES as LOCATION ON a.[Location] = LOCATION.TABLEENTRIESID 
524
LEFT JOIN TABLEENTRIES as LETTER on a.[LETTER_CODE] = LETTER.TABLEENTRIESID
525
LEFT JOIN ActionNotepad ON a.ID = ActionNotepad.ParentId
526
LEFT JOIN CAMPAIGN on a.CAMPAIGN_ID = CAMPAIGN.id
527
LEFT JOIN CONSTIT_RELATIONSHIPS cr on a.CONTACT_ID = cr.ID
528
```
529
530
"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.
531
532
*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.
533
534
## Action Notes
535
536
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:
537 16 Jon Goldberg
```sql
538 1 Jon Goldberg
SELECT
539
  NotesID
540
, Title
541
, Description
542
, Author
543
, ActualNotes
544
, ParentId
545
, NotepadDate
546
, TABLEENTRIES.LONGDESCRIPTION as Type
547
  FROM ActionNotepad
548
  LEFT JOIN TABLEENTRIES ON ActionNotepad.NoteTypeId = TABLEENTRIES.TABLEENTRIESID
549
ORDER BY ParentId, ActionNotepad."SEQUENCE"
550
```
551
552
## Events
553
554
Events are stored fairly similarly to CiviCRM, except:
555
* locations are stored on the event record itself (which I'm not dealing with).
556
* There's fields for storing data about classes.  I haven't delved into this - I suspect that this may tie into recurring events.
557
* "Event Category" and "Event Type" might both map to Civi's "Event Type".  This isn't the case for me.
558
* 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.
559
560
Here's some SQL to pull in the most relevant data:
561 17 Jon Goldberg
```sql
562 1 Jon Goldberg
SELECT
563
  se.CAPACITY
564
, se.END_DATE
565
, se.ID
566
, se.NAME
567
, se.START_DATE
568
, se.DATE_ADDED
569
, te.LONGDESCRIPTION as activity_type
570
, se.INACTIVE
571
, se.DISPLAYONCALENDAR
572
, CAMPAIGN.DESCRIPTION as campaign
573
, se.DESCRIPTION
574
FROM SPECIAL_EVENT se
575
LEFT JOIN CAMPAIGN on se.CAMPAIGN_ID = CAMPAIGN.id 
576
LEFT JOIN TABLEENTRIES te ON se.TYPEID = te.TABLEENTRIESID
577
```
578
579
## Notes
580
581
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). 
582
583
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.
584
585
It may be possible to export the photos in the Notes using the techniques described below under "Media".
586
587
Here's the SQL I'm currently using to extract notes before doing transforms in Kettle:
588 18 Jon Goldberg
```sql
589 1 Jon Goldberg
SELECT
590
Title as subject
591
, Description
592
, Author
593
, ActualNotes
594
, ParentId
595
, cn.DateChanged
596
, LONGDESCRIPTION as NoteType
597
FROM ConstituentNotepad cn
598
LEFT JOIN TABLEENTRIES ON NoteTypeId = TABLEENTRIESID
599
```
600 22 Jon Goldberg
601
## Localization formats
602
Raiser's Edge stores most of this info in the `COUNTRY_CODES` table, though the actual country name is stored in `TABLEENTRIES`.  This SQL will get you both:
603
```sql
604
SELECT LONGDESCRIPTION, COUNTRY_CODES.*
605
  FROM COUNTRY_CODES
606
  JOIN TABLEENTRIES ON COUNTRY_CODES.COUNTRYCODESID = TABLEENTRIES.TABLEENTRIESID
607
```
608
609
Address formats (stored in Civi in `civicrm_address_format`) are stored in `COUNTRY_LABELS`.  You can add ass many tokens (`FIELD_NUM`) to a line (`LINE_NUM`) and they'll appear in order of `SEQUENCE`).  I couldn't find a lookup table in the database that translated the tokens, but here it is:
610
```
611
1 = Address lines
612
2 = City
613
3 = State/Province
614
4 = Postcode
615
5 = Country
616
6 = Country abbreviation
617
9 = County
618
101 = :
619
102 = ,
620
103 = -
621
104 = .
622
105 = /
623
106 = <space>
624
```
625
626 21 Jon Goldberg
## Financial accounts
627
I believe that their presence in RE is set by a flag `GENERAL_INFORMATION.GL_PRESENT`, with `GENERAL_INFORMATION.GL_ENG_TYPE` playing a role (I believe dealing with Financial Edge integration).
628
The relevant fields are:
629
* `FUND` (relates to `GIFT.FundId`).
630
* `FUNDDISTRIBUTION` (connector table, also connects to Gift Type and Subtype, which are also set on the Gift.  You can have different Financial Accounts based on a combination of FundId, TypeId, and SubTypeId).
631
* `GLDISTRIBUTIONDETAIL` (Contains GL Account codes, etc. Looks like it contains some Quickbooks integration fields. Most similar to `civicrm_financial_account`.)
632
* `GLDISTRIBUTION` (This also links to `FUNDDISTRIBUTION` but AFAICT has no data that needs migrating to CiviCRM).
633
634
## Misc
635
636
Some RE tables and what they're for (and their equivalents in Civi if applicable):
637
`GENERAL_INFORMATION`: Similar to both `civicrm_domain` and `civicrm_settings`.  Version number, Organization name, license number, general settings, etc.
638 1 Jon Goldberg
639
## Media
640
641
### Exporting from RE
642
643
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.
644
645 19 Jon Goldberg
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: 
646
```sql
647 1 Jon Goldberg
SELECT OBJECT FROM [dbo].[MEDIA]
648
```
649
650
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.
651
652
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:
653
```
654
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
655
```
656
657
### Importing into CiviCRM
658
659
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.
660
661
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:
662 19 Jon Goldberg
```php
663 1 Jon Goldberg
$result = civicrm_api3('Attachment', 'create', array(
664
  'sequential' => 1,
665
  'name' => "drill.jpg",
666
  'mime_type' => "image/jpeg",
667
  'entity_id' => 628,
668
  'entity_table' => "civicrm_activity",
669
  'options' => array('move-file' => "/home/jon/local/civicrm-buildkit/build/d46/sites/default/files/civicrm/custom/drill.jpg"),
670
));
671
```
672
673
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!
674
675
If you use the API CSV import tool, your CSVs should look like this:
676
```
677
"name",entity_id,"entity_table","mime_type","options.move-file"
678
"100.png",87511,"civicrm_activity","image/png","/home/jon/local/lccr/wp-content/plugins/files/civicrm/custom/100.png"
679
"1000.pdf",88411,"civicrm_activity","application/pdf","/home/jon/local/lccr/wp-content/plugins/files/civicrm/custom/1000.pdf"
680
```
681
682
## And More
683
684
### Tables that Civi doesn't have a direct counterpart for
685
686
* Aliases (stores Maiden Name and d/b/a - unsure how to import into Civi just yet)
687
* 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.
688
689
690
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.
691
692
693
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.
694
695
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.
696
697
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.
698
699
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.
700
701
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".
702
703
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.
704
705
NOTE: Letters sent is incomplete, there's more than 12 letters to some folks!
706
707
GIFTS is related to constituent on the last column (Constituent System Record ID)
708
709
### Code Tables/Option Groups/Option Values
710
711
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).
712
713
## Deciphering MS SQL
714
715
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.
716
717
### Looking Up Functions
718
719
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.
720
721
### Looking Up Stored Procedures
722
723
If, in the profiler, taking a certain action shows a command like this:
724
These have a syntax like:
725 19 Jon Goldberg
```sql
726 1 Jon Goldberg
exec sp_execute 48,43,'Acknowledgee'
727
```
728
729
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:
730 19 Jon Goldberg
```sql
731 1 Jon Goldberg
declare `p1 int
732
set `p1=48
733
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'
734
select `p1
735
```
736
737
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.
738
739
### Addressee/Postal Greeting/E-mail greeting
740
741
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.
742
743
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:
744 19 Jon Goldberg
```sql
745 1 Jon Goldberg
/****** Script for SelectTopNRows command from SSMS  ******/
746
SELECT s.ID
747
, sf1.FIELDNAME as FIELD1
748
, sf2.FIELDNAME as FIELD2
749
, sf3.FIELDNAME as FIELD3
750
, sf4.FIELDNAME as FIELD4
751
, sf5.FIELDNAME as FIELD5
752
, sf6.FIELDNAME as FIELD6
753
, sf7.FIELDNAME as FIELD7
754
, sf8.FIELDNAME as FIELD8
755
, sf9.FIELDNAME as FIELD9
756
, sf10.FIELDNAME as FIELD10     
757
, sf11.FIELDNAME as FIELD11
758
, sf12.FIELDNAME as FIELD12
759
, sf13.FIELDNAME as FIELD13
760
, sf14.FIELDNAME as FIELD14
761
, sf15.FIELDNAME as FIELD15
762
, sf16.FIELDNAME as FIELD16
763
, sf17.FIELDNAME as FIELD17
764
, sf18.FIELDNAME as FIELD18
765
, sf19.FIELDNAME as FIELD19
766
, sf20.FIELDNAME as FIELD20
767
  FROM SALUTATIONS s
768
  LEFT JOIN SALUTATION_FIELDS sf1 on CODE1 = sf1.ID
769
  LEFT JOIN SALUTATION_FIELDS sf2 on CODE2 = sf2.ID
770
  LEFT JOIN SALUTATION_FIELDS sf3 on CODE3 = sf3.ID
771
  LEFT JOIN SALUTATION_FIELDS sf4 on CODE4 = sf4.ID
772
  LEFT JOIN SALUTATION_FIELDS sf5 on CODE5 = sf5.ID
773
  LEFT JOIN SALUTATION_FIELDS sf6 on CODE6 = sf6.ID
774
  LEFT JOIN SALUTATION_FIELDS sf7 on CODE7 = sf7.ID
775
  LEFT JOIN SALUTATION_FIELDS sf8 on CODE8 = sf8.ID
776
  LEFT JOIN SALUTATION_FIELDS sf9 on CODE9 = sf9.ID
777
  LEFT JOIN SALUTATION_FIELDS sf10 on CODE10 = sf10.ID
778
  LEFT JOIN SALUTATION_FIELDS sf11 on CODE11 = sf11.ID
779
  LEFT JOIN SALUTATION_FIELDS sf12 on CODE12 = sf12.ID
780
  LEFT JOIN SALUTATION_FIELDS sf13 on CODE13 = sf13.ID
781
  LEFT JOIN SALUTATION_FIELDS sf14 on CODE14 = sf14.ID
782
  LEFT JOIN SALUTATION_FIELDS sf15 on CODE15 = sf15.ID
783
  LEFT JOIN SALUTATION_FIELDS sf16 on CODE16 = sf16.ID
784
  LEFT JOIN SALUTATION_FIELDS sf17 on CODE17 = sf17.ID
785
  LEFT JOIN SALUTATION_FIELDS sf18 on CODE18 = sf18.ID
786
  LEFT JOIN SALUTATION_FIELDS sf19 on CODE19 = sf19.ID
787
  LEFT JOIN SALUTATION_FIELDS sf20 on CODE20 = sf20.ID
788 20 Jon Goldberg
```
789 1 Jon Goldberg
790
791
### Things I see that RE does better than Civi:
792
793
* 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.
794
* 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.
795
* 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.