Project

General

Profile

Exporting Raiser's Edge for CiviCRM » History » Version 58

Jon Goldberg, 08/31/2015 11:42 AM
Update Solicit Code section

1 44 Jon Goldberg
{{lastupdated_at}} by {{lastupdated_by}}
2
3 24 Jon Goldberg
{{toc}}
4
5 1 Jon Goldberg
h1. Exporting Raiser's Edge for CiviCRM
6
7 23 Jon Goldberg
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.
8 1 Jon Goldberg
9 47 Jon Goldberg
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
10
11 23 Jon Goldberg
h2. Export tool - general guide.
12
13
The Raiser's Edge Export tool is on the left toolbar when you first enter Raiser's Edge.
14
15 1 Jon Goldberg
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).
16
17 23 Jon Goldberg
For most export, select Constituent as the Export type.  This is the "base table" - all records will be joined relative to it.
18 3 Jon Goldberg
19 1 Jon Goldberg
h2. Constituent Based Exports
20
21 21 Jon Goldberg
h3. Contact Information
22 1 Jon Goldberg
23 23 Jon Goldberg
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".
24 1 Jon Goldberg
25 23 Jon Goldberg
h3. SQL
26
27 1 Jon Goldberg
If extracting directly from SQL, @SELECT * FROM RECORDS@.
28 21 Jon Goldberg
29 23 Jon Goldberg
Note that you can extract only constituents by adding @WHERE IS_CONSTITUENT = -1@.  For a Civi migration, I recommend importing all contacts.
30 21 Jon Goldberg
31 23 Jon Goldberg
h3. Export tool (NOTE: This ONLY gets constituents).
32
33 1 Jon Goldberg
Tab 1. General:
34
- Include all records.
35
- Head of Household processing: Export both constituents separately.
36
- Check all of the "Include these Constitutents": Inactive, deceased, no valid address
37
38
Tab 2: Output.
39
First, expand the "Constituent Information" in the left pane, and add every field to the export.  Do the export (as a CSV).
40 6 Jon Goldberg
41 3 Jon Goldberg
h3. Constituent Codes
42 15 Jon Goldberg
43 19 Jon Goldberg
In RE: Found at the bottom of the "Bio 2" tab.
44
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.
45 3 Jon Goldberg
46 1 Jon Goldberg
Export as _one to many_, below.
47 3 Jon Goldberg
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.
48
49
No need to export these fields:
50
System Record ID
51
Import ID
52 23 Jon Goldberg
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.
53 6 Jon Goldberg
54
h3. Solicit Codes
55
56 1 Jon Goldberg
These can map to groups - but also may map to privacy preferences or custom fields (e.g. Email Only, Do Not Solicit)
57 58 Jon Goldberg
58
SQL to extract solicit codes:
59
<pre>
60
SELECT RECORDSID AS external_identifier, LONGDESCRIPTION as solicit_code FROM CONSTITUENT_SOLICITCODES JOIN TABLEENTRIES ON SOLICIT_CODE = TABLEENTRIES.TABLEENTRIESID WHERE TABLEENTRIES.ACTIVE = -1
61
</pre>
62
63
In my copy of RE, the CODETABLESID is 5044, so to get a list of all solicit codes, use:
64
<pre>
65
SELECT LONGDESCRIPTION, ACTIVE FROM TABLEENTRIES WHERE CODETABLESID = 5044 ORDER BY SEQUENCE;
66
</pre>
67
68 3 Jon Goldberg
69 20 Jon Goldberg
h3. Addresses
70
71
SQL tables: ADDRESS, CONSTIT_ADDRESS
72
73
Addresses are a many-to-many relationship in RE.
74 50 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.
75 20 Jon Goldberg
76 25 Jon Goldberg
h3. Phones/E-mail/websites
77 1 Jon Goldberg
78 55 Jon Goldberg
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.
79 25 Jon Goldberg
80 26 Jon Goldberg
Notes:
81
* You can NOT have duplicate phone types in RE, so no need to try and catch multiple "Home" numbers!
82
* Oh - except that one contact can have two home phone numbers on two different addresses.
83
* Don't forget to filter out duplicate numbers/e-mails/etc. when someone puts the same phone number on two different addresses.
84 22 Jon Goldberg
85
This SQL gets me a useful list of phones and e-mail for further processing in Kettle:
86
<pre>
87
SELECT DISTINCT
88
  CONSTITADDRESSID
89
, CONSTIT_ID
90
, PHONETYPEID
91
, CONSTIT_ADDRESS_PHONES."SEQUENCE"
92
, NUM
93
, DO_NOT_CALL
94
, TEXT_MSG
95
FROM CONSTIT_ADDRESS_PHONES
96
LEFT JOIN PHONES ON CONSTIT_ADDRESS_PHONES.PHONESID = PHONES.PHONESID
97
LEFT JOIN CONSTIT_ADDRESS ON CONSTITADDRESSID = CONSTIT_ADDRESS.ID
98
</pre>
99
100 9 Jon Goldberg
h3. Relationships
101
102 29 Jon Goldberg
Relevant SQL table: CONSTIT_RELATIONSHIPS
103
104 9 Jon Goldberg
Relationships are different in Civi and RE in the following significant ways:
105
* Relationships don't have to have a relationship type.
106 1 Jon Goldberg
* 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".
107 29 Jon Goldberg
* 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.
108 30 Jon Goldberg
* There need not be a relationship type at all.  This doesn't make sense, except that:
109
* There are hardcoded fields for IS_SPOUSE, HON_MEM_ACKNOWLEDGE, IS_HEADOFHOUSEHOLD, and SOFTCREDIT_GIFTS.
110
111 32 Jon Goldberg
Because relationships aren't necessarily reciprocal, I find it helpful to take my list of invalid relationships and do BOTH of the following:
112
* Look up the RELATIONSHIP_TYPE against the @name_b_a@ field in @civicrm_relationship_type@.
113
* Look up the RECIP_RELATIONSHIP_TYPE against both @name_a_b@ and @name_b_a@ in @civicrm_relationship_type@.
114 9 Jon Goldberg
115 53 Jon Goldberg
h3. Solicitor Relationships
116
117
Solicitor relationships are stored in a different table.  I used this SQL to extract them:
118
<pre>
119
SELECT
120
CONSTIT_ID
121
, SOLICITOR_ID
122
, TABLEENTRIES.LONGDESCRIPTION as solicitor_type
123
, AMOUNT
124
, NOTES
125
, cs."SEQUENCE" as weight
126
FROM CONSTIT_SOLICITORS cs
127
LEFT JOIN TABLEENTRIES ON cs.SOLICITOR_TYPE = TABLEENTRIES.TABLEENTRIESID
128
ORDER BY weight
129
</pre>
130
131 10 Jon Goldberg
h3. Attributes
132
133
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.
134
135 11 Jon Goldberg
Valuable information about the setup of the attributes is available in RE from *Config > Attributes*.
136 1 Jon Goldberg
137 33 Jon Goldberg
* The analogous field to @civicrm_custom_field@ is @AttributeTypes@.
138
* @AttributeTypes.CODETABLESID@ gives a lookup for the RE "option group" that contains valid options for that attribute.
139 37 Jon Goldberg
* 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.
140
 
141 33 Jon Goldberg
Here's my preliminary SQL to export attributes from RE:
142
<pre>
143
SELECT
144 36 Jon Goldberg
ca.PARENTID as external_identifier
145
, ca.ATTRIBUTETYPESID
146
, at.DESCRIPTION as Category
147
, TABLEENTRIES.LONGDESCRIPTION as Description
148 33 Jon Goldberg
, TEXT
149
, NUM
150
, DATETIME
151
, CURRENCY
152
, "BOOLEAN"
153 35 Jon Goldberg
, COMMENTS
154 33 Jon Goldberg
, ca.ATTRIBUTEDATE
155
FROM ConstituentAttributes ca
156
JOIN AttributeTypes at ON ca.ATTRIBUTETYPESID = at.ATTRIBUTETYPESID
157 36 Jon Goldberg
LEFT JOIN TABLEENTRIES ON ca.TABLEENTRIESID = TABLEENTRIES.TABLEENTRIESID
158 33 Jon Goldberg
</pre>
159
160 34 Jon Goldberg
*note:*  In the SQL above, "PARENTID" and not "ConstitID" is the correct foreign key to link this to the contact.
161
162 38 Jon Goldberg
To get a list of option values out of RE for the attributes, use this SQL:
163
<pre>
164
SELECT
165
DESCRIPTION
166
, at.CODETABLESID
167
, LONGDESCRIPTION
168
FROM TABLEENTRIES te 
169
LEFT JOIN AttributeTypes at ON te.CODETABLESID = at.CODETABLESID
170
ORDER BY DESCRIPTION
171
</pre>
172
173 39 Jon Goldberg
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:
174
<pre>
175
SELECT ATTRIBUTETYPESID, PARENTID, COUNT(LONGDESCRIPTION)
176
FROM ConstituentAttributes ca
177
JOIN TABLEENTRIES te ON ca.TABLEENTRIESID = te.TABLEENTRIESID
178
GROUP BY PARENTID, ATTRIBUTETYPESID
179
HAVING COUNT(LONGDESCRIPTION) > 1
180
ORDER BY ATTRIBUTETYPESID
181
</pre>
182
183 38 Jon Goldberg
*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.
184 10 Jon Goldberg
185 49 Jon Goldberg
h3. Salutations/addressee info
186 48 Jon Goldberg
187 49 Jon Goldberg
RE stores contact salutations and addressee info in two places.
188 48 Jon Goldberg
189 49 Jon Goldberg
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@.
190 1 Jon Goldberg
191 49 Jon Goldberg
An unlimited number of non-primary salutations can be stored in the @CONSTITUENT_SALUTATION@ table.
192 48 Jon Goldberg
193 49 Jon Goldberg
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".
194
195
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.
196 48 Jon Goldberg
197 3 Jon Goldberg
h3. Other constituent tables:
198 5 Jon Goldberg
199 2 Jon Goldberg
Skip these tables:
200
* Spouse
201
* Gifts
202
* First Gift, Last gift, Largest Gift
203
* Actions
204 1 Jon Goldberg
* First Action, Last Action
205
* Summary Information
206
207 41 Jon Goldberg
h2. Contribution-related exports
208
209
h3. Contributions/Gifts
210
211
Contributions (in RE parlance: Gifts) are complicated beasts!
212
213
Here are some relevant database tables and their equivalent in Civi:
214
GIFT	civicrm_contribution
215
GiftSplit	civicrm_line_item
216
CAMPAIGN	Roughly maps to Campaign.  Your mapping may vary and/or include custom fields.
217
APPEAL	Also roughly maps to Campaign (or Source).  Your mapping may vary and/or include custom fields.
218
FUND	Roughly maps to Financial Type.  Your mapping may vary and/or include custom fields.
219
220
Note that gift type is hardcoded into a function called "TranslateGiftType) - so you may want to include that function in your SQL, e.g.:
221
<pre>
222
SELECT
223
gs.GiftId
224
, g.CONSTIT_ID
225
, gs.Amount
226
, g.DTE as gift_date
227
, FUND.DESCRIPTION as fund
228
, CAMPAIGN.DESCRIPTION as campaign
229
, APPEAL.DESCRIPTION as appeal
230
, g.PAYMENT_TYPE
231
, g.ACKNOWLEDGE_FLAG
232
, g.CHECK_NUMBER
233
, g.CHECK_DATE
234
, g.BATCH_NUMBER
235
, g.ANONYMOUS
236
, gst.LONGDESCRIPTION as giftsubtype
237
, g.TYPE
238
, DBO.TranslateGiftType(g.TYPE) as type2
239
FROM GiftSplit gs
240
LEFT JOIN FUND on gs.FundId = FUND.id
241
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
242
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
243
LEFT JOIN GIFT g on gs.GiftId = g.ID
244
LEFT JOIN TABLEENTRIES gst on g.GIFTSUBTYPE = gst.TABLEENTRIESID
245
</pre>
246
247 42 Jon Goldberg
Payment Type is also hard-coded, it seems:
248
1	Cash
249
2	Personal Check
250
3	Business Check
251
4	Credit Card
252
6	Direct Debit
253
8	Other
254
255
h3. Soft Credits
256
257
Stored in GIFTSOFTCREDIT.  RE does NOT have the concept of a soft credit type - which is fine.
258
<pre>
259
SELECT
260
, GiftId
261
, ConstitId
262
, Amount
263
, 'Soft Credit' as soft_credit_type
264
FROM GiftSoftCredit
265
</pre>
266
267 52 Jon Goldberg
h3. Solicitor, Gift
268
269
(Important!  Gift solicitors are different from Contact Solicitors)
270 42 Jon Goldberg
271
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:
272
<pre>
273
SELECT
274
ParentId as gift_id
275
, SolicitorId as soft_creditee_external_identifier
276
, Amount
277
, 'Solicitor' as soft_credit_type
278
FROM GiftSolicitor
279
</pre>
280
281 41 Jon Goldberg
h3. In Honor/Memorial Of (aka Tributes)
282
283
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.  
284
285
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.
286
287
<pre>
288
SELECT
289
gt.GIFT_ID
290
, gt.TRIBUTE_TYPE
291
, t.DESCRIPTION
292
, t.RECORDS_ID as tributee_extenal_identifier
293
, te.LONGDESCRIPTION as tribute_type
294
FROM GIFT_TRIBUTE gt
295
JOIN TRIBUTE t ON gt.TRIBUTE_ID = t.ID
296
LEFT JOIN TABLEENTRIES te on gt.TRIBUTE_TYPE = te.TABLEENTRIESID
297
</pre>
298
299 51 Jon Goldberg
h2. Actions
300
301
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:
302
<pre>
303
SELECT
304
  a.ADDED_BY
305
, a.AUTO_REMIND
306
, a.RECORDS_ID as external_identifier
307
, cr.RELATION_ID as action_contact_id
308
, a.DTE as activity_date_time
309
, LETTER.LONGDESCRIPTION as letter
310
, a.PRIORITY as priority_id
311
, a.REMIND_VALUE
312
, a.CATEGORY
313
, a.Completed
314
, a.COMPLETED_DATE
315
, a.FUND_ID
316
, a.FOLLOWUPTO_ID
317
, a.TRACKACTION_ID
318
, a.PhoneNumber as phone_number
319
, a.Remind_Frequency
320
, a.WORDDOCNAME
321
, a.APPEAL_ID
322
, a.APPEAL_LETTER_CODE
323
, a.OUTLOOK_EMAIL_SUBJECT
324
, STATUS.LONGDESCRIPTION as status
325
, TYPE.LONGDESCRIPTION as type
326
, LOCATION.LONGDESCRIPTION as location
327
, ActionNotepad.ActualNotes
328
, CAMPAIGN.DESCRIPTION as campaign
329
FROM ACTIONS a
330
LEFT JOIN TABLEENTRIES as STATUS ON a.STATUS = STATUS.TABLEENTRIESID
331
LEFT JOIN TABLEENTRIES as TYPE ON a.[TYPE] = [TYPE].TABLEENTRIESID
332
LEFT JOIN TABLEENTRIES as LOCATION ON a.[Location] = LOCATION.TABLEENTRIESID 
333
LEFT JOIN TABLEENTRIES as LETTER on a.[LETTER_CODE] = LETTER.TABLEENTRIESID
334 56 Jon Goldberg
LEFT JOIN ActionNotepad ON a.ID = ActionNotepad.ParentId
335 51 Jon Goldberg
LEFT JOIN CAMPAIGN on a.CAMPAIGN_ID = CAMPAIGN.id
336
LEFT JOIN CONSTIT_RELATIONSHIPS cr on a.CONTACT_ID = cr.ID
337
</pre>
338
339 1 Jon Goldberg
"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.
340 56 Jon Goldberg
341
*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.
342 51 Jon Goldberg
343 57 Jon Goldberg
h2. Action Notes
344
345
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:
346
<pre>
347
SELECT
348
  NotesID
349
, Title
350
, Description
351
, Author
352
, ActualNotes
353
, ParentId
354
, NotepadDate
355
, TABLEENTRIES.LONGDESCRIPTION as Type
356
  FROM ActionNotepad
357
  LEFT JOIN TABLEENTRIES ON ActionNotepad.NoteTypeId = TABLEENTRIES.TABLEENTRIESID
358
ORDER BY ParentId, ActionNotepad."SEQUENCE"
359
</pre>
360
361 54 Jon Goldberg
h2. Events
362
363
Events are stored fairly similarly to CiviCRM, except:
364
* locations are stored on the event record itself (which I'm not dealing with).
365
* There's fields for storing data about classes.  I haven't delved into this - I suspect that this may tie into recurring events.
366
* "Event Category" and "Event Type" might both map to Civi's "Event Type".  This isn't the case for me.
367
* 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.
368
369
Here's some SQL to pull in the most relevant data:
370
<pre>
371
SELECT
372
  se.CAPACITY
373
, se.END_DATE
374
, se.ID
375
, se.NAME
376
, se.START_DATE
377
, se.DATE_ADDED
378
, te.LONGDESCRIPTION as activity_type
379
, se.INACTIVE
380
, se.DISPLAYONCALENDAR
381
, CAMPAIGN.DESCRIPTION as campaign
382
, se.DESCRIPTION
383
FROM SPECIAL_EVENT se
384
LEFT JOIN CAMPAIGN on se.CAMPAIGN_ID = CAMPAIGN.id 
385
LEFT JOIN TABLEENTRIES te ON se.TYPEID = te.TABLEENTRIESID
386
</pre>
387
388 45 Jon Goldberg
h2. Notes
389
390
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). 
391
392
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.
393
394
Once I revisit the "Media" data, I may figure out a way to extract photos, which I could then add to notes as attachments.
395
396 46 Jon Goldberg
Here's the SQL I'm currently using to extract notes before doing transforms in Kettle:
397
<pre>
398
SELECT
399
Title as subject
400
, Description
401
, Author
402
, ActualNotes
403
, ParentId
404
, cn.DateChanged
405
, LONGDESCRIPTION as NoteType
406
FROM ConstituentNotepad cn
407
LEFT JOIN TABLEENTRIES ON NoteTypeId = TABLEENTRIESID
408
</pre>
409
410 43 Jon Goldberg
h2. And More
411
412 7 Jon Goldberg
h3. Tables that Civi doesn't have a direct counterpart for
413 5 Jon Goldberg
414 3 Jon Goldberg
* Aliases (stores Maiden Name and d/b/a - unsure how to import into Civi just yet)
415 7 Jon Goldberg
* 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.
416 2 Jon Goldberg
417
418
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.
419
420 1 Jon Goldberg
421
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.
422
423
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.
424
425
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.
426
427
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.
428
429
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".
430
431
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.
432
433
NOTE: Letters sent is incomplete, there's more than 12 letters to some folks!
434
435
GIFTS is related to constituent on the last column (Constituent System Record ID)
436 8 Jon Goldberg
437 13 Jon Goldberg
h3. Code Tables/Option Groups/Option Values
438
439 17 Jon Goldberg
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).
440
441
h2. Deciphering MS SQL
442
443
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.
444
445
h3. Looking Up Functions
446
447
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.
448
449
h3. Looking Up Stored Procedures
450
451 18 Jon Goldberg
If, in the profiler, taking a certain action shows a command like this:
452 17 Jon Goldberg
These have a syntax like:
453 1 Jon Goldberg
<pre>
454 18 Jon Goldberg
exec sp_execute 48,43,'Acknowledgee'
455 1 Jon Goldberg
</pre>
456
457 18 Jon Goldberg
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:
458
<pre>
459
declare @p1 int
460
set @p1=48
461
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'
462
select @p1
463
</pre>
464
465 40 Jon Goldberg
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.
466 17 Jon Goldberg
467 13 Jon Goldberg
468 14 Jon Goldberg
h3. Addressee/Postal Greeting/E-mail greeting
469
470
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.
471
472 8 Jon Goldberg
See also:
473
http://support.littlegreenlight.com/kb/migration/migrating-from-the-raisers-edge-to-lgl
474 14 Jon Goldberg
475
h3. Things I see that RE does better than Civi:
476
477
* 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.
478
* 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.
479 28 Jon Goldberg
* 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.
Go to top