Skip to content

Commit

Permalink
Cleanup sql query
Browse files Browse the repository at this point in the history
On digging into this query I found that is uses protected words like value & count
so I have fixed the query to no longer use those & re-formatted to add comments.

I suspect the actual fix might need to sit around pending community input so I think it is good to
get this tidy up merged to make it all clearer
  • Loading branch information
eileenmcnaughton committed May 19, 2022
1 parent 4d61dc0 commit 30d6c82
Showing 1 changed file with 18 additions and 14 deletions.
32 changes: 18 additions & 14 deletions CRM/Event/BAO/Event.php
Original file line number Diff line number Diff line change
Expand Up @@ -2258,20 +2258,24 @@ public static function eventTotalSeats($eventId, $extraWhereClause = NULL) {
//3. consider event seat as a sum of all seats from line items in case price field value carries count.

$query = "
SELECT IF ( SUM( value.count*lineItem.qty ),
SUM( value.count*lineItem.qty ) +
COUNT( DISTINCT participant.id ) -
COUNT( DISTINCT IF ( value.count, participant.id, NULL ) ),
COUNT( DISTINCT participant.id ) )
FROM civicrm_participant participant
INNER JOIN civicrm_contact contact ON ( contact.id = participant.contact_id AND contact.is_deleted = 0 )
INNER JOIN civicrm_event event ON ( event.id = participant.event_id )
LEFT JOIN civicrm_line_item lineItem ON ( lineItem.entity_id = participant.id
AND lineItem.entity_table = 'civicrm_participant' )
LEFT JOIN civicrm_price_field_value value ON ( value.id = lineItem.price_field_value_id AND value.count )
WHERE ( participant.event_id = %1 )
AND participant.is_test = 0
{$extraWhereClause}
SELECT
IF
-- If the line item count * the line item quantity is not 0
(SUM(price_field_value.`count` * lineItem.qty),
-- then use the count * the quantity, ensuring each
-- actual participant record gets a result
SUM(price_field_value.`count` * lineItem.qty)
+ COUNT(DISTINCT participant.id )
- COUNT(DISTINCT IF (price_field_value.`count`, participant.id, NULL)),
-- if the line item count is NULL or 0 then count the participants
COUNT(DISTINCT participant.id))
FROM civicrm_participant participant
INNER JOIN civicrm_contact contact ON (contact.id = participant.contact_id AND contact.is_deleted = 0)
INNER JOIN civicrm_event event ON ( event.id = participant.event_id )
LEFT JOIN civicrm_line_item lineItem ON ( lineItem.entity_id = participant.id AND lineItem.entity_table = 'civicrm_participant' )
LEFT JOIN civicrm_price_field_value price_field_value ON (price_field_value.id = lineItem.price_field_value_id AND price_field_value.`count`)
WHERE (participant.event_id = %1) AND participant.is_test = 0
{$extraWhereClause}
GROUP BY participant.event_id";

return (int) CRM_Core_DAO::singleValueQuery($query, [1 => [$eventId, 'Positive']]);
Expand Down

0 comments on commit 30d6c82

Please sign in to comment.