forked from twomice/com.joineryhq.jsumfields
-
Notifications
You must be signed in to change notification settings - Fork 0
/
jsumfields.php
2795 lines (2696 loc) · 116 KB
/
jsumfields.php
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<?php
require_once 'jsumfields.civix.php';
/**
* Implements hook_civicrm_apiWrappers().
*/
function jsumfields_civicrm_apiWrappers(&$wrappers, $apiRequest) {
if (strtolower($apiRequest['entity']) == 'sumfields' && strtolower($apiRequest['action']) == 'gendata') {
$wrappers[] = new CRM_Jsumfields_APIWrapperSumfieldsGendata();
}
}
/**
* Implements hook_civicrm_buildForm().
*/
function jsumfields_civicrm_buildForm($formName, &$form) {
if ($formName == 'CRM_Sumfields_Form_SumFields') {
$tpl = CRM_Core_Smarty::singleton();
$fieldsets = $tpl->_tpl_vars['fieldsets'];
// Get jsumfields definitions, because we need the fieldset names as a target
// for where to insert our option fields
$custom = array();
jsumfields_civicrm_sumfields_definitions($custom);
// Create a field for Financial Types on related contributions.
$label = jsumfields_ts('Financial Types');
$form->add('select', 'jsumfields_relatedcontrib_financial_type_ids', $label, sumfields_get_all_financial_types(), FALSE, array('multiple' => TRUE, 'class' => 'crm-select2 huge'));
$fieldsets[$custom['optgroups']['relatedcontrib']['fieldset']]['jsumfields_relatedcontrib_financial_type_ids'] = jsumfields_ts('Financial types to be used when calculating Related Contribution summary fields.');
// Create a field for Relationship Types on related contributions.
$label = jsumfields_ts('Relationship Types');
$form->add('select', 'jsumfields_relatedcontrib_relationship_type_ids', $label, _jsumfields_get_all_relationship_types(), FALSE, array('multiple' => TRUE, 'class' => 'crm-select2 huge'));
$fieldsets[$custom['optgroups']['relatedcontrib']['fieldset']]['jsumfields_relatedcontrib_relationship_type_ids'] = jsumfields_ts('Relationship types to be used when calculating Related Contribution summary fields.');
// Create a field for Grant Status on grant fields.
$label = jsumfields_ts('Grant Statuses');
$form->add('select', 'jsumfields_grant_status_ids', $label, _jsumfields_get_all_grant_statuses(), FALSE, array('multiple' => TRUE, 'class' => 'crm-select2 huge'));
$fieldsets[$custom['optgroups']['civigrant']['fieldset']]['jsumfields_grant_status_ids'] = jsumfields_ts('Grant statuses to be used when calculating Grant fields.');
// Create a field for Grant Type on grant fields.
$label = jsumfields_ts('Grant Types');
$form->add('select', 'jsumfields_grant_type_ids', $label, _jsumfields_get_all_grant_types(), FALSE, array('multiple' => TRUE, 'class' => 'crm-select2 huge'));
$fieldsets[$custom['optgroups']['civigrant']['fieldset']]['jsumfields_grant_type_ids'] = jsumfields_ts('Grant types to be used when calculating Grant fields.');
// Set defaults.
$form->setDefaults(array(
'jsumfields_relatedcontrib_financial_type_ids' => sumfields_get_setting('jsumfields_relatedcontrib_financial_type_ids'),
'jsumfields_relatedcontrib_relationship_type_ids' => sumfields_get_setting('jsumfields_relatedcontrib_relationship_type_ids'),
'jsumfields_grant_status_ids' => sumfields_get_setting('jsumfields_grant_status_ids'),
'jsumfields_grant_type_ids' => sumfields_get_setting('jsumfields_grant_type_ids'),
));
$form->assign('fieldsets', $fieldsets);
}
}
/**
* Implements hook_civicrm_postProcess().
*/
function jsumfields_civicrm_postProcess($formName, &$form) {
if ($formName == 'CRM_Sumfields_Form_SumFields') {
// Save option fields as submitted.
sumfields_save_setting('jsumfields_relatedcontrib_financial_type_ids', CRM_Utils_Array::value('jsumfields_relatedcontrib_financial_type_ids', $form->_submitValues));
sumfields_save_setting('jsumfields_relatedcontrib_relationship_type_ids', CRM_Utils_Array::value('jsumfields_relatedcontrib_relationship_type_ids', $form->_submitValues));
sumfields_save_setting('jsumfields_grant_status_ids', CRM_Utils_Array::value('jsumfields_grant_status_ids', $form->_submitValues));
sumfields_save_setting('jsumfields_grant_type_ids', CRM_Utils_Array::value('jsumfields_grant_type_ids', $form->_submitValues));
if ($form->_submitValues['when_to_apply_change'] == 'on_submit') {
// Update our own trigger data, as needed.
_jsumfields_generate_data_based_on_current_data();
}
}
}
/**
* Implements hook_civicrm_sumfields_definitions().
*
* NOTE: Array properties in $custom named 'jsumfields_*' will be used by
* jsumfields_civicrm_triggerInfo() to build triggers, and by
* _jsumfields_generate_data_based_on_current_data() to populate field values.
*
* See DEVNOTES.md for supported 'jsumfields_*' properties.
*/
function jsumfields_civicrm_sumfields_definitions(&$custom) {
// Adjust some labels in summary fields to be more explicit.
$custom['fields']['contribution_total_this_year']['label'] = jsumfields_ts('Total Contributions this Fiscal Year');
$custom['fields']['contribution_total_last_year']['label'] = jsumfields_ts('Total Contributions last Fiscal Year');
$custom['fields']['contribution_total_year_before_last']['label'] = jsumfields_ts('Total Contributions Fiscal Year Before Last');
$custom['fields']['soft_total_this_year']['label'] = jsumfields_ts('Total Soft Credits this Fiscal Year');
$custom['fields']['event_first_attended_date'] = array(
'label' => jsumfields_ts('Date of the first attended event'),
'data_type' => 'Date',
'html_type' => 'Select Date',
'weight' => '71',
'text_length' => '32',
'trigger_sql' => '(
SELECT
e.start_date AS summary_value
FROM civicrm_participant t1
JOIN civicrm_event e ON t1.event_id = e.id
WHERE
t1.contact_id = NEW.contact_id
AND t1.status_id IN (%participant_status_ids)
AND e.event_type_id IN (%event_type_ids)
ORDER BY start_date ASC LIMIT 1
)',
'trigger_table' => 'civicrm_participant',
'optgroup' => 'event_standard',
);
$custom['fields']['grant_count_received'] = array(
'label' => jsumfields_ts('Total number of grants received'),
'data_type' => 'Int',
'html_type' => 'Text',
'weight' => '71',
'text_length' => '255',
'trigger_sql' => _jsumfields_sql_rewrite('
(
SELECT
count(*)
FROM
civicrm_grant g
WHERE
g.contact_id = NEW.contact_id
AND g.status_id in (%jsumfields_grant_status_ids)
AND g.grant_type_id in (%jsumfields_grant_type_ids)
)
'),
'trigger_table' => 'civicrm_grant',
'optgroup' => 'civigrant',
);
$custom['fields']['grant_total_received'] = array(
'label' => jsumfields_ts('Total amount in grants received'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => _jsumfields_sql_rewrite('
(
SELECT
coalesce(sum(g.amount_granted), 0)
FROM
civicrm_grant g
WHERE
g.contact_id = NEW.contact_id
AND g.status_id in (%jsumfields_grant_status_ids)
AND g.grant_type_id in (%jsumfields_grant_type_ids)
)
'),
'trigger_table' => 'civicrm_grant',
'optgroup' => 'civigrant',
);
$custom['fields']['grant_types_received'] = array(
'label' => jsumfields_ts('Grant types received'),
'data_type' => 'String',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '255',
'trigger_sql' => _jsumfields_sql_rewrite('
(
SELECT
GROUP_CONCAT(
DISTINCT ov.label
ORDER BY ov.label
SEPARATOR ", "
)
FROM
civicrm_grant g
INNER JOIN civicrm_option_value ov ON ov.value = g.grant_type_id
INNER JOIN civicrm_option_group og
ON og.id = ov.option_group_id
AND og.name = "grant_type"
WHERE
g.contact_id = NEW.contact_id
AND g.status_id in (%jsumfields_grant_status_ids)
AND g.grant_type_id in (%jsumfields_grant_type_ids)
)
'),
'trigger_table' => 'civicrm_grant',
'optgroup' => 'civigrant',
);
$custom['fields']['mail_openrate_alltime'] = array(
'label' => jsumfields_ts('Open rate rate all time'),
'data_type' => 'Float',
'html_type' => 'Text',
'weight' => '71',
'text_length' => '255',
'trigger_table' => 'civicrm_jsumfields_placeholder',
'trigger_sql' => '""',
'jsumfields_update_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q.id
WHERE
1
GROUP BY
q.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q.id
WHERE
1
GROUP BY
q.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q.id
WHERE
1
GROUP BY
q.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
'jsumfields_extra' => array(
array(
'trigger_table' => 'civicrm_mailing_event_delivered',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
),
array(
'trigger_table' => 'civicrm_mailing_event_bounce',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
),
array(
'trigger_table' => 'civicrm_mailing_event_opened',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
),
),
'optgroup' => 'civimail',
);
$custom['fields']['mail_openrate_last12months'] = array(
'label' => jsumfields_ts('Open rate rate last 12 months'),
'data_type' => 'Float',
'html_type' => 'Text',
'weight' => '71',
'text_length' => '255',
'trigger_table' => 'civicrm_jsumfields_placeholder',
'trigger_sql' => '""',
'jsumfields_update_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
INNER JOIN civicrm_mailing_job j ON j.id = q2.job_id
WHERE
1
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
INNER JOIN civicrm_mailing_job j ON j.id = q2.job_id
WHERE
1
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
INNER JOIN civicrm_mailing_job j ON j.id = q2.job_id
WHERE
1
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
'jsumfields_extra' => array(
array(
'trigger_table' => 'civicrm_mailing_event_delivered',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
INNER JOIN civicrm_mailing_job j ON j.id = q2.job_id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
INNER JOIN civicrm_mailing_job j ON j.id = q2.job_id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
INNER JOIN civicrm_mailing_job j ON j.id = q2.job_id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
),
array(
'trigger_table' => 'civicrm_mailing_event_bounce',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
),
array(
'trigger_table' => 'civicrm_mailing_event_opened',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings sent to contact
SELECT q2.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) s
LEFT JOIN (
-- total mailings opened
SELECT q2.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_opened o ON o.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings bounced
SELECT q2.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q1
INNER JOIN civicrm_mailing_event_queue q2 ON q1.contact_id = q2.contact_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q2.id
WHERE
q1.id = NEW.event_queue_id
AND j.start_date >= DATE_SUB(CURDATE(), INTERVAL 1 YEAR)
GROUP BY
q2.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
),
),
'optgroup' => 'civimail',
);
$mail_clickrate_alltime_jsumfields_extra_trigger_sql = '
-- Of all emails in which there is a link, which this contact opened:
-- in how many of those emails did this contact click a link?
-- In other words:
-- Click-through rate = U / (S - B)
-- U = number of distinct trackable URLs opened by this contact.
-- S = number of emails-with-trackable-links sent to this contact.
-- B = number of bounced emails-with-trackable-links sent to this contact.
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM (
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings-with-trackable-links sent to contact
SELECT q.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q.id
INNER JOIN civicrm_mailing_job j ON q.job_id = j.id
INNER JOIN civicrm_mailing_trackable_url u ON u.mailing_id = j.mailing_id
WHERE
q.id = NEW.event_queue_id
GROUP BY
q.contact_id
) s
LEFT JOIN (
-- total trackable urls opened
SELECT q.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_trackable_url_open o ON o.event_queue_id = q.id
WHERE
q.id = NEW.event_queue_id
GROUP BY
q.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings-with-trackable-links bounced
SELECT q.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_job j ON q.job_id = j.id
INNER JOIN civicrm_mailing_trackable_url u ON u.mailing_id = j.mailing_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q.id
WHERE
q.id = NEW.event_queue_id
GROUP BY
q.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
';
$custom['fields']['mail_clickrate_alltime'] = array(
'label' => jsumfields_ts('Click-through rate all time'),
'data_type' => 'Float',
'html_type' => 'Text',
'weight' => '71',
'text_length' => '255',
'trigger_table' => 'civicrm_jsumfields_placeholder',
'trigger_sql' => '""',
'jsumfields_update_sql' => '
-- Of all emails in which there is a link, which this contact opened:
-- in how many of those emails did this contact click a link?
-- In other words:
-- Click-through rate = U / (S - B)
-- U = number of distinct trackable URLs opened by this contact.
-- S = number of emails-with-trackable-links sent to this contact.
-- B = number of bounced emails-with-trackable-links sent to this contact.
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.contact_id, t.rate
FROM
(
SELECT
s.contact_id, ROUND(coalesce(coalesce(o.opened, 0) / (coalesce(s.sent, 0) - coalesce(b.bounced, 0)), 0) * 100, 2) as rate
FROM
(
-- total mailings-with-trackable-links sent to contact
SELECT q.contact_id, count(*) as sent
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_delivered d ON d.event_queue_id = q.id
INNER JOIN civicrm_mailing_job j ON q.job_id = j.id
INNER JOIN civicrm_mailing_trackable_url u ON u.mailing_id = j.mailing_id
WHERE
1
GROUP BY
q.contact_id
) s
LEFT JOIN (
-- total trackable urls opened
SELECT q.contact_id, count(*) as opened
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_event_trackable_url_open o ON o.event_queue_id = q.id
WHERE
1
GROUP BY
q.contact_id
) o ON o.contact_id = s.contact_id
LEFT JOIN (
-- total mailings-with-trackable-links bounced
SELECT q.contact_id, count(*) as bounced
FROM
civicrm_mailing_event_queue q
INNER JOIN civicrm_mailing_job j ON q.job_id = j.id
INNER JOIN civicrm_mailing_trackable_url u ON u.mailing_id = j.mailing_id
INNER JOIN civicrm_mailing_event_bounce b ON b.event_queue_id = q.id
WHERE
1
GROUP BY
q.contact_id
) b ON b.contact_id = s.contact_id
) t
ON DUPLICATE KEY UPDATE %%jsumfields_custom_column_name = t.rate;
',
'jsumfields_extra' => array(
array(
'trigger_table' => 'civicrm_mailing_event_delivered',
'trigger_sql' => $mail_clickrate_alltime_jsumfields_extra_trigger_sql,
),
array(
'trigger_table' => 'civicrm_mailing_event_bounce',
'trigger_sql' => $mail_clickrate_alltime_jsumfields_extra_trigger_sql,
),
array(
'trigger_table' => 'civicrm_mailing_event_trackable_url_open',
'trigger_sql' => $mail_clickrate_alltime_jsumfields_extra_trigger_sql,
),
),
'optgroup' => 'civimail',
);
$custom['fields']['contribution_total_this_calendar_year'] = array(
'label' => jsumfields_ts('Total Contributions this Calendar Year'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(total_amount),0)
FROM civicrm_contribution t1
WHERE
YEAR(CAST(receive_date AS DATE)) = YEAR(CURDATE())
AND t1.contact_id = NEW.contact_id
AND t1.contribution_status_id = 1
AND t1.financial_type_id IN (%financial_type_ids)
)',
'trigger_table' => 'civicrm_contribution',
'optgroup' => 'fundraising',
);
$custom['fields']['contribution_total_last_calendar_year'] = array(
'label' => jsumfields_ts('Total Contributions last Calendar Year'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(total_amount),0)
FROM civicrm_contribution t1
WHERE YEAR(CAST(receive_date AS DATE)) = (YEAR(CURDATE()) - 1)
AND t1.contact_id = NEW.contact_id
AND t1.contribution_status_id = 1
AND t1.financial_type_id IN (%financial_type_ids)
)',
'trigger_table' => 'civicrm_contribution',
'optgroup' => 'fundraising',
);
$custom['fields']['contribution_total_calendar_year_before_last'] = array(
'label' => jsumfields_ts('Total Contributions Calendar Year Before Last'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(total_amount),0)
FROM civicrm_contribution t1
WHERE YEAR(CAST(receive_date AS DATE)) = YEAR(DATE_SUB(CURDATE(), INTERVAL 2 YEAR))
AND t1.contact_id = NEW.contact_id
AND t1.contribution_status_id = 1
AND t1.financial_type_id IN (%financial_type_ids)
)',
'trigger_table' => 'civicrm_contribution',
'optgroup' => 'fundraising',
);
$custom['fields']['contribution_count_distinct_years'] = array(
'label' => jsumfields_ts('Number of Years of Contributions'),
'data_type' => 'Integer',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT count(DISTINCT YEAR(CAST(receive_date AS DATE)))
FROM civicrm_contribution t1
WHERE
t1.contact_id = NEW.contact_id
AND t1.contribution_status_id = 1
AND t1.financial_type_id IN (%financial_type_ids)
)',
'trigger_table' => 'civicrm_contribution',
'optgroup' => 'fundraising',
);
$custom['fields']['soft_total_this_calendar_year'] = array(
'label' => jsumfields_ts('Total Soft Credits this Calendar Year'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(amount),0)
FROM civicrm_contribution_soft t1
WHERE t1.contact_id = NEW.contact_id
AND t1.contribution_id IN (
SELECT id
FROM civicrm_contribution
WHERE contribution_status_id = 1
AND financial_type_id IN (%financial_type_ids)
AND YEAR(CAST(receive_date AS DATE)) = YEAR(CURDATE())
)
)',
'trigger_table' => 'civicrm_contribution_soft',
'optgroup' => 'soft',
);
$custom['fields']['soft_total_last_calendar_year'] = array(
'label' => jsumfields_ts('Total Soft Credits last Calendar Year'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(amount),0)
FROM civicrm_contribution_soft t1
WHERE t1.contact_id = NEW.contact_id
AND t1.contribution_id IN (
SELECT id
FROM civicrm_contribution
WHERE contribution_status_id = 1
AND financial_type_id IN (%financial_type_ids)
AND YEAR(CAST(receive_date AS DATE)) = (YEAR(CURDATE()) - 1)
)
)',
'trigger_table' => 'civicrm_contribution_soft',
'optgroup' => 'soft',
);
$custom['fields']['soft_total_last_fiscal_year'] = array(
'label' => jsumfields_ts('Total Soft Credits last Fiscal Year'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(amount),0)
FROM civicrm_contribution_soft t1
WHERE t1.contact_id = NEW.contact_id
AND t1.contribution_id IN (
SELECT id
FROM civicrm_contribution
WHERE contribution_status_id = 1
AND financial_type_id IN (%financial_type_ids)
AND CAST(receive_date AS DATE) BETWEEN DATE_SUB("%current_fiscal_year_begin", INTERVAL 1 YEAR) AND DATE_SUB("%current_fiscal_year_end", INTERVAL 1 YEAR)
)
)',
'trigger_table' => 'civicrm_contribution_soft',
'optgroup' => 'soft',
);
$custom['fields']['hard_and_soft'] = array(
'label' => jsumfields_ts('Lifetime contributions + soft credits'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => '(
SELECT COALESCE(SUM(cont1.total_amount), 0)
FROM civicrm_contribution cont1
LEFT JOIN civicrm_contribution_soft soft ON soft.contribution_id = cont1.id
WHERE
(cont1.contact_id = NEW.contact_id OR soft.contact_id = NEW.contact_id)
AND cont1.contribution_status_id = 1
AND cont1.financial_type_id IN (%financial_type_ids)
)',
'trigger_table' => 'civicrm_contribution',
'optgroup' => 'fundraising', // could just add this to the existing "fundraising" optgroup
);
/* For the "Related Contributions" group of fields, we cannot make them work
* as true sumfields fields, because of assumptions in sumfields
* [https://github.com/progressivetech/net.ourpowerbase.sumfields/blob/master/sumfields.php#L476]:
* 1. that every trigger table has a column named contact_id (which civicrm_relationship does not)
* 2. that the contact_id column in the trigger table is the one for whom the custom field should be updated (which is not true for any realtionship-based sumfields).
* So to make this work, we hijack and emulate select parts of sumfields logic:
* a. _jsumfields_generate_data_based_on_current_data(), our own version of
* sumfields_generate_data_based_on_current_data()
* b. calling _jsumfields_generate_data_based_on_current_data() via
* apiwrappers hook, so it always happens when the API gendata is called.
* c. calling _jsumfields_generate_data_based_on_current_data() via
* postProcess hook, so it happens (as needed ) when the Sumfields form is
* submitted.
* To make all this happen, we define special values in array properties named
* 'jsumfields_*', which are ignored by sumfields, but are specifically
* handled by _jsumfields_generate_data_based_on_current_data() and
* jsumfields_civicrm_triggerInfo().
*/
$custom['fields']['relatedcontrib_this_fiscal_year'] = array(
'label' => jsumfields_ts('Related contact contributions this fiscal year'),
'data_type' => 'Money',
'html_type' => 'Text',
'weight' => '15',
'text_length' => '32',
'trigger_sql' => _jsumfields_sql_rewrite('
(
select coalesce(sum(total_amount),0) as total from
(
select
contact_id_a, r.relationship_type_id, r.is_active, ctrb.financial_type_id, ctrb.receive_date, ctrb.total_amount, ctrb.contribution_status_id
from
civicrm_relationship r
inner join civicrm_contribution ctrb ON ctrb.contact_id = r.contact_id_b
UNION ALL
select
contact_id_b, r.relationship_type_id, r.is_active, ctrb.financial_type_id, ctrb.receive_date, ctrb.total_amount, ctrb.contribution_status_id
from
civicrm_relationship r
inner join civicrm_contribution ctrb ON ctrb.contact_id = r.contact_id_a
) t
where
t.relationship_type_id in (%jsumfields_relatedcontrib_relationship_type_ids)
and t.is_active
and t.financial_type_id in (%jsumfields_relatedcontrib_financial_type_ids)
AND CAST(t.receive_date AS DATE) BETWEEN "%current_fiscal_year_begin" AND "%current_fiscal_year_end"
AND t.contribution_status_id = 1
AND contact_id_a = NEW.contact_id
group by contact_id_a
)
'),
'trigger_table' => 'civicrm_contribution',
'jsumfields_extra' => array(
array(
'trigger_table' => 'civicrm_contribution',
'trigger_sql' => '
INSERT INTO %%jsumfields_custom_table_name (entity_id, %%jsumfields_custom_column_name)
SELECT t.related_contact_id, t.total
FROM
(
SELECT
t.related_contact_id, if(t.related_contact_id = r.contact_id_b, r.contact_id_a, r.contact_id_b) as donor_contact_id, coalesce(sum(ctrb.total_amount), 0) as total
FROM
(
select DISTINCT
NEW.contact_id, if(r.contact_id_a = NEW.contact_id, r.contact_id_b, r.contact_id_a) as related_contact_id
from
civicrm_relationship r
WHERE
NEW.contact_id IN (r.contact_id_a, r.contact_id_b)
AND r.relationship_type_id in (%jsumfields_relatedcontrib_relationship_type_ids)
AND r.is_active
) t
INNER JOIN civicrm_relationship r ON t.related_contact_id in (r.contact_id_b, r.contact_id_a)
AND r.relationship_type_id in (%jsumfields_relatedcontrib_relationship_type_ids)
AND r.is_active
LEFT JOIN civicrm_contribution ctrb ON ctrb.contact_id = if(t.related_contact_id = r.contact_id_b, r.contact_id_a, r.contact_id_b)
and ctrb.financial_type_id in (%jsumfields_relatedcontrib_financial_type_ids)
AND CAST(ctrb.receive_date AS DATE) BETWEEN "%current_fiscal_year_begin" AND "%current_fiscal_year_end"
AND ctrb.contribution_status_id = 1
GROUP BY
t.related_contact_id