Skip to content

Commit cf01507

Browse files
authored
Improve check-in list query performance (#417)
1 parent 1b9fbd9 commit cf01507

File tree

2 files changed

+72
-11
lines changed

2 files changed

+72
-11
lines changed

backend/app/Repository/Eloquent/CheckInListRepository.php

Lines changed: 27 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -5,7 +5,6 @@
55
use HiEvents\DomainObjects\CheckInListDomainObject;
66
use HiEvents\DomainObjects\Generated\CapacityAssignmentDomainObjectAbstract;
77
use HiEvents\DomainObjects\Generated\CheckInListDomainObjectAbstract;
8-
use HiEvents\DomainObjects\Status\AttendeeStatus;
98
use HiEvents\Http\DTO\QueryParamsDTO;
109
use HiEvents\Models\CheckInList;
1110
use HiEvents\Repository\DTO\CheckedInAttendeesCountDTO;
@@ -33,15 +32,24 @@ public function getCheckedInAttendeeCountById(int $checkInListId): CheckedInAtte
3332
SELECT attendee_id, check_in_list_id
3433
FROM attendee_check_ins
3534
WHERE deleted_at IS NULL
35+
AND check_in_list_id = :check_in_list_id
3636
GROUP BY attendee_id, check_in_list_id
3737
),
3838
valid_attendees AS (
39-
SELECT a.id, tcil.check_in_list_id
39+
SELECT a.id, pcil.check_in_list_id
4040
FROM attendees a
41-
JOIN product_check_in_lists tcil ON a.product_id = tcil.product_id
41+
JOIN product_check_in_lists pcil ON a.product_id = pcil.product_id
42+
JOIN orders o ON a.order_id = o.id
43+
JOIN check_in_lists cil ON pcil.check_in_list_id = cil.id
44+
JOIN event_settings es ON cil.event_id = es.event_id
4245
WHERE a.deleted_at IS NULL
43-
AND tcil.deleted_at IS NULL
44-
AND a.status in ('ACTIVE', 'AWAITING_PAYMENT')
46+
AND pcil.deleted_at IS NULL
47+
AND pcil.check_in_list_id = :check_in_list_id
48+
AND (
49+
(es.allow_orders_awaiting_offline_payment_to_check_in = true AND a.status in ('ACTIVE', 'AWAITING_PAYMENT') AND o.status IN ('COMPLETED', 'AWAITING_OFFLINE_PAYMENT'))
50+
OR
51+
(es.allow_orders_awaiting_offline_payment_to_check_in = false AND a.status = 'ACTIVE' AND o.status = 'COMPLETED')
52+
)
4553
)
4654
SELECT
4755
cil.id AS check_in_list_id,
@@ -67,22 +75,30 @@ public function getCheckedInAttendeeCountById(int $checkInListId): CheckedInAtte
6775
public function getCheckedInAttendeeCountByIds(array $checkInListIds): Collection
6876
{
6977
$placeholders = implode(',', array_fill(0, count($checkInListIds), '?'));
70-
$attendeeActiveStatus = AttendeeStatus::ACTIVE->name;
7178

7279
$sql = <<<SQL
7380
WITH valid_check_ins AS (
7481
SELECT attendee_id, check_in_list_id
7582
FROM attendee_check_ins
7683
WHERE deleted_at IS NULL
84+
AND check_in_list_id IN ($placeholders)
7785
GROUP BY attendee_id, check_in_list_id
7886
),
7987
valid_attendees AS (
80-
SELECT a.id, tcil.check_in_list_id
88+
SELECT a.id, pcil.check_in_list_id
8189
FROM attendees a
82-
JOIN product_check_in_lists tcil ON a.product_id = tcil.product_id
90+
JOIN product_check_in_lists pcil ON a.product_id = pcil.product_id
91+
JOIN orders o ON a.order_id = o.id
92+
JOIN check_in_lists cil ON pcil.check_in_list_id = cil.id
93+
JOIN event_settings es ON cil.event_id = es.event_id
8394
WHERE a.deleted_at IS NULL
84-
AND tcil.deleted_at IS NULL
85-
AND a.status = '$attendeeActiveStatus'
95+
AND pcil.deleted_at IS NULL
96+
AND pcil.check_in_list_id IN ($placeholders)
97+
AND (
98+
(es.allow_orders_awaiting_offline_payment_to_check_in = true AND a.status IN ('ACTIVE', 'AWAITING_PAYMENT') AND o.status IN ('COMPLETED', 'AWAITING_OFFLINE_PAYMENT'))
99+
OR
100+
(es.allow_orders_awaiting_offline_payment_to_check_in = false AND a.status = 'ACTIVE' AND o.status = 'COMPLETED')
101+
)
86102
)
87103
SELECT
88104
cil.id AS check_in_list_id,
@@ -96,7 +112,7 @@ public function getCheckedInAttendeeCountByIds(array $checkInListIds): Collectio
96112
GROUP BY cil.id;
97113
SQL;
98114

99-
$query = $this->db->select($sql, $checkInListIds);
115+
$query = $this->db->select($sql, array_merge($checkInListIds, $checkInListIds, $checkInListIds));
100116

101117
return collect($query)->map(
102118
static fn($item) => new CheckedInAttendeesCountDTO(
Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
<?php
2+
3+
use Illuminate\Database\Migrations\Migration;
4+
use Illuminate\Database\Schema\Blueprint;
5+
use Illuminate\Support\Facades\Schema;
6+
7+
return new class extends Migration {
8+
public function up(): void
9+
{
10+
Schema::table('product_check_in_lists', static function (Blueprint $table) {
11+
$table->index('check_in_list_id');
12+
});
13+
14+
Schema::table('attendees', static function (Blueprint $table) {
15+
$table->index('order_id');
16+
});
17+
18+
Schema::table('orders', static function (Blueprint $table) {
19+
$table->index('short_id');
20+
});
21+
22+
Schema::table('organizers', static function (Blueprint $table) {
23+
$table->index('account_id');
24+
});
25+
}
26+
27+
public function down(): void
28+
{
29+
Schema::table('product_check_in_lists', static function (Blueprint $table) {
30+
$table->dropIndex(['check_in_list_id']);
31+
});
32+
33+
Schema::table('attendees', static function (Blueprint $table) {
34+
$table->dropIndex(['order_id']);
35+
});
36+
37+
Schema::table('orders', static function (Blueprint $table) {
38+
$table->dropIndex(['short_id']);
39+
});
40+
41+
Schema::table('organizers', static function (Blueprint $table) {
42+
$table->dropIndex(['account_id']);
43+
});
44+
}
45+
};

0 commit comments

Comments
 (0)