Project

General

Profile

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

Jon Goldberg, 12/27/2014 05:26 PM

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
Export as _one to many_, below.
57
These can map to groups - but also may map to privacy preferences or custom fields (e.g. Email Only, Do Not Solicit)
58
Export the "Solicit Code" only (along with the Constituent's System Record ID, of course).
59 3 Jon Goldberg
60 20 Jon Goldberg
h3. Addresses
61
62
SQL tables: ADDRESS, CONSTIT_ADDRESS
63
64
Addresses are a many-to-many relationship in RE.
65 27 Jon Goldberg
Not all addresses in the database are visible in RE.  Addresses with a 1 or 7, for instance.  Make sure to look your data over and filter those out accordingly.
66 20 Jon Goldberg
67 25 Jon Goldberg
h3. Phones/E-mail/websites
68 1 Jon Goldberg
69 25 Jon Goldberg
RE is a children of the 90's, so a) phones are tied to addresses, not contacts, and b) e-mails and websites are a type of phone.
70
71 26 Jon Goldberg
Notes:
72
* You can NOT have duplicate phone types in RE, so no need to try and catch multiple "Home" numbers!
73
* Oh - except that one contact can have two home phone numbers on two different addresses.
74
* Don't forget to filter out duplicate numbers/e-mails/etc. when someone puts the same phone number on two different addresses.
75 22 Jon Goldberg
76
This SQL gets me a useful list of phones and e-mail for further processing in Kettle:
77
<pre>
78
SELECT DISTINCT
79
  CONSTITADDRESSID
80
, CONSTIT_ID
81
, PHONETYPEID
82
, CONSTIT_ADDRESS_PHONES."SEQUENCE"
83
, NUM
84
, DO_NOT_CALL
85
, TEXT_MSG
86
FROM CONSTIT_ADDRESS_PHONES
87
LEFT JOIN PHONES ON CONSTIT_ADDRESS_PHONES.PHONESID = PHONES.PHONESID
88
LEFT JOIN CONSTIT_ADDRESS ON CONSTITADDRESSID = CONSTIT_ADDRESS.ID
89
</pre>
90
91 9 Jon Goldberg
h3. Relationships
92
93 29 Jon Goldberg
Relevant SQL table: CONSTIT_RELATIONSHIPS
94
95 9 Jon Goldberg
Relationships are different in Civi and RE in the following significant ways:
96
* Relationships don't have to have a relationship type.
97 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".
98 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.
99 30 Jon Goldberg
* There need not be a relationship type at all.  This doesn't make sense, except that:
100
* There are hardcoded fields for IS_SPOUSE, HON_MEM_ACKNOWLEDGE, IS_HEADOFHOUSEHOLD, and SOFTCREDIT_GIFTS.
101
102 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:
103
* Look up the RELATIONSHIP_TYPE against the @name_b_a@ field in @civicrm_relationship_type@.
104
* Look up the RECIP_RELATIONSHIP_TYPE against both @name_a_b@ and @name_b_a@ in @civicrm_relationship_type@.
105 9 Jon Goldberg
106 10 Jon Goldberg
h3. Attributes
107
108
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.
109
110 11 Jon Goldberg
Valuable information about the setup of the attributes is available in RE from *Config > Attributes*.
111 1 Jon Goldberg
112 33 Jon Goldberg
* The analogous field to @civicrm_custom_field@ is @AttributeTypes@.
113
* @AttributeTypes.CODETABLESID@ gives a lookup for the RE "option group" that contains valid options for that attribute.
114 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.
115
 
116 33 Jon Goldberg
Here's my preliminary SQL to export attributes from RE:
117
<pre>
118
SELECT
119 36 Jon Goldberg
ca.PARENTID as external_identifier
120
, ca.ATTRIBUTETYPESID
121
, at.DESCRIPTION as Category
122
, TABLEENTRIES.LONGDESCRIPTION as Description
123 33 Jon Goldberg
, TEXT
124
, NUM
125
, DATETIME
126
, CURRENCY
127
, "BOOLEAN"
128 35 Jon Goldberg
, COMMENTS
129 33 Jon Goldberg
, ca.ATTRIBUTEDATE
130
FROM ConstituentAttributes ca
131
JOIN AttributeTypes at ON ca.ATTRIBUTETYPESID = at.ATTRIBUTETYPESID
132 36 Jon Goldberg
LEFT JOIN TABLEENTRIES ON ca.TABLEENTRIESID = TABLEENTRIES.TABLEENTRIESID
133 33 Jon Goldberg
</pre>
134
135 34 Jon Goldberg
*note:*  In the SQL above, "PARENTID" and not "ConstitID" is the correct foreign key to link this to the contact.
136
137 38 Jon Goldberg
To get a list of option values out of RE for the attributes, use this SQL:
138
<pre>
139
SELECT
140
DESCRIPTION
141
, at.CODETABLESID
142
, LONGDESCRIPTION
143
FROM TABLEENTRIES te 
144
LEFT JOIN AttributeTypes at ON te.CODETABLESID = at.CODETABLESID
145
ORDER BY DESCRIPTION
146
</pre>
147
148 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:
149
<pre>
150
SELECT ATTRIBUTETYPESID, PARENTID, COUNT(LONGDESCRIPTION)
151
FROM ConstituentAttributes ca
152
JOIN TABLEENTRIES te ON ca.TABLEENTRIESID = te.TABLEENTRIESID
153
GROUP BY PARENTID, ATTRIBUTETYPESID
154
HAVING COUNT(LONGDESCRIPTION) > 1
155
ORDER BY ATTRIBUTETYPESID
156
</pre>
157
158 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.
159 10 Jon Goldberg
160 3 Jon Goldberg
h3. Other constituent tables:
161 5 Jon Goldberg
162 2 Jon Goldberg
Skip these tables:
163
* Spouse
164
* Gifts
165
* First Gift, Last gift, Largest Gift
166
* Actions
167 1 Jon Goldberg
* First Action, Last Action
168
* Summary Information
169
170 41 Jon Goldberg
h2. Contribution-related exports
171
172
h3. Contributions/Gifts
173
174
Contributions (in RE parlance: Gifts) are complicated beasts!
175
176
Here are some relevant database tables and their equivalent in Civi:
177
GIFT	civicrm_contribution
178
GiftSplit	civicrm_line_item
179
CAMPAIGN	Roughly maps to Campaign.  Your mapping may vary and/or include custom fields.
180
APPEAL	Also roughly maps to Campaign (or Source).  Your mapping may vary and/or include custom fields.
181
FUND	Roughly maps to Financial Type.  Your mapping may vary and/or include custom fields.
182
183
Note that gift type is hardcoded into a function called "TranslateGiftType) - so you may want to include that function in your SQL, e.g.:
184
<pre>
185
SELECT
186
gs.GiftId
187
, g.CONSTIT_ID
188
, gs.Amount
189
, g.DTE as gift_date
190
, FUND.DESCRIPTION as fund
191
, CAMPAIGN.DESCRIPTION as campaign
192
, APPEAL.DESCRIPTION as appeal
193
, g.PAYMENT_TYPE
194
, g.ACKNOWLEDGE_FLAG
195
, g.CHECK_NUMBER
196
, g.CHECK_DATE
197
, g.BATCH_NUMBER
198
, g.ANONYMOUS
199
, gst.LONGDESCRIPTION as giftsubtype
200
, g.TYPE
201
, DBO.TranslateGiftType(g.TYPE) as type2
202
FROM GiftSplit gs
203
LEFT JOIN FUND on gs.FundId = FUND.id
204
LEFT JOIN APPEAL on gs.AppealId = APPEAL.id
205
LEFT JOIN CAMPAIGN on gs.CampaignId = CAMPAIGN.id 
206
LEFT JOIN GIFT g on gs.GiftId = g.ID
207
LEFT JOIN TABLEENTRIES gst on g.GIFTSUBTYPE = gst.TABLEENTRIESID
208
</pre>
209
210 42 Jon Goldberg
Payment Type is also hard-coded, it seems:
211
1	Cash
212
2	Personal Check
213
3	Business Check
214
4	Credit Card
215
6	Direct Debit
216
8	Other
217
218
h3. Soft Credits
219
220
Stored in GIFTSOFTCREDIT.  RE does NOT have the concept of a soft credit type - which is fine.
221
<pre>
222
SELECT
223
, GiftId
224
, ConstitId
225
, Amount
226
, 'Soft Credit' as soft_credit_type
227
FROM GiftSoftCredit
228
</pre>
229
230
h3. Solicitor
231
232
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:
233
<pre>
234
SELECT
235
ParentId as gift_id
236
, SolicitorId as soft_creditee_external_identifier
237
, Amount
238
, 'Solicitor' as soft_credit_type
239
FROM GiftSolicitor
240
</pre>
241
242 41 Jon Goldberg
h3. In Honor/Memorial Of (aka Tributes)
243
244
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.  
245
246
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.
247
248
<pre>
249
SELECT
250
gt.GIFT_ID
251
, gt.TRIBUTE_TYPE
252
, t.DESCRIPTION
253
, t.RECORDS_ID as tributee_extenal_identifier
254
, te.LONGDESCRIPTION as tribute_type
255
FROM GIFT_TRIBUTE gt
256
JOIN TRIBUTE t ON gt.TRIBUTE_ID = t.ID
257
LEFT JOIN TABLEENTRIES te on gt.TRIBUTE_TYPE = te.TABLEENTRIESID
258
</pre>
259
260 45 Jon Goldberg
h2. Notes
261
262
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). 
263
264
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.
265
266
Once I revisit the "Media" data, I may figure out a way to extract photos, which I could then add to notes as attachments.
267
268 46 Jon Goldberg
Here's the SQL I'm currently using to extract notes before doing transforms in Kettle:
269
<pre>
270
SELECT
271
Title as subject
272
, Description
273
, Author
274
, ActualNotes
275
, ParentId
276
, cn.DateChanged
277
, LONGDESCRIPTION as NoteType
278
FROM ConstituentNotepad cn
279
LEFT JOIN TABLEENTRIES ON NoteTypeId = TABLEENTRIESID
280
</pre>
281
282 43 Jon Goldberg
h2. And More
283
284 7 Jon Goldberg
h3. Tables that Civi doesn't have a direct counterpart for
285 5 Jon Goldberg
286 3 Jon Goldberg
* Aliases (stores Maiden Name and d/b/a - unsure how to import into Civi just yet)
287 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.
288 2 Jon Goldberg
289
290
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.
291
292 1 Jon Goldberg
293
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.
294
295
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.
296
297
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.
298
299
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.
300
301
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".
302
303
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.
304
305
NOTE: Letters sent is incomplete, there's more than 12 letters to some folks!
306
307
GIFTS is related to constituent on the last column (Constituent System Record ID)
308 8 Jon Goldberg
309 13 Jon Goldberg
h3. Code Tables/Option Groups/Option Values
310
311 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).
312
313
h2. Deciphering MS SQL
314
315
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.
316
317
h3. Looking Up Functions
318
319
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.
320
321
h3. Looking Up Stored Procedures
322
323 18 Jon Goldberg
If, in the profiler, taking a certain action shows a command like this:
324 17 Jon Goldberg
These have a syntax like:
325 1 Jon Goldberg
<pre>
326 18 Jon Goldberg
exec sp_execute 48,43,'Acknowledgee'
327 1 Jon Goldberg
</pre>
328
329 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:
330
<pre>
331
declare @p1 int
332
set @p1=48
333
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'
334
select @p1
335
</pre>
336
337 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.
338 17 Jon Goldberg
339 13 Jon Goldberg
340 14 Jon Goldberg
h3. Addressee/Postal Greeting/E-mail greeting
341
342
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.
343
344 8 Jon Goldberg
See also:
345
http://support.littlegreenlight.com/kb/migration/migrating-from-the-raisers-edge-to-lgl
346 14 Jon Goldberg
347
h3. Things I see that RE does better than Civi:
348
349
* 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.
350
* 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.
351 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