Project

General

Profile

Exporting Raisers Edge for CiviCRM » History » Version 2

Jon Goldberg, 06/08/2018 02:25 PM

1 1 Jon Goldberg
{{lastupdated_at}} by {{lastupdated_by}}
2
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
```
65
SELECT RECORDSID AS external_identifier, LONGDESCRIPTION as solicit_code FROM CONSTITUENT_SOLICITCODES JOIN TABLEENTRIES ON SOLICIT_CODE = TABLEENTRIES.TABLEENTRIESID WHERE TABLEENTRIES.ACTIVE = -1
66
```
67
68
In my copy of RE, the CODETABLESID is 5044, so to get a list of all solicit codes, use:
69
```
70
SELECT LONGDESCRIPTION, ACTIVE FROM TABLEENTRIES WHERE CODETABLESID = 5044 ORDER BY SEQUENCE;
71
```
72
73
### Addresses
74
75
SQL tables: ADDRESS, CONSTIT_ADDRESS
76
77
Addresses are a many-to-many relationship in RE.
78 2 Jon Goldberg
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.
79
80
Source: http://www.kb.blackbaud.co.uk/articles/Article/41141
81
The address Indicator field is located on the CONSTIT_ADDRESS table and can have the following values: 
82
~~~
83
0 = Alternate
84
1 = Contact
85
2 = Preferred (Primary Address entered on the Bio 1 tab of the constituent record)
86
3 = Business
87
4 = Spouse Business
88
5 = Spouse Preferred
89
6 = Spouse Alternate
90
7 = Relationship
91
~~~
92
93
### Primary Business Information 
94
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.
95 1 Jon Goldberg
96
### Phones/E-mail/websites
97
98
RE is a child of the 90's, so a) phones are tied to addresses, not contacts, and b) e-mails and websites are a type of phone.
99
100
Notes:
101
* You can NOT have duplicate phone types in RE, so no need to try and catch multiple "Home" numbers!
102
* Oh - except that one contact can have two home phone numbers on two different addresses.
103
* Don't forget to filter out duplicate numbers/e-mails/etc. when someone puts the same phone number on two different addresses.
104
105
This SQL gets me a useful list of phones and e-mail for further processing in Kettle:
106
```
107
SELECT DISTINCT
108
  CONSTITADDRESSID
109
, CONSTIT_ID
110
, PHONETYPEID
111
, CONSTIT_ADDRESS_PHONES."SEQUENCE"
112
, NUM
113
, DO_NOT_CALL
114
, TEXT_MSG
115
FROM CONSTIT_ADDRESS_PHONES
116
LEFT JOIN PHONES ON CONSTIT_ADDRESS_PHONES.PHONESID = PHONES.PHONESID
117
LEFT JOIN CONSTIT_ADDRESS ON CONSTITADDRESSID = CONSTIT_ADDRESS.ID
118
```
119
120
### Relationships
121
122
Relevant SQL table: CONSTIT_RELATIONSHIPS
123
124
Relationships are different in Civi and RE in the following significant ways:
125
* Relationships don't have to have a relationship type.
126
* 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".
127
* 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.
128
* There need not be a relationship type at all.  This doesn't make sense, except that:
129
* There are hardcoded fields for IS_SPOUSE, HON_MEM_ACKNOWLEDGE, IS_HEADOFHOUSEHOLD, and SOFTCREDIT_GIFTS.
130
131
Because relationships aren't necessarily reciprocal, I find it helpful to take my list of invalid relationships and do BOTH of the following:
132
* Look up the RELATIONSHIP_TYPE against the `name_b_a` field in `civicrm_relationship_type`.
133
* Look up the RECIP_RELATIONSHIP_TYPE against both `name_a_b` and `name_b_a` in `civicrm_relationship_type`.
134
135
### Solicitor Relationships
136
137
Solicitor relationships are stored in a different table.  I used this SQL to extract them:
138
```
139
SELECT
140
CONSTIT_ID
141
, SOLICITOR_ID
142
, TABLEENTRIES.LONGDESCRIPTION as solicitor_type
143
, AMOUNT
144
, NOTES
145
, cs."SEQUENCE" as weight
146
FROM CONSTIT_SOLICITORS cs
147
LEFT JOIN TABLEENTRIES ON cs.SOLICITOR_TYPE = TABLEENTRIES.TABLEENTRIESID
148
ORDER BY weight
149
```
150
151
### Attributes
152
153
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.
154
155
Valuable information about the setup of the attributes is available in RE from *Config > Attributes*.
156
157
* The analogous field to `civicrm_custom_field` is `AttributeTypes`.
158
* `AttributeTypes.CODETABLESID` gives a lookup for the RE "option group" that contains valid options for that attribute.
159
* 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.
160
 
161
Here's my preliminary SQL to export attributes from RE:
162
```
163
SELECT
164
ca.PARENTID as external_identifier
165
, ca.ATTRIBUTETYPESID
166
, at.DESCRIPTION as Category
167
, TABLEENTRIES.LONGDESCRIPTION as Description
168
, TEXT
169
, NUM
170
, DATETIME
171
, CURRENCY
172
, "BOOLEAN"
173
, COMMENTS
174
, ca.ATTRIBUTEDATE
175
FROM ConstituentAttributes ca
176
JOIN AttributeTypes at ON ca.ATTRIBUTETYPESID = at.ATTRIBUTETYPESID
177
LEFT JOIN TABLEENTRIES ON ca.TABLEENTRIESID = TABLEENTRIES.TABLEENTRIESID
178
```
179
180
*note:*  In the SQL above, "PARENTID" and not "ConstitID" is the correct foreign key to link this to the contact.
181
182
To get a list of option values out of RE for the attributes, use this SQL:
183
```
184
SELECT
185
DESCRIPTION
186
, at.CODETABLESID
187
, LONGDESCRIPTION
188
FROM TABLEENTRIES te 
189
LEFT JOIN AttributeTypes at ON te.CODETABLESID = at.CODETABLESID
190
ORDER BY DESCRIPTION
191
```
192
193
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:
194
```
195
SELECT ATTRIBUTETYPESID, PARENTID, COUNT(LONGDESCRIPTION)
196
FROM ConstituentAttributes ca
197
JOIN TABLEENTRIES te ON ca.TABLEENTRIESID = te.TABLEENTRIESID
198
GROUP BY PARENTID, ATTRIBUTETYPESID
199
HAVING COUNT(LONGDESCRIPTION) > 1
200
ORDER BY ATTRIBUTETYPESID
201
```
202
203
*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.
204
205
### Salutations/addressee info
206
207
RE stores contact salutations and addressee info in two places.
208
209
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`.
210
211
An unlimited number of non-primary salutations can be stored in the `CONSTITUENT_SALUTATION` table.
212
213
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".
214
215
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.
216
217
### Other constituent tables:
218
219
Skip these tables:
220
* Spouse
221
* Gifts
222
* First Gift, Last gift, Largest Gift
223
* Actions
224
* First Action, Last Action
225
* Summary Information
226
227
## Contribution-related exports
228
229
### Contributions/Gifts
230
231
Contributions (in RE parlance: Gifts) are complicated beasts!
232
233
Here are some relevant database tables and their equivalent in Civi:
234
GIFT	civicrm_contribution
235
GiftSplit	civicrm_line_item
236
CAMPAIGN	Roughly maps to Campaign.  Your mapping may vary and/or include custom fields.
237
APPEAL	Also roughly maps to Campaign (or Source).  Your mapping may vary and/or include custom fields.
238
FUND	Roughly maps to Financial Type, but you might choose to import as a custom field instead.
239
240
See "Campaigns, Appeals, Packages" below for more.
241
242
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).
243
244
Note that gift type is hardcoded into a function called "TranslateGiftType) - so you may want to include that function in your SQL, e.g.:
245
```
246
SELECT
247
gs.GiftId
248
, g.CONSTIT_ID
249
, gs.Amount
250
, g.DTE as gift_date
251
, FUND.DESCRIPTION as fund
252
, CAMPAIGN.DESCRIPTION as campaign
253
, APPEAL.DESCRIPTION as appeal
254
, g.PAYMENT_TYPE
255
, g.ACKNOWLEDGE_FLAG
256
, g.CHECK_NUMBER
257
, g.CHECK_DATE
258
, g.BATCH_NUMBER
259
, g.ANONYMOUS
260
, gst.LONGDESCRIPTION as giftsubtype
261
, g.TYPE
262
, DBO.TranslateGiftType(g.TYPE) as type2
263
FROM GiftSplit gs
264
LEFT JOIN FUND on gs.FundId = FUND.id
265
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
266
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
267
LEFT JOIN GIFT g on gs.GiftId = g.ID
268
LEFT JOIN TABLEENTRIES gst on g.GIFTSUBTYPE = gst.TABLEENTRIESID
269
```
270
271
(See here: http://www.re-decoded.com/2013/07/payment-type-or-payment-method-id-reference/#more-714)
272
273
Payment Type is also hard-coded, it seems:
274
1	Cash
275
2	Personal Check
276
3	Business Check
277
4	Credit Card
278
5 	Standing Order
279
6	Direct Debit
280
7	Voucher
281
8	Other
282
283
### Soft Credits
284
285
Stored in GIFTSOFTCREDIT.  RE does NOT have the concept of a soft credit type - which is fine.
286
```
287
SELECT
288
, GiftId
289
, ConstitId
290
, Amount
291
, 'Soft Credit' as soft_credit_type
292
FROM GiftSoftCredit
293
```
294
295
### Solicitor, Gift
296
297
(Important!  Gift solicitors are different from Contact Solicitors)
298
299
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:
300
```
301
SELECT
302
ParentId as gift_id
303
, SolicitorId as soft_creditee_external_identifier
304
, Amount
305
, 'Solicitor' as soft_credit_type
306
FROM GiftSolicitor
307
```
308
309
### In Honor/Memorial Of (aka Tributes)
310
311
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.  
312
313
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.
314
315
```
316
```
317
SELECT
318
```
319
gt.GIFT_ID
320
, gt.TRIBUTE_TYPE
321
, t.DESCRIPTION
322
, t.RECORDS_ID as tributee_extenal_identifier
323
, te.LONGDESCRIPTION as tribute_type
324
FROM GIFT_TRIBUTE gt
325
JOIN TRIBUTE t ON gt.TRIBUTE_ID = t.ID
326
LEFT JOIN TABLEENTRIES te on gt.TRIBUTE_TYPE = te.TABLEENTRIESID
327
```
328
329
### Pledges
330
331
Here are the relevant tables and their equivalents in Civi:
332
GIFT
333
Installment
334
InstallmentPayment
335
336
`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.  
337
338
`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.
339
340
*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.
341
342
The INSTALLMENT_FREQUENCY list is hard-coded:
343
|1| Annually|
344
|2| Every 6 Months|
345
|3| Every 3 Months|
346
|4| Every 2 Months|
347
|5| Every Month|
348
|6| Due Twice/Month|
349
|9| Irregular|
350
|10| Single Installment|
351
352
Some SQL:
353
```
354
/* Find all GIFT records with one or more associated Installment records.  These are pledges OR recurring gifts. */
355
SELECT DISTINCT
356
g.CONSTIT_ID
357
, g.ID as GiftId
358
, g.Amount
359
, g.DTE as receive_date
360
, FUND.DESCRIPTION as fund
361
, FUND.FUND_ID
362
, CAMPAIGN.DESCRIPTION as campaign
363
, APPEAL.DESCRIPTION as appeal
364
, g.PAYMENT_TYPE
365
, g.ACKNOWLEDGEDATE
366
, DBO.TranslateGiftType(g.TYPE) as type
367
, g.REF as note
368
,DATE_1ST_PAY
369
,g.DATEADDED
370
,g.DATECHANGED
371
,INSTALLMENT_FREQUENCY
372
,NUMBER_OF_INSTALLMENTS
373
,POST_DATE
374
,POST_STATUS
375
,REMIND_FLAG
376
,Schedule_Month
377
,Schedule_DayOfMonth
378
,Schedule_MonthlyDayOfWeek
379
,Schedule_Spacing
380
,Schedule_MonthlyType
381
,Schedule_MonthlyOrdinal
382
,Schedule_WeeklyDayOfWeek
383
,Schedule_DayOfMonth2
384
,Schedule_SMDayType1
385
,Schedule_SMDayType2
386
,NextTransactionDate
387
,Schedule_EndDate
388
,FrequencyDescription
389
, r.CONSTITUENT_ID
390
FROM Gift g
391
LEFT JOIN GiftSplit gs on g.ID = gs.GiftId
392
LEFT JOIN FUND on gs.FundId = FUND.id
393
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
394
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
395
LEFT JOIN RECORDS r ON g.CONSTIT_ID = r.ID
396
JOIN Installment i ON g.ID = i.PledgeId
397
```
398
399
Find pledge payments:
400
```
401
/* Find all pledge installments, and their related payments if they exist. */
402
SELECT
403
i.InstallmentId
404
, i.PledgeId
405
, i.AdjustmentId
406
, i.Amount as scheduled_amount
407
, i.Dte
408
, ip.Amount as actual_amount
409
, ip.PaymentId
410
, g.CONSTIT_ID
411
, g.RECEIPT_AMOUNT
412
, g.DTE as receive_date
413
, g.TYPE
414
, DBO.TranslateGiftType(g.TYPE) as type
415
FROM Installment i
416
LEFT JOIN InstallmentPayment ip ON i.InstallmentId = ip.InstallmentId
417
LEFT JOIN GIFT g ON ip.PaymentId = g.ID
418
/* Adjustments are stored in here too - when an adjustment happens, the pledge ID of the original value is blanked */
419
WHERE i.PledgeId IS NOT NULL 
420
ORDER BY i.AdjustmentId
421
/* Write-off Types: Covenant WriteOff, MG Write Off, Write Off */
422
```
423
424
## Campaigns, Appeals, Packages
425
426
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.
427
428
429
## Actions
430
431
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:
432
```
433
SELECT
434
  a.ADDED_BY
435
, a.AUTO_REMIND
436
, a.RECORDS_ID as external_identifier
437
, cr.RELATION_ID as action_contact_id
438
, a.DTE as activity_date_time
439
, LETTER.LONGDESCRIPTION as letter
440
, a.PRIORITY as priority_id
441
, a.REMIND_VALUE
442
, a.CATEGORY
443
, a.Completed
444
, a.COMPLETED_DATE
445
, a.FUND_ID
446
, a.FOLLOWUPTO_ID
447
, a.TRACKACTION_ID
448
, a.PhoneNumber as phone_number
449
, a.Remind_Frequency
450
, a.WORDDOCNAME
451
, a.APPEAL_ID
452
, a.APPEAL_LETTER_CODE
453
, a.OUTLOOK_EMAIL_SUBJECT
454
, STATUS.LONGDESCRIPTION as status
455
, TYPE.LONGDESCRIPTION as type
456
, LOCATION.LONGDESCRIPTION as location
457
, ActionNotepad.ActualNotes
458
, CAMPAIGN.DESCRIPTION as campaign
459
FROM ACTIONS a
460
LEFT JOIN TABLEENTRIES as STATUS ON a.STATUS = STATUS.TABLEENTRIESID
461
LEFT JOIN TABLEENTRIES as TYPE ON a.[TYPE] = [TYPE].TABLEENTRIESID
462
LEFT JOIN TABLEENTRIES as LOCATION ON a.[Location] = LOCATION.TABLEENTRIESID 
463
LEFT JOIN TABLEENTRIES as LETTER on a.[LETTER_CODE] = LETTER.TABLEENTRIESID
464
LEFT JOIN ActionNotepad ON a.ID = ActionNotepad.ParentId
465
LEFT JOIN CAMPAIGN on a.CAMPAIGN_ID = CAMPAIGN.id
466
LEFT JOIN CONSTIT_RELATIONSHIPS cr on a.CONTACT_ID = cr.ID
467
```
468
469
"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.
470
471
*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.
472
473
## Action Notes
474
475
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:
476
```
477
SELECT
478
  NotesID
479
, Title
480
, Description
481
, Author
482
, ActualNotes
483
, ParentId
484
, NotepadDate
485
, TABLEENTRIES.LONGDESCRIPTION as Type
486
  FROM ActionNotepad
487
  LEFT JOIN TABLEENTRIES ON ActionNotepad.NoteTypeId = TABLEENTRIES.TABLEENTRIESID
488
ORDER BY ParentId, ActionNotepad."SEQUENCE"
489
```
490
491
## Events
492
493
Events are stored fairly similarly to CiviCRM, except:
494
* locations are stored on the event record itself (which I'm not dealing with).
495
* There's fields for storing data about classes.  I haven't delved into this - I suspect that this may tie into recurring events.
496
* "Event Category" and "Event Type" might both map to Civi's "Event Type".  This isn't the case for me.
497
* 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.
498
499
Here's some SQL to pull in the most relevant data:
500
```
501
SELECT
502
  se.CAPACITY
503
, se.END_DATE
504
, se.ID
505
, se.NAME
506
, se.START_DATE
507
, se.DATE_ADDED
508
, te.LONGDESCRIPTION as activity_type
509
, se.INACTIVE
510
, se.DISPLAYONCALENDAR
511
, CAMPAIGN.DESCRIPTION as campaign
512
, se.DESCRIPTION
513
FROM SPECIAL_EVENT se
514
LEFT JOIN CAMPAIGN on se.CAMPAIGN_ID = CAMPAIGN.id 
515
LEFT JOIN TABLEENTRIES te ON se.TYPEID = te.TABLEENTRIESID
516
```
517
518
## Notes
519
520
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). 
521
522
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.
523
524
It may be possible to export the photos in the Notes using the techniques described below under "Media".
525
526
Here's the SQL I'm currently using to extract notes before doing transforms in Kettle:
527
```
528
SELECT
529
Title as subject
530
, Description
531
, Author
532
, ActualNotes
533
, ParentId
534
, cn.DateChanged
535
, LONGDESCRIPTION as NoteType
536
FROM ConstituentNotepad cn
537
LEFT JOIN TABLEENTRIES ON NoteTypeId = TABLEENTRIESID
538
```
539
540
## Media
541
542
### Exporting from RE
543
544
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.
545
546
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: ```
547
SELECT OBJECT FROM [dbo].[MEDIA]
548
```
549
550
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.
551
552
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:
553
```
554
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
555
```
556
557
### Importing into CiviCRM
558
559
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.
560
561
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:
562
```
563
$result = civicrm_api3('Attachment', 'create', array(
564
  'sequential' => 1,
565
  'name' => "drill.jpg",
566
  'mime_type' => "image/jpeg",
567
  'entity_id' => 628,
568
  'entity_table' => "civicrm_activity",
569
  'options' => array('move-file' => "/home/jon/local/civicrm-buildkit/build/d46/sites/default/files/civicrm/custom/drill.jpg"),
570
));
571
```
572
573
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!
574
575
If you use the API CSV import tool, your CSVs should look like this:
576
```
577
"name",entity_id,"entity_table","mime_type","options.move-file"
578
"100.png",87511,"civicrm_activity","image/png","/home/jon/local/lccr/wp-content/plugins/files/civicrm/custom/100.png"
579
"1000.pdf",88411,"civicrm_activity","application/pdf","/home/jon/local/lccr/wp-content/plugins/files/civicrm/custom/1000.pdf"
580
```
581
582
## And More
583
584
### Tables that Civi doesn't have a direct counterpart for
585
586
* Aliases (stores Maiden Name and d/b/a - unsure how to import into Civi just yet)
587
* 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.
588
589
590
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.
591
592
593
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.
594
595
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.
596
597
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.
598
599
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.
600
601
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".
602
603
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.
604
605
NOTE: Letters sent is incomplete, there's more than 12 letters to some folks!
606
607
GIFTS is related to constituent on the last column (Constituent System Record ID)
608
609
### Code Tables/Option Groups/Option Values
610
611
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).
612
613
## Deciphering MS SQL
614
615
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.
616
617
### Looking Up Functions
618
619
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.
620
621
### Looking Up Stored Procedures
622
623
If, in the profiler, taking a certain action shows a command like this:
624
These have a syntax like:
625
```
626
exec sp_execute 48,43,'Acknowledgee'
627
```
628
629
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:
630
```
631
declare `p1 int
632
set `p1=48
633
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'
634
select `p1
635
```
636
637
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.
638
639
640
### Addressee/Postal Greeting/E-mail greeting
641
642
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.
643
644
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:
645
```<code class="sql">
646
/****** Script for SelectTopNRows command from SSMS  ******/
647
SELECT s.ID
648
, sf1.FIELDNAME as FIELD1
649
, sf2.FIELDNAME as FIELD2
650
, sf3.FIELDNAME as FIELD3
651
, sf4.FIELDNAME as FIELD4
652
, sf5.FIELDNAME as FIELD5
653
, sf6.FIELDNAME as FIELD6
654
, sf7.FIELDNAME as FIELD7
655
, sf8.FIELDNAME as FIELD8
656
, sf9.FIELDNAME as FIELD9
657
, sf10.FIELDNAME as FIELD10     
658
, sf11.FIELDNAME as FIELD11
659
, sf12.FIELDNAME as FIELD12
660
, sf13.FIELDNAME as FIELD13
661
, sf14.FIELDNAME as FIELD14
662
, sf15.FIELDNAME as FIELD15
663
, sf16.FIELDNAME as FIELD16
664
, sf17.FIELDNAME as FIELD17
665
, sf18.FIELDNAME as FIELD18
666
, sf19.FIELDNAME as FIELD19
667
, sf20.FIELDNAME as FIELD20
668
  FROM SALUTATIONS s
669
  LEFT JOIN SALUTATION_FIELDS sf1 on CODE1 = sf1.ID
670
  LEFT JOIN SALUTATION_FIELDS sf2 on CODE2 = sf2.ID
671
  LEFT JOIN SALUTATION_FIELDS sf3 on CODE3 = sf3.ID
672
  LEFT JOIN SALUTATION_FIELDS sf4 on CODE4 = sf4.ID
673
  LEFT JOIN SALUTATION_FIELDS sf5 on CODE5 = sf5.ID
674
  LEFT JOIN SALUTATION_FIELDS sf6 on CODE6 = sf6.ID
675
  LEFT JOIN SALUTATION_FIELDS sf7 on CODE7 = sf7.ID
676
  LEFT JOIN SALUTATION_FIELDS sf8 on CODE8 = sf8.ID
677
  LEFT JOIN SALUTATION_FIELDS sf9 on CODE9 = sf9.ID
678
  LEFT JOIN SALUTATION_FIELDS sf10 on CODE10 = sf10.ID
679
  LEFT JOIN SALUTATION_FIELDS sf11 on CODE11 = sf11.ID
680
  LEFT JOIN SALUTATION_FIELDS sf12 on CODE12 = sf12.ID
681
  LEFT JOIN SALUTATION_FIELDS sf13 on CODE13 = sf13.ID
682
  LEFT JOIN SALUTATION_FIELDS sf14 on CODE14 = sf14.ID
683
  LEFT JOIN SALUTATION_FIELDS sf15 on CODE15 = sf15.ID
684
  LEFT JOIN SALUTATION_FIELDS sf16 on CODE16 = sf16.ID
685
  LEFT JOIN SALUTATION_FIELDS sf17 on CODE17 = sf17.ID
686
  LEFT JOIN SALUTATION_FIELDS sf18 on CODE18 = sf18.ID
687
  LEFT JOIN SALUTATION_FIELDS sf19 on CODE19 = sf19.ID
688
  LEFT JOIN SALUTATION_FIELDS sf20 on CODE20 = sf20.ID
689
</code>```
690
691
692
### Things I see that RE does better than Civi:
693
694
* 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.
695
* 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.
696
* 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.