Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

(dev/core/68) Fix DB Error on 'Find Participant' page when MySQL FULL_GROUP_BY_MODE is enabled #11996

Merged
merged 2 commits into from
May 10, 2018

Conversation

monishdeb
Copy link
Member

@monishdeb monishdeb commented Apr 18, 2018

Overview

Steps to replicate:

  1. Ensure that FULL_GROUP_BY_MODE is enabled in MySQL
  2. Go to 'Find Participant' search form and do a simple search.

Issue: https://lab.civicrm.org/dev/core/issues/68

Before

This leads to DB Error - https://pastebin.com/jxbaAbpS

After

Fixed the DB Error

@lcdservices
Copy link
Contributor

This is working as expected. Using MySQL 5.7 with FULL_GROUP_BY_MODE you can now use Find Participants.

@eileenmcnaughton
Copy link
Contributor

I'm feeling really stung by regressions related to full group by fixes. I am aware of at least one unfixed regression from a full group by fix (https://issues.civicrm.org/jira/browse/CRM-21699) & one that I merged just this week (#10988) . I think we need to figure out how to lift the bar on these.

I don't think we should merge any more full group by fixes without
a) a unit test &
b) trying to get the test suite switched over to running in full group by mode
c) making sure all PR descriptions include before & after sql & a discussion of the paths by which the change should be hit.

@seamuslee001 & I discussed over on #11954 a bit

@seamuslee001
Copy link
Contributor

This seems to be baulked on the lack of a unit test

@eileenmcnaughton
Copy link
Contributor

I think it's baulked on more than that from my pov - it's a really central change & it's baulked on us having an appropriate way to work with full group by & on someone being able to confirm they have been running this in production on more than one site for several months

* @param array $orderBys - ORDER BY sub-clauses
*
*/
public static function getGroupByFromOrderBy(&$groupBy, $orderBys) {
if (!CRM_Utils_SQL::disableFullGroupByMode()) {
foreach ($orderBys as $orderBy) {
$orderBy = str_replace(array(' DESC', ' ASC', '`'), '', $orderBy); // remove sort syntax from ORDER BY clauses if present
$orderBy = str_ireplace(array(' DESC', ' ASC', '`'), '', $orderBy); // remove sort syntax from ORDER BY clauses if present
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@eileenmcnaughton so this change is about making it so that its not case sensitive iirc

* @param array $orderBys - ORDER BY sub-clauses
*
*/
public static function getGroupByFromOrderBy(&$groupBy, $orderBys) {
if (!CRM_Utils_SQL::disableFullGroupByMode()) {
foreach ($orderBys as $orderBy) {
$orderBy = str_replace(array(' DESC', ' ASC', '`'), '', $orderBy); // remove sort syntax from ORDER BY clauses if present
$orderBy = str_ireplace(array(' DESC', ' ASC', '`'), '', $orderBy); // remove sort syntax from ORDER BY clauses if present
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

so - this seems totally safe IMHO - if it's OK for non sensitive then case sensitive is ok

// if ORDER BY column is not present in GROUP BY then append it to end
if (preg_match('/(MAX|MIN)\(/i', trim($orderBy)) !== 1 && !strstr($groupBy, $orderBy)) {
$groupBy .= ", {$orderBy}";
if (preg_match('/(MAX|MIN)\(/i', trim($orderBy)) !== 1) {
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

so change is coping with possibility of non-string $groupBy

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

So the purpose of this if is to find any columns that are aggregated in the select and not add them to teh group by right?

return !strstr($var, $orderBy);
});
}
elseif (!strstr($groupBy, $orderBy)) {
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

this is unchanged

$groupBy .= ", {$orderBy}";
if (preg_match('/(MAX|MIN)\(/i', trim($orderBy)) !== 1) {
if (is_array($groupBy)) {
// retrieve and add all the ORDER BY columns which are not in GROUP BY list of columns
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

so the change is this - the possibility of groupBy being an array & it now being handled if it is

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

So if its not present in the array add it otherwise don't worry

@@ -4898,16 +4907,16 @@ public function searchQuery(
list($select, $from, $where, $having) = $this->query($count, $sortByChar, $groupContacts, $onlyDeleted);

if (!empty($groupByCols)) {
if (!empty($order)) {
// retrieve order by columns from ORDER BY clause
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

and this re-ordering - not sure the reason

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I suspect the reasoning is that if any of the orderBy Columns are not already in the Select statement then they would be added to the GroupBy but not Select because of L4917

@eileenmcnaughton
Copy link
Contributor

eileenmcnaughton commented May 8, 2018

so - looking at this with @seamuslee001 - I have a generalised high-level of concern about FGB fixes based on the experience we have had. However, I note that this PR is not adding FGB handling but tweaking existing handling - to the point of handling a different format for $groupBy in this function, and that @seamuslee001 has added a test.

I also confirm per @seamuslee001 & @lcdservices that this does fix a problem.

So, if we assume the FGB handling is generally working then extending it to an area that is known to be broken on FGB sites should be safe-ish (or at least more so than adding it to new code areas.....)

@eileenmcnaughton
Copy link
Contributor

Hmm I guess it DOES add fgb handling to more areas by catching more places

@eileenmcnaughton
Copy link
Contributor

So - my understanding is that what this does is IF a column is in the order by but NOT the group by then it will be added to the group by clause - at the mysql level this is a similar change to

#10926

which caused this regression

https://issues.civicrm.org/jira/browse/CRM-21699?filter=24614

We have a situation where the GROUP BY clause is generally 'correct' because when people have been writing the queries that was their focus. Order bys are a bit more hit & miss - but now we are changing Order by to match Group by through this & this PR DOES extend it.

So, I think we maybe need to find a bunch of places where this is called with $groupBy as an array and actually get the before & after query output to test against data

@eileenmcnaughton
Copy link
Contributor

(I take back my 'safeish' & 'low-risk' comments after more thought)

@eileenmcnaughton
Copy link
Contributor

Here is the original query

SELECT contact_a.id as contact_id, contact_a.contact_type as `contact_type`, contact_a.contact_sub_type as `contact_sub_type`, contact_a.sort_name as `sort_name`, contact_a.display_name as `display_name`, civicrm_event.id as event_id, civicrm_event.title as event_title, civicrm_event.start_date as event_start_date, civicrm_event.end_date as event_end_date, civicrm_event.default_role_id as `default_role_id`, civicrm_participant.id as participant_id, civicrm_participant.fee_level as participant_fee_level, civicrm_participant.fee_amount as participant_fee_amount, civicrm_participant.fee_currency as participant_fee_currency, event_type.label as event_type, civicrm_participant.status_id as participant_status_id, participant_status.label as participant_status, civicrm_participant.role_id as participant_role_id, civicrm_participant.role_id as participant_role, civicrm_participant.register_date as participant_register_date, civicrm_participant.source as participant_source, civicrm_note.note as participant_note, civicrm_participant.is_pay_later as participant_is_pay_later, civicrm_participant.is_test as participant_is_test, civicrm_participant.registered_by_id as participant_registered_by_id, discount_name.title as participant_discount_name, civicrm_participant.campaign_id as participant_campaign_id   FROM civicrm_contact contact_a LEFT JOIN civicrm_participant ON civicrm_participant.contact_id = contact_a.id  LEFT JOIN civicrm_event ON civicrm_participant.event_id = civicrm_event.id  LEFT JOIN civicrm_option_group option_group_event_type ON (option_group_event_type.name = 'event_type') LEFT JOIN civicrm_option_value event_type ON (civicrm_event.event_type_id = event_type.value AND option_group_event_type.id = event_type.option_group_id )  LEFT JOIN civicrm_discount discount ON ( civicrm_participant.discount_id = discount.id ) LEFT JOIN civicrm_option_group discount_name ON ( discount_name.id = discount.price_set_id )  LEFT JOIN civicrm_note ON ( civicrm_note.entity_table = 'civicrm_participant' AND
                                                        civicrm_participant.id = civicrm_note.entity_id ) LEFT JOIN civicrm_option_group option_group_participant_role ON (option_group_participant_role.name = 'participant_role') LEFT JOIN civicrm_option_value participant_role ON ((civicrm_participant.role_id = participant_role.value OR SUBSTRING_INDEX(role_id,'�', 1) = participant_role.value)
                               AND option_group_participant_role.id = participant_role.option_group_id )  LEFT JOIN civicrm_participant_status_type participant_status ON (civicrm_participant.status_id = participant_status.id)  WHERE  ( civicrm_participant.is_test = 0 )  AND (contact_a.is_deleted = 0)   GROUP BY civicrm_participant.id  ORDER BY `participant_register_date` desc, `contact_a`.`id`  LIMIT 0, 50 

And with FGB support added

SELECT GROUP_CONCAT(DISTINCT contact_a.id) as contact_id, GROUP_CONCAT(DISTINCT contact_a.contact_type) as `contact_type`, GROUP_CONCAT(DISTINCT contact_a.contact_sub_type) as `contact_sub_type`, GROUP_CONCAT(DISTINCT contact_a.sort_name) as `sort_name`, GROUP_CONCAT(DISTINCT contact_a.display_name) as `display_name`, GROUP_CONCAT(DISTINCT civicrm_event.id) as event_id, GROUP_CONCAT(DISTINCT civicrm_event.title) as event_title, GROUP_CONCAT(DISTINCT civicrm_event.start_date) as event_start_date, GROUP_CONCAT(DISTINCT civicrm_event.end_date) as event_end_date, GROUP_CONCAT(DISTINCT civicrm_event.default_role_id) as `default_role_id`, civicrm_participant.id as participant_id, GROUP_CONCAT(DISTINCT civicrm_participant.fee_level) as participant_fee_level, GROUP_CONCAT(DISTINCT civicrm_participant.fee_amount) as participant_fee_amount, GROUP_CONCAT(DISTINCT civicrm_participant.fee_currency) as participant_fee_currency, GROUP_CONCAT(DISTINCT event_type.label) as event_type, GROUP_CONCAT(DISTINCT civicrm_participant.status_id) as participant_status_id, GROUP_CONCAT(DISTINCT participant_status.label) as participant_status, GROUP_CONCAT(DISTINCT civicrm_participant.role_id) as participant_role_id, GROUP_CONCAT(DISTINCT civicrm_participant.role_id) as participant_role, GROUP_CONCAT(DISTINCT civicrm_participant.register_date) as participant_register_date, GROUP_CONCAT(DISTINCT civicrm_participant.source) as participant_source, GROUP_CONCAT(DISTINCT civicrm_note.note) as participant_note, GROUP_CONCAT(DISTINCT civicrm_participant.is_pay_later) as participant_is_pay_later, GROUP_CONCAT(DISTINCT civicrm_participant.is_test) as participant_is_test, GROUP_CONCAT(DISTINCT civicrm_participant.registered_by_id) as participant_registered_by_id, GROUP_CONCAT(DISTINCT discount_name.title) as participant_discount_name, GROUP_CONCAT(DISTINCT civicrm_participant.campaign_id) as participant_campaign_id   FROM civicrm_contact contact_a LEFT JOIN civicrm_participant ON civicrm_participant.contact_id = contact_a.id  LEFT JOIN civicrm_event ON civicrm_participant.event_id = civicrm_event.id  LEFT JOIN civicrm_option_group option_group_event_type ON (option_group_event_type.name = 'event_type') LEFT JOIN civicrm_option_value event_type ON (civicrm_event.event_type_id = event_type.value AND option_group_event_type.id = event_type.option_group_id )  LEFT JOIN civicrm_discount discount ON ( civicrm_participant.discount_id = discount.id ) LEFT JOIN civicrm_option_group discount_name ON ( discount_name.id = discount.price_set_id )  LEFT JOIN civicrm_note ON ( civicrm_note.entity_table = 'civicrm_participant' AND
                                                        civicrm_participant.id = civicrm_note.entity_id ) LEFT JOIN civicrm_option_group option_group_participant_role ON (option_group_participant_role.name = 'participant_role') LEFT JOIN civicrm_option_value participant_role ON ((civicrm_participant.role_id = participant_role.value OR SUBSTRING_INDEX(role_id,'�', 1) = participant_role.value)
                               AND option_group_participant_role.id = participant_role.option_group_id )  LEFT JOIN civicrm_participant_status_type participant_status ON (civicrm_participant.status_id = participant_status.id)  WHERE  ( civicrm_participant.is_test = 0 )  AND (contact_a.is_deleted = 0)   GROUP BY civicrm_participant.id,  participant_register_date desc,  contact_a.id  ORDER BY `participant_register_date` desc, `contact_a`.`id`  LIMIT 0, 50 

WITH FGB + this patch I'm getting this:

SELECT GROUP_CONCAT(DISTINCT contact_a.id) as contact_id, GROUP_CONCAT(DISTINCT contact_a.contact_type) as `contact_type`, GROUP_CONCAT(DISTINCT contact_a.contact_sub_type) as `contact_sub_type`, GROUP_CONCAT(DISTINCT contact_a.sort_name) as `sort_name`, GROUP_CONCAT(DISTINCT contact_a.display_name) as `display_name`, GROUP_CONCAT(DISTINCT civicrm_event.id) as event_id, GROUP_CONCAT(DISTINCT civicrm_event.title) as event_title, GROUP_CONCAT(DISTINCT civicrm_event.start_date) as event_start_date, GROUP_CONCAT(DISTINCT civicrm_event.end_date) as event_end_date, GROUP_CONCAT(DISTINCT civicrm_event.default_role_id) as `default_role_id`, civicrm_participant.id as participant_id, GROUP_CONCAT(DISTINCT civicrm_participant.fee_level) as participant_fee_level, GROUP_CONCAT(DISTINCT civicrm_participant.fee_amount) as participant_fee_amount, GROUP_CONCAT(DISTINCT civicrm_participant.fee_currency) as participant_fee_currency, GROUP_CONCAT(DISTINCT event_type.label) as event_type, GROUP_CONCAT(DISTINCT civicrm_participant.status_id) as participant_status_id, GROUP_CONCAT(DISTINCT participant_status.label) as participant_status, GROUP_CONCAT(DISTINCT civicrm_participant.role_id) as participant_role_id, GROUP_CONCAT(DISTINCT civicrm_participant.role_id) as participant_role, GROUP_CONCAT(DISTINCT civicrm_participant.register_date) as participant_register_date, GROUP_CONCAT(DISTINCT civicrm_participant.source) as participant_source, GROUP_CONCAT(DISTINCT civicrm_note.note) as participant_note, GROUP_CONCAT(DISTINCT civicrm_participant.is_pay_later) as participant_is_pay_later, GROUP_CONCAT(DISTINCT civicrm_participant.is_test) as participant_is_test, GROUP_CONCAT(DISTINCT civicrm_participant.registered_by_id) as participant_registered_by_id, GROUP_CONCAT(DISTINCT discount_name.title) as participant_discount_name, GROUP_CONCAT(DISTINCT civicrm_participant.campaign_id) as participant_campaign_id  

 FROM civicrm_contact contact_a LEFT JOIN civicrm_participant ON civicrm_participant.contact_id = contact_a.id  LEFT JOIN civicrm_event ON civicrm_participant.event_id = civicrm_event.id  LEFT JOIN civicrm_option_group option_group_event_type ON (option_group_event_type.name = 'event_type') LEFT JOIN civicrm_option_value event_type ON (civicrm_event.event_type_id = event_type.value AND option_group_event_type.id = event_type.option_group_id )  LEFT JOIN civicrm_discount discount ON ( civicrm_participant.discount_id = discount.id ) LEFT JOIN civicrm_option_group discount_name ON ( discount_name.id = discount.price_set_id )  LEFT JOIN civicrm_note ON ( civicrm_note.entity_table = 'civicrm_participant' AND
                                                        civicrm_participant.id = civicrm_note.entity_id ) LEFT JOIN civicrm_option_group option_group_participant_role ON (option_group_participant_role.name = 'participant_role') LEFT JOIN civicrm_option_value participant_role ON ((civicrm_participant.role_id = participant_role.value OR SUBSTRING_INDEX(role_id,'�', 1) = participant_role.value)
                               AND option_group_participant_role.id = participant_role.option_group_id )  
LEFT JOIN civicrm_participant_status_type participant_status ON (civicrm_participant.status_id = participant_status.id)  WHERE  ( civicrm_participant.is_test = 0 )  AND (contact_a.is_deleted = 0)   GROUP BY civicrm_participant.id  
ORDER BY `participant_register_date` desc, `contact_a`.`id`  LIMIT 0, 50 

Which seems OK - but I feel the point of the patch is to add participant_register_date desc, contact_a.id to the GROUP BY row - which would be OK in this query in that civicrm_participant.id would defacto group by those anyway - but I don't know what it would take for me to be sure there are no queries adversely affected

@seamuslee001
Copy link
Contributor

@eileenmcnaughton @monishdeb so i'm putting this through its paces on a php5.6 MySQL 5.7 test box by running ALL the tests

It has detected one legit failure which is a regression it seems https://gist.github.com/seamuslee001/586c83c01098cd74c4c55c7ebdc72d22

@monishdeb
Copy link
Member Author

monishdeb commented May 8, 2018

@eileenmcnaughton @seamuslee001 let me explain my fix in points:

  1. FGB expects a) columns that are present in ORDER BY must be present in GROUP BY, and b) those present in GROUP BY must be there in SELECT clause. So this patch moves the place by doing a) first and then at last when we know that all the legit columns are present in GROUP BY then using appendAnyValueToSelect() do (b) . Earlier the error was (b) was called before (a) so the columns which are present in ORDER BY (here participant_register_date) are added in GROUP BY but doesn't make up to SELECT clause, trigger a error.

  2. Extended getGroupByFromOrderBy() to accept GROUP BY columns in array format.

  3. Modified https://github.com/civicrm/civicrm-core/pull/11996/files#diff-e54381bfdf51e31cab376c71ca0d66ffR4744 here as there are places in codebase where small case sort is being used asc or desc

@monishdeb
Copy link
Member Author

@seamuslee001 the failure https://gist.github.com/seamuslee001/586c83c01098cd74c4c55c7ebdc72d22 is strange because it should have added the ORDER BY columns in GROUP BY as per the fix :(

@eileenmcnaughton
Copy link
Contributor

@monishdeb so the thing that is most likely to turn a query that returns the right result, but does not meet the full group by standard is to do what we did in #10926 - ie we added a column to the GROUP BY column because it was in the ORDER BY - thus changing the actual outcome in an unpredictable way.

So as we hone in on the risks on FGB patches - it seems anything that adds to the GROUP BY clause is at high risk of taking a working query and messing with the results. Given this risk - is the hypothetical benefit of a 'better' query worth the risk is it actually worse due to using a GROUP BY that was not intended when the query was written?

@monishdeb
Copy link
Member Author

Hmm right at one hand it will satisfy the FGB but on the otherhand doing so will keep adding GROUP BY columns if there are more such columns present in ORDER BY. So in order to fulfil FGB but not to cause any drastic change to SQL output I think we should bring that disable/renable FGB function ? In that way we doesn't need to worry about FGB errors anymore.

@eileenmcnaughton
Copy link
Contributor

The failing test is a great example of the risk here is the query in the test

SELECT GROUP_CONCAT(DISTINCT contact_a.id) as contact_id, GROUP_CONCAT(DISTINCT contact_a.contact_type) as `contact_type`, GROUP_CONCAT(DISTINCT contact_a.contact_sub_type) as `contact_sub_type`, GROUP_CONCAT(DISTINCT contact_a.sort_name) as `sort_name`, GROUP_CONCAT(DISTINCT contact_a.display_name) as `display_name`, civicrm_activity.id as activity_id, GROUP_CONCAT(DISTINCT activity_type.value) as activity_type_id, GROUP_CONCAT(DISTINCT civicrm_activity.subject) as activity_subject, GROUP_CONCAT(DISTINCT civicrm_activity.activity_date_time) as activity_date_time, GROUP_CONCAT(DISTINCT civicrm_activity.status_id) as activity_status_id, GROUP_CONCAT(DISTINCT civicrm_activity.source_record_id) as source_record_id, GROUP_CONCAT(DISTINCT civicrm_activity.is_test) as activity_is_test, GROUP_CONCAT(DISTINCT civicrm_activity.campaign_id) as activity_campaign_id, GROUP_CONCAT(DISTINCT civicrm_activity.engagement_level) as activity_engagement_level, GROUP_CONCAT(DISTINCT source_contact.sort_name) as source_contact   FROM civicrm_contact contact_a LEFT JOIN civicrm_activity_contact
                      ON ( civicrm_activity_contact.contact_id = contact_a.id )  LEFT JOIN civicrm_activity
                      ON ( civicrm_activity.id = civicrm_activity_contact.activity_id
                      AND civicrm_activity.is_deleted = 0 AND civicrm_activity.is_current_revision = 1 ) INNER JOIN civicrm_contact
                      ON ( civicrm_activity_contact.contact_id = civicrm_contact.id and civicrm_contact.is_deleted != 1 ) LEFT JOIN civicrm_option_group option_group_activity_type ON (option_group_activity_type.name = 'activity_type') LEFT JOIN civicrm_option_value activity_type ON (civicrm_activity.activity_type_id = activity_type.value
                               AND option_group_activity_type.id = activity_type.option_group_id )
        LEFT JOIN civicrm_activity_contact ac
                      ON ( ac.activity_id = civicrm_activity_contact.activity_id AND ac.record_type_id = 2)
        INNER JOIN civicrm_contact source_contact ON (ac.contact_id = source_contact.id) WHERE (contact_a.is_deleted = 0) AND  (activity_type.component_id IS NULL OR activity_type.component_id <> 5)  AND  (activity_type.component_id IS NULL OR activity_type.component_id <> 7)  
        AND  (activity_type.component_id IS NULL OR activity_type.component_id <> 9)  
          GROUP BY civicrm_activity.id  ORDER BY `activity_date_time` desc, `contact_a`.`id` 

When I run it locally on my DB I get 460 rows returned

If I CHANGE the group by to include the columns in the ORDER BY I get 513 rows returned - so if we had 'fixed' it because it 'should have added the ORDER BY columns in GROUP BY as per the fix' then we would get 53 rows returned that the original developer never had a plan for ...

@eileenmcnaughton
Copy link
Contributor

@monishdeb I agree on the disable & re-enable sadly. I get the logic of what we are trying to do to meet fgb compliance but it's very very hard to retrofit that on our search logic which has a lot of quirks

@monishdeb
Copy link
Member Author

@eileenmcnaughton @seamuslee001 @lcdservices as per the discussion I have to choose to disable/reenable FGB when there are GROUP BY columns present. Please check my latest change.

@eileenmcnaughton
Copy link
Contributor

This would seem to get rid of those nasty fatal errors without making changes to query output that could have unexpected results

@monishdeb
Copy link
Member Author

Jenkins test this please

@eileenmcnaughton eileenmcnaughton added the merge ready PR will be merged after a few days if there are no objections label May 8, 2018
@eileenmcnaughton
Copy link
Contributor

I've added merge ready - this should be merged IMHO but it gives it a cool down - I don't believe SELECT SQL_CALC_FOUND_ROWS will hit us here

@eileenmcnaughton
Copy link
Contributor

Merging now - then we will re-run #12085 & see how it goes. Based on online feedback this may be a candidate for backporting

@eileenmcnaughton eileenmcnaughton merged commit fd87b71 into civicrm:master May 10, 2018
@monishdeb monishdeb deleted the dev-core-68 branch May 11, 2018 04:09
@monishdeb
Copy link
Member Author

Thanks @eileenmcnaughton

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
master merge ready PR will be merged after a few days if there are no objections
Projects
None yet
Development

Successfully merging this pull request may close these issues.

5 participants