From 8b3be0f059f7ae389c0df4287bb6549e5212d0d0 Mon Sep 17 00:00:00 2001 From: Jakob Schmitt Date: Wed, 9 Apr 2025 17:25:01 +0200 Subject: [PATCH 01/12] Add support for mysql database driver in database migration --- .../2020_01_25_113926_initial_db.php | 13 +- ...city_assignments_and_associated_tables.php | 4 +- .../2024_07_19_033929_add_missing_indexes.php | 9 +- ...08_032637_create_check_in_lists_tables.php | 37 +- ...325_add_event_id_to_attendee_check_ins.php | 30 +- ...9_20_032323_rename_tickets_to_products.php | 67 +- ...025_01_03_010511_create_invoices_table.php | 18 +- ...1_10_144325_add_index_to_orders_status.php | 15 +- backend/database/migrations/schema.mysql.sql | 781 ++++++++++++++++++ 9 files changed, 918 insertions(+), 56 deletions(-) create mode 100644 backend/database/migrations/schema.mysql.sql diff --git a/backend/database/migrations/2020_01_25_113926_initial_db.php b/backend/database/migrations/2020_01_25_113926_initial_db.php index a392f3ec..f1e40144 100644 --- a/backend/database/migrations/2020_01_25_113926_initial_db.php +++ b/backend/database/migrations/2020_01_25_113926_initial_db.php @@ -2,6 +2,7 @@ use Illuminate\Database\Migrations\Migration; use Illuminate\Support\Facades\DB; +use Nette\NotImplementedException; class InitialDb extends Migration { @@ -12,8 +13,16 @@ class InitialDb extends Migration */ public function up() { - DB::unprepared(file_get_contents(__DIR__ . '/extensions.sql')); - DB::unprepared(file_get_contents(__DIR__ . '/schema.sql')); + if (DB::getDriverName() === 'mysql') { + DB::unprepared(file_get_contents(__DIR__ . '/schema.mysql.sql')); + return; + } + if (DB::getDriverName() === 'pgsql') { + DB::unprepared(file_get_contents(__DIR__ . '/extensions.sql')); + DB::unprepared(file_get_contents(__DIR__ . '/schema.sql')); + return; + } + throw new NotImplementedException("Unsupported database driver: " . DB::getDriverName() . ". Only mysql and psql are supported."); } /** diff --git a/backend/database/migrations/2024_07_14_031511_create_capacity_assignments_and_associated_tables.php b/backend/database/migrations/2024_07_14_031511_create_capacity_assignments_and_associated_tables.php index 77839e52..0b7faf8b 100644 --- a/backend/database/migrations/2024_07_14_031511_create_capacity_assignments_and_associated_tables.php +++ b/backend/database/migrations/2024_07_14_031511_create_capacity_assignments_and_associated_tables.php @@ -34,8 +34,8 @@ public function up(): void $table->index('ticket_id'); $table->index('capacity_assignment_id'); - - $table->unique(['ticket_id', 'capacity_assignment_id']); + // mysql default max key length is 64 characters. Laravel's auto generated index name is too long, so we set a shorter custom one. + $table->unique(['ticket_id', 'capacity_assignment_id'], 'idx_ticket_id_capacity_assignment_id_unique'); }); Schema::table('ticket_prices', function (Blueprint $table) { diff --git a/backend/database/migrations/2024_07_19_033929_add_missing_indexes.php b/backend/database/migrations/2024_07_19_033929_add_missing_indexes.php index 897f64a0..679a5175 100644 --- a/backend/database/migrations/2024_07_19_033929_add_missing_indexes.php +++ b/backend/database/migrations/2024_07_19_033929_add_missing_indexes.php @@ -2,13 +2,20 @@ use Illuminate\Database\Migrations\Migration; use Illuminate\Database\Schema\Blueprint; +use Illuminate\Support\Facades\DB; use Illuminate\Support\Facades\Schema; return new class extends Migration { public function up(): void { Schema::table('orders', function (Blueprint $table) { - $table->index(['event_id', 'status', 'reserved_until', 'deleted_at']); + if (DB::getDriverName() === 'mysql') { + // status is a text column, so mysql needs a length for the index + // mysql max index size is 767 or 3072 bytes -> 8 byte event_id, 4*187 bytes status, 4 byte reserved_until, 4 byte deleted_at 4 or 5 bytes + DB::statement('CREATE INDEX orders_event_id_status_reserved_until_deleted_at_index ON orders (event_id, status(187), reserved_until, deleted_at)'); + } else { + $table->index(['event_id', 'status', 'reserved_until', 'deleted_at']); + } }); } diff --git a/backend/database/migrations/2024_08_08_032637_create_check_in_lists_tables.php b/backend/database/migrations/2024_08_08_032637_create_check_in_lists_tables.php index febfebee..1a071be7 100644 --- a/backend/database/migrations/2024_08_08_032637_create_check_in_lists_tables.php +++ b/backend/database/migrations/2024_08_08_032637_create_check_in_lists_tables.php @@ -76,10 +76,22 @@ public function up(): void // $table->dropColumn('checked_out_by'); }); - DB::statement('CREATE INDEX idx_attendees_ticket_id_deleted_at ON attendees(ticket_id) WHERE deleted_at IS NULL'); - DB::statement('CREATE INDEX idx_ticket_check_in_lists_ticket_id_deleted_at ON ticket_check_in_lists(ticket_id, check_in_list_id) WHERE deleted_at IS NULL'); - DB::statement('CREATE INDEX idx_attendee_check_ins_attendee_id_check_in_list_id_deleted_at ON attendee_check_ins(attendee_id, check_in_list_id) WHERE deleted_at IS NULL'); - + // mysql does not support where clauses in indecies + if (DB::getDriverName() === 'mysql') { + Schema::table('attendees', static function (Blueprint $table) { + $table->index(['ticket_id', 'deleted_at'], 'idx_attendees_ticket_id_deleted_at'); + }); + Schema::table('ticket_check_in_lists', static function (Blueprint $table) { + $table->index(['ticket_id', 'check_in_list_id', 'deleted_at'], 'idx_ticket_check_in_lists_ticket_id_deleted_at'); + }); + Schema::table('attendee_check_ins', static function (Blueprint $table) { + $table->index(['attendee_id', 'check_in_list_id', 'deleted_at'], 'idx_attendee_check_ins_attendee_id_check_in_list_id_deleted_at'); + }); + } else { + DB::statement('CREATE INDEX idx_attendees_ticket_id_deleted_at ON attendees(ticket_id) WHERE deleted_at IS NULL'); + DB::statement('CREATE INDEX idx_ticket_check_in_lists_ticket_id_deleted_at ON ticket_check_in_lists(ticket_id, check_in_list_id) WHERE deleted_at IS NULL'); + DB::statement('CREATE INDEX idx_attendee_check_ins_attendee_id_check_in_list_id_deleted_at ON attendee_check_ins(attendee_id, check_in_list_id) WHERE deleted_at IS NULL'); + } } public function down(): void @@ -94,8 +106,19 @@ public function down(): void Schema::dropIfExists('ticket_check_in_lists'); Schema::dropIfExists('check_in_lists'); - DB::statement('DROP INDEX IF EXISTS idx_attendees_ticket_id_deleted_at'); - DB::statement('DROP INDEX IF EXISTS idx_ticket_check_in_lists_ticket_id_deleted_at'); - DB::statement('DROP INDEX IF EXISTS idx_attendee_check_ins_attendee_id_check_in_list_id_deleted_at'); + if (DB::getDriverName() === 'mysql') { + Schema::table('attendees', static function (Blueprint $table) { + // must delete foreing key before dropping index + $table->dropForeign('fk_attendees_ticket_id'); + $table->dropIndex('idx_attendees_ticket_id_deleted_at'); + // restore foreign key + $table->foreign('ticket_id', 'fk_attendees_ticket_id')->references('id')->on('tickets')->onDelete('cascade'); + }); + // the other indecies get deleted by drop table + } else { + DB::statement('DROP INDEX IF EXISTS idx_attendees_ticket_id_deleted_at'); + DB::statement('DROP INDEX IF EXISTS idx_ticket_check_in_lists_ticket_id_deleted_at'); + DB::statement('DROP INDEX IF EXISTS idx_attendee_check_ins_attendee_id_check_in_list_id_deleted_at'); + } } }; diff --git a/backend/database/migrations/2024_08_17_140325_add_event_id_to_attendee_check_ins.php b/backend/database/migrations/2024_08_17_140325_add_event_id_to_attendee_check_ins.php index 79d4f524..fb3fd62a 100644 --- a/backend/database/migrations/2024_08_17_140325_add_event_id_to_attendee_check_ins.php +++ b/backend/database/migrations/2024_08_17_140325_add_event_id_to_attendee_check_ins.php @@ -9,18 +9,26 @@ { public function up(): void { - DB::transaction(static function () { + $transactional = static function () { Schema::table('attendee_check_ins', static function (Blueprint $table) { // Add the event_id column without a foreign key constraint first $table->unsignedBigInteger('event_id')->nullable()->after('attendee_id'); }); - DB::statement(' - UPDATE attendee_check_ins - SET event_id = attendees.event_id - FROM attendees - WHERE attendee_check_ins.attendee_id = attendees.id - '); + if (DB::getDriverName() === 'mysql') { + DB::statement(' + UPDATE attendee_check_ins + JOIN attendees ON attendee_check_ins.attendee_id = attendees.id + SET attendee_check_ins.event_id = attendees.event_id + '); + } else { + DB::statement(' + UPDATE attendee_check_ins + SET event_id = attendees.event_id + FROM attendees + WHERE attendee_check_ins.attendee_id = attendees.id + '); + } // Now, set the event_id column to be not nullable and add the foreign key constraint Schema::table('attendee_check_ins', static function (Blueprint $table) { @@ -29,7 +37,13 @@ public function up(): void $table->index('event_id'); }); - }); + }; + // mysql does not support changing columns in transations, only adding or dropping columns + if (DB::getDriverName() === 'mysql') { + $transactional(); + } else { + DB::transaction($transactional); + } } public function down(): void diff --git a/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php b/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php index 907f3fab..5d90dd92 100644 --- a/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php +++ b/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php @@ -16,8 +16,11 @@ public function up(): void Schema::rename('ticket_check_in_lists', 'product_check_in_lists'); Schema::rename('ticket_capacity_assignments', 'product_capacity_assignments'); - DB::statement('ALTER SEQUENCE ticket_capacity_assignments_id_seq RENAME TO product_capacity_assignments_id_seq'); - DB::statement('ALTER SEQUENCE ticket_check_in_lists_id_seq RENAME TO product_check_in_lists_id_seq'); + // mysql's auto_increments have no name, therefore theres no need to rename them + if (DB::getDriverName() !== 'mysql') { + DB::statement('ALTER SEQUENCE ticket_capacity_assignments_id_seq RENAME TO product_capacity_assignments_id_seq'); + DB::statement('ALTER SEQUENCE ticket_check_in_lists_id_seq RENAME TO product_check_in_lists_id_seq'); + } Schema::table('order_items', function (Blueprint $table) { $table->renameColumn('ticket_id', 'product_id'); @@ -77,17 +80,17 @@ public function up(): void $table->renameColumn('ticket_page_message', 'product_page_message'); }); - $this->renameIndex('idx_ticket_prices_ticket_id', 'idx_product_prices_product_id'); - $this->renameIndex('order_items_ticket_id_index', 'order_items_product_id_index'); - $this->renameIndex('order_items_ticket_price_id_index', 'order_items_product_price_id_index'); - $this->renameIndex('idx_attendees_ticket_id_deleted_at', 'idx_attendees_product_id_deleted_at'); - $this->renameIndex('ticket_tax_and_fees_ticket_id_index', 'product_tax_and_fees_product_id_index'); - $this->renameIndex('idx_ticket_questions_active', 'idx_product_questions_active'); - $this->renameIndex('ticket_check_in_lists_ticket_id_check_in_list_id_index', 'product_check_in_lists_product_id_check_in_list_id_index'); - $this->renameIndex('idx_ticket_check_in_lists_ticket_id_deleted_at', 'idx_product_check_in_lists_product_id_deleted_at'); - $this->renameIndex('attendee_check_ins_ticket_id_index', 'attendee_check_ins_product_id_index'); - $this->renameIndex('ticket_capacity_assignments_ticket_id_index', 'product_capacity_assignments_product_id_index'); - $this->renameIndex('attendees_ticket_prices_id_fk', 'attendees_product_prices_id_fk'); + $this->renameIndex('product_prices', 'idx_ticket_prices_ticket_id', 'idx_product_prices_product_id'); + $this->renameIndex('order_items', 'order_items_ticket_id_index', 'order_items_product_id_index'); + $this->renameIndex('order_items', 'order_items_ticket_price_id_index', 'order_items_product_price_id_index'); + $this->renameIndex('attendees', 'idx_attendees_ticket_id_deleted_at', 'idx_attendees_product_id_deleted_at'); + $this->renameIndex('procut_tax_and_fees', 'ticket_tax_and_fees_ticket_id_index', 'product_tax_and_fees_product_id_index'); + $this->renameIndex('product_questions', 'idx_ticket_questions_active', 'idx_product_questions_active'); + $this->renameIndex('product_check_in_lists', 'ticket_check_in_lists_ticket_id_check_in_list_id_index', 'product_check_in_lists_product_id_check_in_list_id_index'); + $this->renameIndex('product_check_in_lists', 'idx_ticket_check_in_lists_ticket_id_deleted_at', 'idx_product_check_in_lists_product_id_deleted_at'); + $this->renameIndex('attendee_check_ins', 'attendee_check_ins_ticket_id_index', 'attendee_check_ins_product_id_index'); + $this->renameIndex('product_capacity_assignments', 'ticket_capacity_assignments_ticket_id_index', 'product_capacity_assignments_product_id_index'); + $this->renameIndex('attendees', 'attendees_ticket_prices_id_fk', 'attendees_product_prices_id_fk'); } public function down(): void @@ -100,9 +103,11 @@ public function down(): void Schema::rename('product_check_in_lists', 'ticket_check_in_lists'); Schema::rename('product_capacity_assignments', 'ticket_capacity_assignments'); - // Rename sequences back - DB::statement('ALTER SEQUENCE product_capacity_assignments_id_seq RENAME TO ticket_capacity_assignments_id_seq'); - DB::statement('ALTER SEQUENCE product_check_in_lists_id_seq RENAME TO ticket_check_in_lists_id_seq'); + if (DB::getDriverName() !== 'mysql') { + // Rename sequences back + DB::statement('ALTER SEQUENCE product_capacity_assignments_id_seq RENAME TO ticket_capacity_assignments_id_seq'); + DB::statement('ALTER SEQUENCE product_check_in_lists_id_seq RENAME TO ticket_check_in_lists_id_seq'); + } Schema::table('order_items', function (Blueprint $table) { $table->renameColumn('product_id', 'ticket_id'); @@ -162,21 +167,25 @@ public function down(): void $table->renameColumn('product_page_message', 'ticket_page_message'); }); - $this->renameIndex('idx_product_prices_product_id', 'idx_ticket_prices_ticket_id'); - $this->renameIndex('order_items_product_id_index', 'order_items_ticket_id_index'); - $this->renameIndex('order_items_product_price_id_index', 'order_items_ticket_price_id_index'); - $this->renameIndex('idx_attendees_product_id_deleted_at', 'idx_attendees_ticket_id_deleted_at'); - $this->renameIndex('product_tax_and_fees_product_id_index', 'ticket_tax_and_fees_ticket_id_index'); - $this->renameIndex('idx_product_questions_active', 'idx_ticket_questions_active'); - $this->renameIndex('product_check_in_lists_product_id_check_in_list_id_index', 'ticket_check_in_lists_ticket_id_check_in_list_id_index'); - $this->renameIndex('idx_product_check_in_lists_product_id_deleted_at', 'idx_ticket_check_in_lists_ticket_id_deleted_at'); - $this->renameIndex('attendee_check_ins_product_id_index', 'attendee_check_ins_ticket_id_index'); - $this->renameIndex('product_capacity_assignments_product_id_index', 'ticket_capacity_assignments_ticket_id_index'); - $this->renameIndex('attendees_product_prices_id_fk', 'attendees_ticket_prices_id_fk'); + $this->renameIndex('ticket_prices', 'idx_product_prices_product_id', 'idx_ticket_prices_ticket_id'); + $this->renameIndex('order_items', 'order_items_product_id_index', 'order_items_ticket_id_index'); + $this->renameIndex('order_items', 'order_items_product_price_id_index', 'order_items_ticket_price_id_index'); + $this->renameIndex('attendees', 'idx_attendees_product_id_deleted_at', 'idx_attendees_ticket_id_deleted_at'); + $this->renameIndex('ticket_tax_tax_and_fees', 'product_tax_and_fees_product_id_index', 'ticket_tax_and_fees_ticket_id_index'); + $this->renameIndex('ticket_questions', 'idx_product_questions_active', 'idx_ticket_questions_active'); + $this->renameIndex('ticket_check_in_lists', 'product_check_in_lists_product_id_check_in_list_id_index', 'ticket_check_in_lists_ticket_id_check_in_list_id_index'); + $this->renameIndex('ticket_check_in_lists', 'idx_product_check_in_lists_product_id_deleted_at', 'idx_ticket_check_in_lists_ticket_id_deleted_at'); + $this->renameIndex('attendee_check_ins', 'attendee_check_ins_product_id_index', 'attendee_check_ins_ticket_id_index'); + $this->renameIndex('ticket_capacity_assignments', 'product_capacity_assignments_product_id_index', 'ticket_capacity_assignments_ticket_id_index'); + $this->renameIndex('attendees', 'attendees_product_prices_id_fk', 'attendees_ticket_prices_id_fk'); } - private function renameIndex($from, $to): void + private function renameIndex($table, $from, $to): void { - DB::statement("ALTER INDEX IF EXISTS {$from} RENAME TO {$to}"); + if (DB::getDriverName() === 'mysql') { + DB::statement("ALTER TABLE {$table} RENAME INDEX `{$from}` TO `{$to}`"); + } else { + DB::statement("ALTER INDEX IF EXISTS {$from} RENAME TO {$to}"); + } } }; diff --git a/backend/database/migrations/2025_01_03_010511_create_invoices_table.php b/backend/database/migrations/2025_01_03_010511_create_invoices_table.php index d8024b6a..6f4f27a3 100644 --- a/backend/database/migrations/2025_01_03_010511_create_invoices_table.php +++ b/backend/database/migrations/2025_01_03_010511_create_invoices_table.php @@ -19,13 +19,29 @@ public function up(): void $table->string('status', 20)->default('PENDING'); $table->jsonb('items'); $table->jsonb('taxes_and_fees')->nullable(); - $table->uuid()->default(DB::raw('gen_random_uuid()')); + $uuid = $table->uuid(); + if (DB::getDriverName() !== 'mysql') { + $uuid->default(DB::raw('gen_random_uuid()')); + } $table->timestamps(); $table->softDeletes(); $table->foreign('order_id')->references('id')->on('orders')->onDelete('cascade'); $table->foreign('account_id')->references('id')->on('accounts')->onDelete('cascade'); }); + if (DB::getDriverName() === 'mysql') { + // mysql can't use uuid() as a default for a column but this is a perfect substitute + DB::statement(' + CREATE TRIGGER before_insert_invoices + BEFORE INSERT ON invoices + FOR EACH ROW + BEGIN + IF NEW.uuid IS NULL THEN + SET NEW.uuid = UUID(); + END IF; + END; + '); + } } public function down(): void diff --git a/backend/database/migrations/2025_01_10_144325_add_index_to_orders_status.php b/backend/database/migrations/2025_01_10_144325_add_index_to_orders_status.php index e2724caf..c704c451 100644 --- a/backend/database/migrations/2025_01_10_144325_add_index_to_orders_status.php +++ b/backend/database/migrations/2025_01_10_144325_add_index_to_orders_status.php @@ -7,17 +7,20 @@ public function up(): void { DB::commit(); - DB::statement('CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_orders_status ON orders (status);'); - DB::statement('CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_orders_refund_status ON orders (refund_status);'); - DB::statement('CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_orders_payment_status ON orders (payment_status);'); + $psql = DB::getDriverName() === 'pgsql' ? "CONCURRENTLY IF NOT EXISTS" : ""; + $myslCharLimit = DB::getDriverName() === 'mysql' ? "(187)" : ""; + DB::statement("CREATE INDEX $psql idx_orders_status ON orders (status{$myslCharLimit});"); + DB::statement("CREATE INDEX $psql idx_orders_refund_status ON orders (refund_status{$myslCharLimit});"); + DB::statement("CREATE INDEX $psql idx_orders_payment_status ON orders (payment_status{$myslCharLimit});"); } public function down(): void { DB::commit(); - DB::statement('DROP INDEX CONCURRENTLY IF EXISTS idx_orders_status;'); - DB::statement('DROP INDEX CONCURRENTLY IF EXISTS idx_orders_refund_status;'); - DB::statement('DROP INDEX CONCURRENTLY IF EXISTS idx_orders_payment_status;'); + $psql = DB::getDriverName() === 'pgsql' ? "CONCURRENTLY IF NOT EXISTS" : ""; + DB::statement("DROP INDEX $psql idx_orders_status;"); + DB::statement("DROP INDEX $psql idx_orders_refund_status;"); + DB::statement("DROP INDEX $psql idx_orders_payment_status;"); } }; diff --git a/backend/database/migrations/schema.mysql.sql b/backend/database/migrations/schema.mysql.sql new file mode 100644 index 00000000..2969f412 --- /dev/null +++ b/backend/database/migrations/schema.mysql.sql @@ -0,0 +1,781 @@ +-- DO NOT MODIFY THIS FILE. Create a new migration file instead. + +create table if not exists migrations +( + id bigint unsigned auto_increment primary key, + migration varchar(255) not null, + batch integer not null +); + +create table if not exists personal_access_tokens +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + tokenable_type varchar(255) not null, + tokenable_id BIGINT UNSIGNED not null, + name varchar(255) not null, + token varchar(64) not null, + abilities text, + last_used_at timestamp(0), + expires_at timestamp(0), + created_at timestamp(0), + updated_at timestamp(0), + constraint personal_access_tokens_token_unique + unique (token) +); + +create index personal_access_tokens_tokenable_type_tokenable_id_index + on personal_access_tokens (tokenable_type, tokenable_id); + +create table if not exists password_reset_tokens +( + email varchar(255) not null, + token varchar(255) not null, + created_at timestamp, + deleted_at timestamp, + updated_at timestamp, + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY +); + +create index password_reset_tokens_email_index + on password_reset_tokens (email); + +create index password_reset_tokens_token_index + on password_reset_tokens (token); + +create table if not exists failed_jobs +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + uuid varchar(255) not null, + connection text not null, + queue text not null, + payload text not null, + exception text not null, + failed_at timestamp(0) default CURRENT_TIMESTAMP not null, + constraint failed_jobs_uuid_unique + unique (uuid) +); + +create table if not exists accounts +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + currency_code varchar(3) not null default 'USD', + timezone varchar(255), + created_at timestamp, + updated_at timestamp, + deleted_at timestamp, + name TEXT not null, + email TEXT not null, + stripe_account_id varchar(50), + short_id varchar(20) not null, + stripe_connect_setup_complete boolean default false, + account_verified_at timestamp +); + +create table if not exists password_resets +( + email varchar(200), + token varchar(200), + created_at timestamp, + updated_at timestamp, + deleted_at timestamp, + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + ip_address TEXT not null, + user_agent TEXT +); + +create table if not exists timezones +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + name varchar(64) not null, + deleted_at timestamp +); + +create table if not exists roles +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + name TEXT, + permissions JSON not null, + account_id BIGINT UNSIGNED, + constraint roles_accounts_id_fk + foreign key (account_id) references accounts(id) +); + +create table if not exists users +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + email varchar(255) not null, + email_verified_at timestamp(0), + password varchar(255) not null, + remember_token varchar(100), + created_at timestamp(0), + updated_at timestamp(0), + deleted_at timestamp, + first_name TEXT not null, + last_name TEXT, + pending_email TEXT, + timezone TEXT not null +); + +create table if not exists event_logs +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + user_id BIGINT UNSIGNED not null, + type varchar(255) not null, + entity_id BIGINT UNSIGNED not null, + entity_type BIGINT UNSIGNED not null, + ip_address TEXT, + user_agent TEXT, + data JSON, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + + constraint event_logs_users_id_fk + foreign key (user_id) references users(id) +); + +create table if not exists taxes_and_fees +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + name varchar(255) not null, + calculation_type varchar(20) not null, + rate DECIMAL(10, 3) not null, + is_active boolean default true, + description text, + created_at timestamp, + deleted_at timestamp, + updated_at timestamp, + account_id BIGINT UNSIGNED not null, + is_default boolean default false not null, + type varchar(20) not null, + CONSTRAINT calculation_method_check + CHECK (calculation_type IN ('FIXED', 'PERCENTAGE')), + + CONSTRAINT type_check + CHECK (type IN ('TAX', 'FEE')) +); + +ALTER TABLE taxes_and_fees +MODIFY COLUMN is_default BOOLEAN DEFAULT FALSE NOT NULL COMMENT 'Whether to apply to all new tickets automatically'; + +create index tax_and_fees_account_id_index + on taxes_and_fees (account_id); + +create table if not exists images +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + entity_id BIGINT UNSIGNED, + entity_type varchar(120), + type varchar(40), + filename varchar(255), + disk varchar(20), + path text, + size integer, + mime_type varchar(50), + created_at timestamp default CURRENT_TIMESTAMP, + updated_at timestamp default CURRENT_TIMESTAMP, + deleted_at timestamp +); + +create index idx_images_entity_id + on images (entity_id); + +create index idx_images_type + on images (type); + +create index idx_images_entity_type + on images (entity_type); + +create table if not exists organizers +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + account_id BIGINT UNSIGNED not null, + name varchar(255) not null, + email varchar(255) not null, + phone varchar(20), + website varchar(255), + description text, + created_at timestamp not null, + updated_at timestamp not null, + deleted_at timestamp, + currency varchar(3) not null default 'USD', + timezone varchar(255) not null, + + foreign key (account_id) references accounts(id) +); + +create table if not exists events +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + title varchar(255) not null, + account_id BIGINT UNSIGNED not null, + user_id BIGINT UNSIGNED not null, + start_date timestamp, + end_date timestamp, + description text, + status TEXT, + location_details JSON, + currency varchar(3) not null default 'USD', + timezone TEXT, + attributes JSON, + created_at timestamp not null, + updated_at timestamp not null, + deleted_at timestamp, + location varchar(255), + organizer_id BIGINT UNSIGNED, + short_id varchar(32) not null, + ticket_quantity_available integer, + + constraint fk_events_account_id + foreign key (account_id) references accounts(id) + on update cascade on delete cascade, + constraint fk_events_user_id + foreign key (user_id) references users(id) + on delete cascade, + constraint events_organizers_id_fk + foreign key (organizer_id) references organizers(id) +); + +create index events_account_id_index + on events (account_id); + +create index events_user_id_index + on events (user_id); + +create index events_organizer_id_index + on events (organizer_id); + +create table if not exists tickets +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + title varchar(255) not null, + event_id BIGINT UNSIGNED not null, + sale_start_date timestamp, + sale_end_date timestamp, + max_per_order integer, + description text, + min_per_order integer, + sales_volume DECIMAL(14, 2) not null default 0.00, + sales_tax_volume DECIMAL(14, 2) not null default 0.00, + hide_before_sale_start_date boolean not null default false, + hide_after_sale_end_date boolean not null default false, + hide_when_sold_out boolean not null default false, + show_quantity_remaining boolean not null default false, + is_hidden_without_promo_code boolean not null default false, + `order` integer not null, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + type varchar(20) not null default 'PAID', + is_hidden boolean default false, + + constraint fk_tickets_event_id + foreign key (event_id) references events(id) + on delete cascade +); + +create table if not exists promo_codes +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + code varchar(50) not null, + discount DECIMAL(14, 2) default 0.00 not null, + applicable_ticket_ids JSON, + expiry_date timestamp, + event_id BIGINT UNSIGNED not null, + discount_type TEXT, + attendee_usage_count integer default 0 not null, + order_usage_count integer default 0 not null, + max_allowed_usages integer, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + + constraint promo_codes_events_id_fk + foreign key (event_id) references events(id) +); + +create index promo_codes_code_index + on promo_codes (code); + +create index promo_codes_event_id_index + on promo_codes (event_id); + +-- TODO: INDEX ON JSON PATH +-- create index promo_codes_applicable_ticket_ids_index +-- on promo_codes (applicable_ticket_ids); + +create table if not exists orders +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + short_id varchar(20) not null, + event_id BIGINT UNSIGNED not null, + total_before_additions DECIMAL(14, 2) default 0.00 not null, + total_refunded DECIMAL(14, 2) default 0.00 not null, + total_gross DECIMAL(14, 2) default 0.00 not null, + currency varchar(3) not null, + first_name varchar(50), + last_name varchar(50), + email varchar(255), + status TEXT not null, + payment_status TEXT, + refund_status TEXT, + reserved_until timestamp(0), + is_manually_created boolean default false not null, + session_id varchar(40), + public_id text not null, -- ARBITRARY LENGTH 300 + point_in_time_data JSON, + payment_gateway TEXT, + promo_code_id BIGINT UNSIGNED, + promo_code TEXT, + address JSON, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + taxes_and_fees_rollup JSON, + total_tax DECIMAL(14, 2) default 0.00 not null, + total_fee DECIMAL(14, 2) default 0.00 not null, + + constraint orders_pk + unique (public_id(255)), + constraint fk_orders_event_id + foreign key (event_id) references events(id), + constraint orders_promo_codes_id_fk + foreign key (promo_code_id) references promo_codes(id) +); + +create index orders_promo_code_id_index + on orders (promo_code_id); + +-- using fulltext instead of gin because it does not exist +create FULLTEXT index idx_orders_first_name_fulltext + on orders (first_name); + +create FULLTEXT index idx_orders_last_name_fulltext + on orders (last_name); + +create FULLTEXT index idx_orders_email_fulltext + on orders (email); + +create FULLTEXT index idx_orders_public_id_fulltext + on orders (public_id); + +create table if not exists questions +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + event_id BIGINT UNSIGNED not null, + title text not null, + required boolean default false not null, + type TEXT, + options JSON, + belongs_to TEXT not null, + created_at timestamp not null, + updated_at timestamp not null, + deleted_at timestamp, + `order` integer not null default 1, + is_hidden boolean default false not null, + + constraint questions_event_id_fk + foreign key (event_id) references events(id) +); + +create table if not exists stripe_payments +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + order_id BIGINT UNSIGNED not null, + payment_intent_id TEXT not null, + charge_id TEXT, + payment_method_id TEXT, + amount_received BIGINT UNSIGNED, + created_at timestamp, + updated_at timestamp, + deleted_at timestamp, + last_error json, + connected_account_id varchar(50), + + constraint stripe_payments_orders_id_fk + foreign key (order_id) references orders(id) +); + +create table if not exists messages +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + event_id BIGINT UNSIGNED not null, + subject varchar(255) not null, + message text not null, + type varchar(40) not null, + recipient_ids JSON, + sent_at timestamp, + sent_by_user_id BIGINT UNSIGNED not null, + attendee_ids JSON, + ticket_ids JSON, + order_id BIGINT UNSIGNED, + status varchar(20) not null, + send_data JSON, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + + constraint messages_events_id_fk + foreign key (event_id) references events(id), + constraint messages_users_id_fk + foreign key (sent_by_user_id) references users(id) +); + +create table if not exists affiliates +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + code text not null, + event_id BIGINT UNSIGNED, + sales_volume DECIMAL(14, 2), + unique_visitors integer default 0 not null, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + + constraint affiliates_events_id_fk + foreign key (event_id) references events(id) +); + +create unique index affiliates_code_uindex + on affiliates (code(255)); + +create index affiliates_event_id_index + on affiliates (event_id); + +create table if not exists event_statistics +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + event_id BIGINT UNSIGNED not null, + unique_views BIGINT UNSIGNED default 0 not null, + total_views BIGINT UNSIGNED default 0 not null, + sales_total_gross DECIMAL(14, 2) default 0.00 not null, + total_tax DECIMAL(14, 2) default 0.00 not null, + sales_total_before_additions DECIMAL(14, 2) default 0.00 not null, + created_at timestamp not null, + deleted_at timestamp, + updated_at timestamp, + total_fee DECIMAL(14, 2) default 0.00 not null, + tickets_sold integer default 0 not null, + version integer default 0 not null, + orders_created integer default 0 not null, + total_refunded DECIMAL(14, 2) default 0 not null, + + constraint event_statistics_events_id_fk + foreign key (event_id) references events(id) +); + +create index event_statistics_event_id_index + on event_statistics (event_id); + +create table if not exists event_daily_statistics +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + sales_total_gross DECIMAL(14, 2) default 0.00 not null, + total_tax DECIMAL(14, 2) default 0.00 not null, + sales_total_before_additions DECIMAL(14, 2) default 0.00 not null, + tickets_sold integer default 0 not null, + orders_created integer default 0 not null, + date date not null, + created_at timestamp not null, + deleted_at timestamp, + updated_at timestamp, + total_fee DECIMAL(14, 2) default 0 not null, + event_id BIGINT UNSIGNED not null, + version integer default 0 not null, + total_refunded DECIMAL(14, 2) default 0 not null, + total_views BIGINT UNSIGNED default 0 not null, + + constraint event_daily_statistics_events_id_fk + foreign key (event_id) references events(id) +); + +create index event_daily_statistics_event_id_index + on event_daily_statistics (event_id); + +create table if not exists ticket_taxes_and_fees +( + id integer AUTO_INCREMENT PRIMARY KEY, + ticket_id BIGINT UNSIGNED not null, + tax_and_fee_id BIGINT UNSIGNED not null, + constraint ticket_tax_and_fees_tickets_id_fk + foreign key (ticket_id) references tickets(id) + on delete cascade, + constraint ticket_tax_and_fees_tax_and_fees_id_fk + foreign key (tax_and_fee_id) references taxes_and_fees(id) + on delete cascade +); + +create index ticket_tax_and_fees_tax_and_fee_id_index + on ticket_taxes_and_fees (tax_and_fee_id); + +create index ticket_tax_and_fees_ticket_id_index + on ticket_taxes_and_fees (ticket_id); + +create table if not exists ticket_prices +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + ticket_id BIGINT UNSIGNED not null, + price DECIMAL(14, 2) not null, + label varchar(255), + sale_start_date timestamp, + sale_end_date timestamp, + created_at timestamp not null, + updated_at timestamp, + deleted_at timestamp, + initial_quantity_available integer, + quantity_sold integer default 0 not null, + is_hidden boolean default false, + `order` integer default 1 not null, + constraint fk_ticket_prices_ticket_id + foreign key (ticket_id) references tickets(id) + on delete cascade, + check (price >= 0) +); + +create index idx_ticket_prices_ticket_id + on ticket_prices (ticket_id); + +create index idx_ticket_prices_dates + on ticket_prices (sale_start_date, sale_end_date); + +create table if not exists order_items +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + total_before_additions DECIMAL(14, 2) not null, + quantity integer not null, + order_id BIGINT UNSIGNED not null, + ticket_id BIGINT UNSIGNED not null, + item_name TEXT, + price DECIMAL(14, 2) not null, + price_before_discount DECIMAL(14, 2), + deleted_at timestamp, + total_tax DECIMAL(14, 2) default 0.00 not null, + total_gross DECIMAL(14, 2), + total_service_fee DECIMAL(14, 2) default 0.00, + taxes_and_fees_rollup JSON, + ticket_price_id BIGINT UNSIGNED not null, + + constraint fk_order_items_order_id + foreign key (order_id) references orders(id) + on delete cascade, + constraint fk_order_items_ticket_id + foreign key (ticket_id) references tickets(id), + constraint order_items_ticket_prices_id_fk + foreign key (ticket_price_id) references ticket_prices(id) +); + +create index order_items_order_id_index + on order_items (order_id); + +create index order_items_ticket_id_index + on order_items (ticket_id); + +create index order_items_ticket_price_id_index + on order_items (ticket_price_id); + +create table if not exists attendees +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + short_id TEXT not null, + first_name varchar(255) not null default '', + last_name varchar(255) not null default '', + email varchar(255) not null, + order_id BIGINT UNSIGNED not null, + ticket_id BIGINT UNSIGNED not null, + event_id BIGINT UNSIGNED not null, + public_id TEXT not null, + status varchar(20) not null, + checked_in_by BIGINT UNSIGNED, + checked_in_at timestamp, + created_at timestamp not null, + updated_at timestamp not null, + deleted_at timestamp, + checked_out_by BIGINT UNSIGNED, + ticket_price_id BIGINT UNSIGNED not null, + + constraint fk_attendees_order_id + foreign key (order_id) references orders(id) + on delete cascade, + constraint fk_attendees_ticket_id + foreign key (ticket_id) references tickets(id) + on delete cascade, + constraint attendees_events_id_fk + foreign key (event_id) references events(id) + on delete cascade, + constraint fk_attendees_checked_in_by_id + foreign key (checked_in_by) references users(id) + on delete cascade, + constraint attendees_users_id_fk + foreign key (checked_out_by) references users(id), + constraint attendees_ticket_prices_id_fk + foreign key (ticket_price_id) references ticket_prices(id) +); + +create FULLTEXT index idx_attendees_first_name_fulltext + on attendees (first_name); + +create FULLTEXT index idx_attendees_last_name_fulltext + on attendees (last_name); + +create FULLTEXT index idx_attendees_email_fulltext + on attendees (email); + +create FULLTEXT index idx_attendees_public_id_fulltext + on attendees (public_id); + +ALTER TABLE attendees + ADD COLUMN public_id_lower VARCHAR(255) GENERATED ALWAYS AS (LOWER(public_id)) STORED; + +CREATE INDEX idx_attendees_public_id_lower + ON attendees (public_id_lower); +-- TODO: code has to use column public_id_lower instead of public_id when using strtolower + +create table if not exists question_answers +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + question_id BIGINT UNSIGNED not null, + order_id BIGINT UNSIGNED not null, + attendee_id BIGINT UNSIGNED, + ticket_id BIGINT UNSIGNED, + created_at timestamp not null, + updated_at timestamp not null, + deleted_at timestamp, + answer JSON, + + constraint fk_question_answers_question_id + foreign key (question_id) references questions(id), + constraint fk_orders_order_id + foreign key (order_id) references orders(id), + constraint fk_attendeed_attendee_id + foreign key (attendee_id) references attendees(id), + constraint fk_tickets_ticket_id + foreign key (ticket_id) references tickets(id) +); + +create index question_answers_attendee_id_index + on question_answers (attendee_id); + +create index question_answers_order_id_index + on question_answers (order_id); + +create index question_answers_question_id_index + on question_answers (question_id); + +create table if not exists ticket_questions +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + ticket_id BIGINT UNSIGNED not null, + question_id BIGINT UNSIGNED not null, + deleted_at timestamp, + constraint fk_ticket_questions_ticket_id + foreign key (ticket_id) references tickets(id) + on delete cascade, + constraint fk_ticket_questions_question_id + foreign key (question_id) references questions(id) + on delete cascade +); +ALTER TABLE ticket_questions + ADD COLUMN is_active TINYINT(1) AS (IF(deleted_at IS NULL, 1, 0)) STORED; +-- Create a unique index on active rows only (emulated via the generated column) +CREATE UNIQUE INDEX idx_ticket_questions_active + ON ticket_questions (ticket_id, question_id, is_active); + +create table if not exists event_settings +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + pre_checkout_message text, + post_checkout_message text, + ticket_page_message text, + continue_button_text varchar(100), + email_footer_message text, + support_email varchar(255), + event_id BIGINT UNSIGNED not null, + created_at timestamp not null, + updated_at timestamp not null, + deleted_at timestamp, + require_attendee_details boolean default true not null, + order_timeout_in_minutes integer default 15 not null, + website_url varchar(400), + maps_url varchar(400), + homepage_background_color varchar(20), + homepage_primary_text_color varchar(20), + homepage_primary_color varchar(20), + homepage_secondary_text_color varchar(20), + homepage_secondary_color varchar(20), + location_details JSON, + online_event_connection_details text, + is_online_event boolean default false not null, + allow_search_engine_indexing boolean default true not null, + seo_title varchar(255), + seo_description varchar(255), + social_media_handles JSON, + show_social_media_handles boolean, + seo_keywords varchar(255), + notify_organizer_of_new_orders boolean default true not null, + price_display_mode varchar(255) not null default 'INCLUSIVE', + hide_getting_started_page boolean default false not null, + show_share_buttons boolean default true not null, + constraint event_settings_events_id_fk + foreign key (event_id) references events(id) + on delete cascade, + CONSTRAINT event_settings_price_display_mode_check + CHECK (price_display_mode IN ('INCLUSIVE', 'EXCLUSIVE')) +); + +create index event_settings_event_id_index + on event_settings (event_id); + +create table if not exists account_users +( + id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, + account_id BIGINT UNSIGNED not null, + user_id BIGINT UNSIGNED not null, + role varchar(100), + created_at timestamp default now(), + deleted_at timestamp, + updated_at timestamp, + is_account_owner boolean default false not null, + invited_by_user_id BIGINT UNSIGNED, + last_login_at timestamp, + status varchar(40) default 'INVITED' not null, + + unique (account_id, user_id, role), + constraint fk_account_users_accounts + foreign key (account_id) references accounts(id) + on delete cascade, + constraint fk_account_users_users + foreign key (user_id) references users(id) + on delete cascade, + constraint account_users_users_id_fk + foreign key (invited_by_user_id) references users(id) +); + +create index idx_account_users_account_id + on account_users (account_id); + +create index idx_account_users_user_id + on account_users (user_id); + +create index idx_account_users_role + on account_users (role); + +create view question_and_answer_views + (question_id, event_id, belongs_to, question_type, first_name, last_name, attendee_id, order_id, title, + answer, question_answer_id) +as +SELECT q.id AS question_id, + q.event_id, + q.belongs_to, + q.type AS question_type, + a.first_name, + a.last_name, + a.id AS attendee_id, + qa.order_id, + q.title, + qa.answer, + qa.id as question_answer_id +FROM question_answers qa + LEFT JOIN attendees a ON a.id = qa.attendee_id + JOIN orders o ON qa.order_id = o.id + JOIN questions q ON q.id = qa.question_id; + From d271832893c2a106014b51108525f3403409dae1 Mon Sep 17 00:00:00 2001 From: Jakob Schmitt Date: Wed, 9 Apr 2025 20:06:44 +0200 Subject: [PATCH 02/12] Update manual SQL queries to work in mysql --- .../Repository/Eloquent/ProductRepository.php | 67 ++++++++++++++----- .../Domain/Event/EventStatsFetchService.php | 14 +++- .../Report/Reports/DailySalesReport.php | 17 +++-- .../Report/Reports/PromoCodesReport.php | 19 ++++-- 4 files changed, 89 insertions(+), 28 deletions(-) diff --git a/backend/app/Repository/Eloquent/ProductRepository.php b/backend/app/Repository/Eloquent/ProductRepository.php index 707bec53..22000681 100644 --- a/backend/app/Repository/Eloquent/ProductRepository.php +++ b/backend/app/Repository/Eloquent/ProductRepository.php @@ -19,6 +19,7 @@ use Illuminate\Database\Eloquent\Builder; use Illuminate\Pagination\LengthAwarePaginator; use Illuminate\Support\Collection; +use Illuminate\Support\Facades\DB; use RuntimeException; use Throwable; @@ -203,14 +204,30 @@ public function bulkUpdateProductsAndCategories(int $eventId, array $productUpda $productOrders = range(1, count($productUpdates)); $productCategoryIds = array_column($productUpdates, 'product_category_id'); - $productParameters = [ - 'eventId' => $eventId, - 'productIds' => '{' . implode(',', $productIds) . '}', - 'productOrders' => '{' . implode(',', $productOrders) . '}', - 'productCategoryIds' => '{' . implode(',', $productCategoryIds) . '}', - ]; - - $productUpdateQuery = "WITH new_order AS ( + if (DB::getDriverName() === 'mysql') { + for ($i = 0; $i < count($productIds); $i++) { + $this->db->update("UPDATE products + SET `order` = :productOrder, + product_category_id = :productCategoryId, + updated_at = NOW() + WHERE products.id = :productId AND products.event_id = :eventId + ", [ + "productOrder" => $productOrders[$i], + "productCategoryId" => $productCategoryIds[$i], + "productId" => $productIds[$i], + "eventId" => $eventId, + ]); + } + } else { + + $productParameters = [ + 'eventId' => $eventId, + 'productIds' => '{' . implode(',', $productIds) . '}', + 'productOrders' => '{' . implode(',', $productOrders) . '}', + 'productCategoryIds' => '{' . implode(',', $productCategoryIds) . '}', + ]; + + $productUpdateQuery = "WITH new_order AS ( SELECT unnest(:productIds::bigint[]) AS product_id, unnest(:productOrders::int[]) AS order, unnest(:productCategoryIds::bigint[]) AS category_id @@ -222,18 +239,33 @@ public function bulkUpdateProductsAndCategories(int $eventId, array $productUpda FROM new_order WHERE products.id = new_order.product_id AND products.event_id = :eventId"; - $this->db->update($productUpdateQuery, $productParameters); + $this->db->update($productUpdateQuery, $productParameters); + } $categoryIds = array_column($categoryUpdates, 'id'); $categoryOrders = array_column($categoryUpdates, 'order'); - $categoryParameters = [ - 'eventId' => $eventId, - 'categoryIds' => '{' . implode(',', $categoryIds) . '}', - 'categoryOrders' => '{' . implode(',', $categoryOrders) . '}', - ]; - - $categoryUpdateQuery = "WITH new_category_order AS ( + if (DB::getDriverName() === 'mysql') { + for ($i = 0; $i < count($categoryIds); $i++) { + $this->db->update("UPDATE product_categories + SET `order` = :categoryOrder, + updated_at = NOW() + WHERE product_categories.id = :categoryId AND product_categories.event_id = :eventId + ", [ + "categoryOrder" => $categoryOrders[$i], + "categoryId" => $categoryIds[$i], + "eventId" => $eventId, + ]); + } + } else { + + $categoryParameters = [ + 'eventId' => $eventId, + 'categoryIds' => '{' . implode(',', $categoryIds) . '}', + 'categoryOrders' => '{' . implode(',', $categoryOrders) . '}', + ]; + + $categoryUpdateQuery = "WITH new_category_order AS ( SELECT unnest(:categoryIds::bigint[]) AS category_id, unnest(:categoryOrders::int[]) AS order ) @@ -243,7 +275,8 @@ public function bulkUpdateProductsAndCategories(int $eventId, array $productUpda FROM new_category_order WHERE product_categories.id = new_category_order.category_id AND product_categories.event_id = :eventId"; - $this->db->update($categoryUpdateQuery, $categoryParameters); + $this->db->update($categoryUpdateQuery, $categoryParameters); + } $this->db->commit(); } catch (Exception $e) { diff --git a/backend/app/Services/Domain/Event/EventStatsFetchService.php b/backend/app/Services/Domain/Event/EventStatsFetchService.php index 8ec5a714..2c0c6785 100644 --- a/backend/app/Services/Domain/Event/EventStatsFetchService.php +++ b/backend/app/Services/Domain/Event/EventStatsFetchService.php @@ -9,6 +9,7 @@ use HiEvents\Services\Domain\Event\DTO\EventDailyStatsResponseDTO; use Illuminate\Database\DatabaseManager; use Illuminate\Support\Collection; +use Illuminate\Support\Facades\DB; readonly class EventStatsFetchService { @@ -65,8 +66,14 @@ public function getDailyEventStats(EventStatsRequestDTO $requestData): Collectio $startDate = $requestData->start_date; $endDate = $requestData->end_date; - - $query = <<toDateString(); $endDateStr = $endDate->toDateString(); - return << __('Active'), ]; + $createdAtInTimezone = DB::getDriverName() === 'mysql' ? + "CONVERT_TZ(ot.created_at, @@session.time_zone, '+00:00')" + : "ot.created_at AT TIME ZONE 'UTC'"; + $expiryDateInTimezone = DB::getDriverName() === 'mysql' ? + "CONVERT_TZ(pc.expiry_date, @@session.time_zone, '+00:00')" + : "pc.expiry_date AT TIME ZONE 'UTC'"; + $castInteger = DB::getDriverName() === "mysql" ? '' : "::integer"; + return <<= pc.max_allowed_usages THEN '{$translatedStringMap['Limit Reached']}' WHEN pc.deleted_at IS NOT NULL THEN '{$translatedStringMap['Deleted']}' ELSE '{$translatedStringMap['Active']}' - END as status + END as status FROM promo_codes pc LEFT JOIN order_totals ot ON pc.id = ot.promo_code_id WHERE From 5f17ccfc9bbda89f6dadb97ed2f5d5675242122b Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Tue, 29 Apr 2025 13:44:13 +0200 Subject: [PATCH 03/12] cast mysql's tinyint(l) representing bools to actual booleans --- backend/app/Models/Account.php | 8 ++++++++ backend/app/Models/AccountConfiguration.php | 1 + backend/app/Models/AccountUser.php | 7 +++++++ backend/app/Models/EventSetting.php | 10 ++++++++++ backend/app/Models/Product.php | 7 +++++++ backend/app/Models/ProductCategory.php | 7 +++++++ backend/app/Models/ProductPrice.php | 1 + backend/app/Models/Question.php | 2 ++ backend/app/Models/TaxAndFee.php | 2 ++ 9 files changed, 45 insertions(+) diff --git a/backend/app/Models/Account.php b/backend/app/Models/Account.php index 729c3edd..677ee03c 100644 --- a/backend/app/Models/Account.php +++ b/backend/app/Models/Account.php @@ -32,4 +32,12 @@ public function configuration(): BelongsTo foreignKey: 'account_configuration_id', ); } + + protected function getCastMap(): array + { + return [ + 'stripe_connect_setup_complete' => 'boolean', + 'is_manually_verified' => 'boolean', + ]; + } } diff --git a/backend/app/Models/AccountConfiguration.php b/backend/app/Models/AccountConfiguration.php index 73238f82..a4b611ab 100644 --- a/backend/app/Models/AccountConfiguration.php +++ b/backend/app/Models/AccountConfiguration.php @@ -14,6 +14,7 @@ class AccountConfiguration extends BaseModel protected function getCastMap(): array { return [ + 'is_system_default' => 'boolean', 'application_fees' => 'array', ]; } diff --git a/backend/app/Models/AccountUser.php b/backend/app/Models/AccountUser.php index 3441396c..f9e1a5db 100644 --- a/backend/app/Models/AccountUser.php +++ b/backend/app/Models/AccountUser.php @@ -20,4 +20,11 @@ public function user(): BelongsTo { return $this->belongsTo(User::class); } + + protected function getCastMap(): array + { + return [ + 'is_account_owner' => 'boolean', + ]; + } } diff --git a/backend/app/Models/EventSetting.php b/backend/app/Models/EventSetting.php index 98ce2114..725ee9cf 100644 --- a/backend/app/Models/EventSetting.php +++ b/backend/app/Models/EventSetting.php @@ -13,6 +13,16 @@ protected function getCastMap(): array return [ 'location_details' => 'array', 'payment_providers' => 'array', + 'social_media_handles' => 'array', + 'show_share_buttons' => 'boolean', + 'hide_getting_started_page' => 'boolean', + 'is_online_event' => 'boolean', + 'notify_organizer_of_new_orders' => 'boolean', + 'require_attendee_details' => 'boolean', + 'require_billing_address' => 'boolean', + 'allow_orders_awaiting_offline_payment_to_check_in' => 'boolean', + 'enable_invoicing' => 'boolean', + 'allow_search_engine_indexing' => 'boolean', ]; } } diff --git a/backend/app/Models/Product.php b/backend/app/Models/Product.php index e1645fd4..19c5f4de 100644 --- a/backend/app/Models/Product.php +++ b/backend/app/Models/Product.php @@ -19,6 +19,13 @@ protected function getCastMap(): array return [ ProductDomainObjectAbstract::SALES_VOLUME => 'float', ProductDomainObjectAbstract::SALES_TAX_VOLUME => 'float', + ProductDomainObjectAbstract::HIDE_BEFORE_SALE_START_DATE => 'boolean', + ProductDomainObjectAbstract::HIDE_AFTER_SALE_END_DATE => 'boolean', + ProductDomainObjectAbstract::HIDE_WHEN_SOLD_OUT => 'boolean', + ProductDomainObjectAbstract::SHOW_QUANTITY_REMAINING => 'boolean', + ProductDomainObjectAbstract::IS_HIDDEN_WITHOUT_PROMO_CODE => 'boolean', + ProductDomainObjectAbstract::IS_HIDDEN => 'boolean', + ProductDomainObjectAbstract::START_COLLAPSED => 'boolean', ]; } diff --git a/backend/app/Models/ProductCategory.php b/backend/app/Models/ProductCategory.php index e40dc76e..19f30caf 100644 --- a/backend/app/Models/ProductCategory.php +++ b/backend/app/Models/ProductCategory.php @@ -21,6 +21,13 @@ class ProductCategory extends BaseModel 'event_id', ]; + protected function getCastMap(): array + { + return [ + 'is_hidden' => 'boolean', + ]; + } + public function products(): HasMany { return $this->hasMany(Product::class); diff --git a/backend/app/Models/ProductPrice.php b/backend/app/Models/ProductPrice.php index 62d38647..43ed6dd0 100644 --- a/backend/app/Models/ProductPrice.php +++ b/backend/app/Models/ProductPrice.php @@ -13,6 +13,7 @@ protected function getCastMap(): array { return [ 'price' => 'float', + 'is_hidden' => 'boolean', ]; } diff --git a/backend/app/Models/Question.php b/backend/app/Models/Question.php index 4097c7b3..eb5a2cb7 100644 --- a/backend/app/Models/Question.php +++ b/backend/app/Models/Question.php @@ -14,6 +14,8 @@ protected function getCastMap(): array { return [ QuestionDomainObjectAbstract::OPTIONS => 'array', + QuestionDomainObjectAbstract::REQUIRED => 'boolean', + QuestionDomainObjectAbstract::IS_HIDDEN => 'boolean', ]; } diff --git a/backend/app/Models/TaxAndFee.php b/backend/app/Models/TaxAndFee.php index ef29a93c..0393bc97 100644 --- a/backend/app/Models/TaxAndFee.php +++ b/backend/app/Models/TaxAndFee.php @@ -20,6 +20,8 @@ protected function getCastMap(): array { return [ 'rate' => 'float', + 'is_active' => 'boolean', + 'is_default' => 'boolean', ]; } } From 4f23fea310ff241a9551d85c6f046be1afb0645e Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Tue, 29 Apr 2025 17:14:52 +0200 Subject: [PATCH 04/12] fix "You cannot use a named parameter marker of the same name more than once in a prepared statement" --- .../Eloquent/CheckInListRepository.php | 4 +-- .../Repository/Eloquent/ProductRepository.php | 5 ++-- ...AvailableProductQuantitiesFetchService.php | 14 +++++----- .../Domain/Report/AbstractReportService.php | 27 +++++++++++++------ .../Report/Reports/ProductSalesReport.php | 2 +- .../Report/Reports/PromoCodesReport.php | 2 +- 6 files changed, 34 insertions(+), 20 deletions(-) diff --git a/backend/app/Repository/Eloquent/CheckInListRepository.php b/backend/app/Repository/Eloquent/CheckInListRepository.php index 2ea36823..1b063e1a 100644 --- a/backend/app/Repository/Eloquent/CheckInListRepository.php +++ b/backend/app/Repository/Eloquent/CheckInListRepository.php @@ -44,7 +44,7 @@ public function getCheckedInAttendeeCountById(int $checkInListId): CheckedInAtte JOIN event_settings es ON cil.event_id = es.event_id WHERE a.deleted_at IS NULL AND pcil.deleted_at IS NULL - AND pcil.check_in_list_id = :check_in_list_id + AND pcil.check_in_list_id = :check_in_list_id2 AND ( (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')) OR @@ -63,7 +63,7 @@ public function getCheckedInAttendeeCountById(int $checkInListId): CheckedInAtte GROUP BY cil.id; SQL; - $query = $this->db->selectOne($sql, ['check_in_list_id' => $checkInListId]); + $query = $this->db->selectOne($sql, ['check_in_list_id' => $checkInListId, 'check_in_list_id2' => $checkInListId]); return new CheckedInAttendeesCountDTO( checkInListId: $checkInListId, diff --git a/backend/app/Repository/Eloquent/ProductRepository.php b/backend/app/Repository/Eloquent/ProductRepository.php index 22000681..7852ece9 100644 --- a/backend/app/Repository/Eloquent/ProductRepository.php +++ b/backend/app/Repository/Eloquent/ProductRepository.php @@ -73,13 +73,14 @@ public function getQuantityRemainingForProductPrice(int $productId, int $product ) AS quantity_remaining, product_prices.initial_quantity_available IS NULL AS unlimited_products_available FROM product_prices - WHERE product_prices.id = :productPriceId + WHERE product_prices.id = :productPriceId2 AND product_prices.product_id = :productId AND product_prices.deleted_at IS NULL SQL; $result = $this->db->selectOne($query, [ 'productPriceId' => $productPriceId, + 'productPriceId2' => $productPriceId, 'productId' => $productId ]); @@ -91,7 +92,7 @@ public function getQuantityRemainingForProductPrice(int $productId, int $product return Constants::INFINITE; } - return (int)$result->quantity_remaining; + return (int) $result->quantity_remaining; } public function getTaxesByProductId(int $productId): Collection diff --git a/backend/app/Services/Domain/Product/AvailableProductQuantitiesFetchService.php b/backend/app/Services/Domain/Product/AvailableProductQuantitiesFetchService.php index 12e060e2..7bbc2774 100644 --- a/backend/app/Services/Domain/Product/AvailableProductQuantitiesFetchService.php +++ b/backend/app/Services/Domain/Product/AvailableProductQuantitiesFetchService.php @@ -15,16 +15,17 @@ use Illuminate\Contracts\Cache\Repository as Cache; use Illuminate\Database\DatabaseManager; use Illuminate\Support\Collection; +use Illuminate\Support\Facades\DB; +use Illuminate\Support\Facades\Log; class AvailableProductQuantitiesFetchService { public function __construct( - private readonly DatabaseManager $db, - private readonly Config $config, - private readonly Cache $cache, + private readonly DatabaseManager $db, + private readonly Config $config, + private readonly Cache $cache, private readonly CapacityAssignmentRepositoryInterface $capacityAssignmentRepository, - ) - { + ) { } public function getAvailableProductQuantities(int $eventId, bool $ignoreCache = false): AvailableProductQuantitiesResponseDTO @@ -120,12 +121,13 @@ private function fetchReservedProductQuantities(int $eventId): Collection LEFT JOIN reserved_quantities ON products.id = reserved_quantities.product_id AND product_prices.id = reserved_quantities.product_price_id WHERE - products.event_id = :eventId + products.event_id = :eventId2 AND products.deleted_at IS NULL AND product_prices.deleted_at IS NULL GROUP BY products.id, product_prices.id, reserved_quantities.quantity_reserved; SQL, [ 'eventId' => $eventId, + 'eventId2' => $eventId, 'reserved' => OrderStatus::RESERVED->name ]); diff --git a/backend/app/Services/Domain/Report/AbstractReportService.php b/backend/app/Services/Domain/Report/AbstractReportService.php index 24c3058a..edf7f9a5 100644 --- a/backend/app/Services/Domain/Report/AbstractReportService.php +++ b/backend/app/Services/Domain/Report/AbstractReportService.php @@ -11,11 +11,10 @@ abstract class AbstractReportService { public function __construct( - private readonly Repository $cache, - private readonly DatabaseManager $queryBuilder, + private readonly Repository $cache, + private readonly DatabaseManager $queryBuilder, private readonly EventRepositoryInterface $eventRepository, - ) - { + ) { } public function generateReport(int $eventId, ?Carbon $startDate = null, ?Carbon $endDate = null): Collection @@ -26,20 +25,32 @@ public function generateReport(int $eventId, ?Carbon $startDate = null, ?Carbon $endDate = Carbon::parse($endDate ?? now(), $timezone); $startDate = Carbon::parse($startDate ?? $endDate->copy()->subDays(30), $timezone); + $sqlQuery = $this->getSqlQuery($startDate, $endDate); + $reportResults = $this->cache->remember( key: $this->getCacheKey($eventId, $startDate, $endDate), ttl: Carbon::now()->addSeconds(20), callback: fn() => $this->queryBuilder->select( - $this->getSqlQuery($startDate, $endDate), - [ - 'event_id' => $eventId, - ] + $sqlQuery, + $this->repeatParameter($sqlQuery, $eventId), ) ); return collect($reportResults); } + protected function repeatParameter($sqlQuery, $value, $key = 'event_id') + { + $parameterArray = []; + $parameterOccourances = substr_count($sqlQuery, ':' . $key); + + for ($i = 1; $i <= $parameterOccourances; $i++) { + $arrayKey = $i == 1 ? $key : ($key . $i); + $parameterArray[$arrayKey] = $value; + } + return $parameterArray; + } + abstract protected function getSqlQuery(Carbon $startDate, Carbon $endDate): string; protected function getCacheKey(int $eventId, ?Carbon $startDate, ?Carbon $endDate): string diff --git a/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php b/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php index c29feee0..64c1c1e8 100644 --- a/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php +++ b/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php @@ -39,7 +39,7 @@ protected function getSqlQuery(Carbon $startDate, Carbon $endDate): string COALESCE(SUM(fo.quantity), 0) AS number_sold FROM products p LEFT JOIN filtered_orders fo ON fo.product_id = p.id - WHERE p.event_id = :event_id + WHERE p.event_id = :event_id2 AND p.deleted_at IS NULL GROUP BY p.id, p.title, p.type ORDER BY p."order" diff --git a/backend/app/Services/Domain/Report/Reports/PromoCodesReport.php b/backend/app/Services/Domain/Report/Reports/PromoCodesReport.php index c1ab60f3..5df15058 100644 --- a/backend/app/Services/Domain/Report/Reports/PromoCodesReport.php +++ b/backend/app/Services/Domain/Report/Reports/PromoCodesReport.php @@ -87,7 +87,7 @@ protected function getSqlQuery(Carbon $startDate, Carbon $endDate): string LEFT JOIN order_totals ot ON pc.id = ot.promo_code_id WHERE pc.deleted_at IS NULL - AND pc.event_id = :event_id + AND pc.event_id = :event_id2 GROUP BY pc.id, COALESCE(pc.code, ot.promo_code), From 71cd64985a22fd59d752c2ab4b2985ac6b4e3ceb Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Tue, 29 Apr 2025 17:22:27 +0200 Subject: [PATCH 05/12] remove generated collumn because mysql collations are case insesitive --- backend/database/migrations/schema.mysql.sql | 11 +---------- 1 file changed, 1 insertion(+), 10 deletions(-) diff --git a/backend/database/migrations/schema.mysql.sql b/backend/database/migrations/schema.mysql.sql index 2969f412..57a48606 100644 --- a/backend/database/migrations/schema.mysql.sql +++ b/backend/database/migrations/schema.mysql.sql @@ -300,10 +300,6 @@ create index promo_codes_code_index create index promo_codes_event_id_index on promo_codes (event_id); --- TODO: INDEX ON JSON PATH --- create index promo_codes_applicable_ticket_ids_index --- on promo_codes (applicable_ticket_ids); - create table if not exists orders ( id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, @@ -623,12 +619,7 @@ create FULLTEXT index idx_attendees_email_fulltext create FULLTEXT index idx_attendees_public_id_fulltext on attendees (public_id); -ALTER TABLE attendees - ADD COLUMN public_id_lower VARCHAR(255) GENERATED ALWAYS AS (LOWER(public_id)) STORED; - -CREATE INDEX idx_attendees_public_id_lower - ON attendees (public_id_lower); --- TODO: code has to use column public_id_lower instead of public_id when using strtolower +create index idx_attendees_public_id ON attendees (public_id(190)); create table if not exists question_answers ( From 1a434db210b64ee2cf8e6422c53b2b759c54b820 Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Tue, 29 Apr 2025 23:23:58 +0200 Subject: [PATCH 06/12] added datetime casts --- backend/app/Models/Account.php | 1 + backend/app/Models/Attendee.php | 7 +++++++ backend/app/Models/CheckInList.php | 8 ++++++++ backend/app/Models/Order.php | 2 ++ backend/app/Models/OrderApplicationFee.php | 1 + backend/app/Models/Product.php | 2 ++ backend/app/Models/ProductPrice.php | 2 ++ 7 files changed, 23 insertions(+) diff --git a/backend/app/Models/Account.php b/backend/app/Models/Account.php index 677ee03c..b53a7558 100644 --- a/backend/app/Models/Account.php +++ b/backend/app/Models/Account.php @@ -36,6 +36,7 @@ public function configuration(): BelongsTo protected function getCastMap(): array { return [ + 'account_verified_at' => 'datetime', 'stripe_connect_setup_complete' => 'boolean', 'is_manually_verified' => 'boolean', ]; diff --git a/backend/app/Models/Attendee.php b/backend/app/Models/Attendee.php index da77d52d..86480374 100644 --- a/backend/app/Models/Attendee.php +++ b/backend/app/Models/Attendee.php @@ -32,4 +32,11 @@ public function check_in(): HasOne { return $this->hasOne(AttendeeCheckIn::class); } + + public function getCastMap(): array + { + return [ + 'checked_in_at' => 'datetime', + ]; + } } diff --git a/backend/app/Models/CheckInList.php b/backend/app/Models/CheckInList.php index 0004d4bd..b6a024fd 100644 --- a/backend/app/Models/CheckInList.php +++ b/backend/app/Models/CheckInList.php @@ -22,4 +22,12 @@ public function event(): BelongsTo { return $this->belongsTo(Event::class); } + + public function getCastMap(): array + { + return [ + 'expires_at' => 'datetime', + 'activates_at' => 'datetime', + ]; + } } diff --git a/backend/app/Models/Order.php b/backend/app/Models/Order.php index a5dc4e5c..7c398a53 100644 --- a/backend/app/Models/Order.php +++ b/backend/app/Models/Order.php @@ -58,6 +58,8 @@ protected function getCastMap(): array 'point_in_time_data' => 'array', 'address' => 'array', 'taxes_and_fees_rollup' => 'array', + 'is_manually_created' => 'boolean', + 'reserved_until' => 'datetime', ]; } diff --git a/backend/app/Models/OrderApplicationFee.php b/backend/app/Models/OrderApplicationFee.php index aca83e6c..5cdd52a4 100644 --- a/backend/app/Models/OrderApplicationFee.php +++ b/backend/app/Models/OrderApplicationFee.php @@ -13,6 +13,7 @@ protected function getCastMap(): array { return [ 'metadata' => 'array', + 'paid_at' => 'datetime', ]; } diff --git a/backend/app/Models/Product.php b/backend/app/Models/Product.php index 19c5f4de..5e96b1c8 100644 --- a/backend/app/Models/Product.php +++ b/backend/app/Models/Product.php @@ -26,6 +26,8 @@ protected function getCastMap(): array ProductDomainObjectAbstract::IS_HIDDEN_WITHOUT_PROMO_CODE => 'boolean', ProductDomainObjectAbstract::IS_HIDDEN => 'boolean', ProductDomainObjectAbstract::START_COLLAPSED => 'boolean', + ProductDomainObjectAbstract::SALE_START_DATE => 'datetime', + ProductDomainObjectAbstract::SALE_END_DATE => 'datetime', ]; } diff --git a/backend/app/Models/ProductPrice.php b/backend/app/Models/ProductPrice.php index 43ed6dd0..c43797a1 100644 --- a/backend/app/Models/ProductPrice.php +++ b/backend/app/Models/ProductPrice.php @@ -13,6 +13,8 @@ protected function getCastMap(): array { return [ 'price' => 'float', + 'sale_start_date' => 'datetime', + 'sale_end_date' => 'datetime', 'is_hidden' => 'boolean', ]; } From cbfcdf5e388fdb5a41fd03e78f21e91fb387d8f0 Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Fri, 2 May 2025 17:46:58 +0200 Subject: [PATCH 07/12] added missing datetime casts --- backend/app/Models/Message.php | 1 + backend/app/Models/Webhook.php | 1 + 2 files changed, 2 insertions(+) diff --git a/backend/app/Models/Message.php b/backend/app/Models/Message.php index 3680e2a1..97e25d53 100644 --- a/backend/app/Models/Message.php +++ b/backend/app/Models/Message.php @@ -26,6 +26,7 @@ protected function getCastMap(): array 'attendee_ids' => 'array', 'product_ids' => 'array', 'send_data' => 'array', + 'sent_at' => 'datetime', ]; } } diff --git a/backend/app/Models/Webhook.php b/backend/app/Models/Webhook.php index 7d2520b7..2bd068d9 100644 --- a/backend/app/Models/Webhook.php +++ b/backend/app/Models/Webhook.php @@ -14,6 +14,7 @@ protected function getCastMap(): array { return [ 'event_types' => 'array', + 'last_triggered_at' => 'datetime', ]; } From 4c718c02d925307759b7d495fac1903dee849c4e Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Fri, 2 May 2025 17:50:12 +0200 Subject: [PATCH 08/12] replace quotes around table "order" for mysql driver --- backend/app/Repository/Eloquent/QuestionRepository.php | 5 +++-- .../Services/Domain/Report/Reports/ProductSalesReport.php | 5 +++-- 2 files changed, 6 insertions(+), 4 deletions(-) diff --git a/backend/app/Repository/Eloquent/QuestionRepository.php b/backend/app/Repository/Eloquent/QuestionRepository.php index 1e0dcdbb..e421c0a5 100644 --- a/backend/app/Repository/Eloquent/QuestionRepository.php +++ b/backend/app/Repository/Eloquent/QuestionRepository.php @@ -11,6 +11,7 @@ use Illuminate\Database\DatabaseManager; use Illuminate\Foundation\Application; use Illuminate\Support\Collection; +use Illuminate\Support\Facades\DB; class QuestionRepository extends BaseRepository implements QuestionRepositoryInterface { @@ -84,14 +85,14 @@ public function sortQuestions(int $eventId, array $orderedQuestionIds): void 'orders' => '{' . implode(',', range(1, count($orderedQuestionIds))) . '}', ]; - $query = "WITH new_order AS ( + $query = str_replace('"', DB::getDriverName() === 'mysql' ? '`' : "", "WITH new_order AS ( SELECT unnest(:questionIds::bigint[]) AS question_id, unnest(:orders::int[]) AS order ) UPDATE questions SET \"order\" = new_order.order FROM new_order - WHERE questions.id = new_order.question_id AND questions.event_id = :eventId"; + WHERE questions.id = new_order.question_id AND questions.event_id = :eventId"); $this->db->update($query, $parameters); } diff --git a/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php b/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php index 64c1c1e8..225246d1 100644 --- a/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php +++ b/backend/app/Services/Domain/Report/Reports/ProductSalesReport.php @@ -5,6 +5,7 @@ use HiEvents\DomainObjects\Status\OrderStatus; use HiEvents\Services\Domain\Report\AbstractReportService; use Illuminate\Support\Carbon; +use Illuminate\Support\Facades\DB; class ProductSalesReport extends AbstractReportService { @@ -14,7 +15,7 @@ protected function getSqlQuery(Carbon $startDate, Carbon $endDate): string $endDateString = $endDate->format('Y-m-d H:i:s'); $completedStatus = OrderStatus::COMPLETED->name; - return << Date: Fri, 2 May 2025 17:50:55 +0200 Subject: [PATCH 09/12] added missing quotes around date in mysql query --- .../app/Services/Domain/Report/Reports/DailySalesReport.php | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/backend/app/Services/Domain/Report/Reports/DailySalesReport.php b/backend/app/Services/Domain/Report/Reports/DailySalesReport.php index 0e5d2cf8..29fff537 100644 --- a/backend/app/Services/Domain/Report/Reports/DailySalesReport.php +++ b/backend/app/Services/Domain/Report/Reports/DailySalesReport.php @@ -14,11 +14,11 @@ public function getSqlQuery(Carbon $startDate, Carbon $endDate): string $endDateStr = $endDate->toDateString(); $withDateRange = DB::getDriverName() === 'mysql' ? "WITH RECURSIVE date_range AS ( - SELECT DATE($startDateStr) AS date + SELECT DATE('$startDateStr') AS date UNION ALL SELECT DATE_ADD(date, INTERVAL 1 DAY) FROM date_range - WHERE date < DATE($endDateStr) + WHERE date < DATE('$endDateStr') )" : "WITH date_range AS ( SELECT generate_series('$startDateStr'::date, '$endDateStr'::date, '1 day'::interval) AS date )"; From 1f4e8fec843f852a2d43264f9c904d3feec01765 Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Fri, 2 May 2025 17:51:45 +0200 Subject: [PATCH 10/12] fix "You cannot use a named parameter marker of the same name more than once in a prepared statement" --- backend/app/Repository/Eloquent/CheckInListRepository.php | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/backend/app/Repository/Eloquent/CheckInListRepository.php b/backend/app/Repository/Eloquent/CheckInListRepository.php index 1b063e1a..fe42337e 100644 --- a/backend/app/Repository/Eloquent/CheckInListRepository.php +++ b/backend/app/Repository/Eloquent/CheckInListRepository.php @@ -58,12 +58,12 @@ public function getCheckedInAttendeeCountById(int $checkInListId): CheckedInAtte FROM check_in_lists cil LEFT JOIN valid_attendees va ON va.check_in_list_id = cil.id LEFT JOIN valid_check_ins vci ON vci.attendee_id = va.id - WHERE cil.id = :check_in_list_id + WHERE cil.id = :check_in_list_id3 AND cil.deleted_at IS NULL GROUP BY cil.id; SQL; - $query = $this->db->selectOne($sql, ['check_in_list_id' => $checkInListId, 'check_in_list_id2' => $checkInListId]); + $query = $this->db->selectOne($sql, ['check_in_list_id' => $checkInListId, 'check_in_list_id2' => $checkInListId, 'check_in_list_id3' => $checkInListId]); return new CheckedInAttendeesCountDTO( checkInListId: $checkInListId, From a04af30a61e21ee991182db45027e2eb7060ee74 Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Sun, 4 May 2025 18:14:23 +0200 Subject: [PATCH 11/12] fix spelling error tax to taxes and procut to product --- .../2024_09_20_032323_rename_tickets_to_products.php | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php b/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php index 5d90dd92..37d10f3e 100644 --- a/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php +++ b/backend/database/migrations/2024_09_20_032323_rename_tickets_to_products.php @@ -84,7 +84,7 @@ public function up(): void $this->renameIndex('order_items', 'order_items_ticket_id_index', 'order_items_product_id_index'); $this->renameIndex('order_items', 'order_items_ticket_price_id_index', 'order_items_product_price_id_index'); $this->renameIndex('attendees', 'idx_attendees_ticket_id_deleted_at', 'idx_attendees_product_id_deleted_at'); - $this->renameIndex('procut_tax_and_fees', 'ticket_tax_and_fees_ticket_id_index', 'product_tax_and_fees_product_id_index'); + $this->renameIndex('product_taxes_and_fees', 'ticket_tax_and_fees_ticket_id_index', 'product_tax_and_fees_product_id_index'); $this->renameIndex('product_questions', 'idx_ticket_questions_active', 'idx_product_questions_active'); $this->renameIndex('product_check_in_lists', 'ticket_check_in_lists_ticket_id_check_in_list_id_index', 'product_check_in_lists_product_id_check_in_list_id_index'); $this->renameIndex('product_check_in_lists', 'idx_ticket_check_in_lists_ticket_id_deleted_at', 'idx_product_check_in_lists_product_id_deleted_at'); @@ -171,7 +171,7 @@ public function down(): void $this->renameIndex('order_items', 'order_items_product_id_index', 'order_items_ticket_id_index'); $this->renameIndex('order_items', 'order_items_product_price_id_index', 'order_items_ticket_price_id_index'); $this->renameIndex('attendees', 'idx_attendees_product_id_deleted_at', 'idx_attendees_ticket_id_deleted_at'); - $this->renameIndex('ticket_tax_tax_and_fees', 'product_tax_and_fees_product_id_index', 'ticket_tax_and_fees_ticket_id_index'); + $this->renameIndex('ticket_taxes_and_fees', 'product_tax_and_fees_product_id_index', 'ticket_tax_and_fees_ticket_id_index'); $this->renameIndex('ticket_questions', 'idx_product_questions_active', 'idx_ticket_questions_active'); $this->renameIndex('ticket_check_in_lists', 'product_check_in_lists_product_id_check_in_list_id_index', 'ticket_check_in_lists_ticket_id_check_in_list_id_index'); $this->renameIndex('ticket_check_in_lists', 'idx_product_check_in_lists_product_id_deleted_at', 'idx_ticket_check_in_lists_ticket_id_deleted_at'); From 09d41a79e841690417ab9da07b837eb51ad342a4 Mon Sep 17 00:00:00 2001 From: Stonebubble Date: Thu, 8 May 2025 18:49:00 +0200 Subject: [PATCH 12/12] added "or replace" to view for repeating migrations while running tests --- backend/database/migrations/schema.mysql.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/backend/database/migrations/schema.mysql.sql b/backend/database/migrations/schema.mysql.sql index 57a48606..49cd9ac4 100644 --- a/backend/database/migrations/schema.mysql.sql +++ b/backend/database/migrations/schema.mysql.sql @@ -750,7 +750,7 @@ create index idx_account_users_user_id create index idx_account_users_role on account_users (role); -create view question_and_answer_views +create or replace view question_and_answer_views (question_id, event_id, belongs_to, question_type, first_name, last_name, attendee_id, order_id, title, answer, question_answer_id) as