Project

General

Profile

Exporting Raisers Edge for CiviCRM » History » Version 42

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