- Add DISCOVERY_LOG_LEVEL=debug - Add DISCOVERY_SHOW_PROGRESS=true - Temporary changes for debugging InitializerProcessor fixes on production
79 lines
3.6 KiB
Markdown
79 lines
3.6 KiB
Markdown
# Database Migration Fix: Column Existence Check
|
|
|
|
## Issue Description
|
|
|
|
When running migrations, particularly the `AddSizeToImageVariantsTable` migration, the following error occurred:
|
|
|
|
```
|
|
Running migrations...
|
|
Migrating: AddSizeToImageVariantsTable - Add Size to Image Slot Table
|
|
❌ Migration failed: Migration AddSizeToImageVariantsTable failed: Failed to execute query: SQLSTATE[42000]: Syntax error or access violation: 1064 You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near '?' at line 1 --- SQL: SHOW COLUMNS FROM image_variants LIKE ? PARAMETERS: {size}
|
|
```
|
|
|
|
## Root Cause
|
|
|
|
The issue was in the `hasColumn` method of the `Schema` class. When checking if a column exists in a MySQL/MariaDB database, the code was using a parameterized query with a placeholder (`?`) in the `LIKE` clause:
|
|
|
|
```php
|
|
'mysql' => "SHOW COLUMNS FROM {$table} LIKE ?",
|
|
```
|
|
|
|
However, MariaDB doesn't support parameter binding for the `LIKE` clause in this context. The placeholder `?` was being passed directly to the SQL statement instead of being replaced with the actual value.
|
|
|
|
## Solution
|
|
|
|
The solution was to modify the `hasColumn` method to use a different query for MySQL/MariaDB that properly supports parameter binding:
|
|
|
|
```php
|
|
public function hasColumn(string $table, string $column): bool
|
|
{
|
|
$driver = $this->getDriverName();
|
|
|
|
$query = match($driver) {
|
|
'mysql' => "SELECT COUNT(*) FROM information_schema.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = ? AND COLUMN_NAME = ?",
|
|
'pgsql' => "SELECT column_name FROM information_schema.columns WHERE table_name = ? AND column_name = ?",
|
|
'sqlite' => "PRAGMA table_info({$table})",
|
|
default => throw new \RuntimeException("Unsupported driver: {$driver}")
|
|
};
|
|
|
|
if ($driver === 'pgsql') {
|
|
$result = $this->connection->queryScalar($query, [$table, $column]);
|
|
} elseif ($driver === 'sqlite') {
|
|
$columns = $this->connection->query($query)->fetchAll();
|
|
foreach ($columns as $col) {
|
|
if ($col['name'] === $column) {
|
|
return true;
|
|
}
|
|
}
|
|
return false;
|
|
} elseif ($driver === 'mysql') {
|
|
$result = $this->connection->queryScalar($query, [$table, $column]);
|
|
} else {
|
|
throw new \RuntimeException("Unsupported driver: {$driver}");
|
|
}
|
|
|
|
return (bool) $result;
|
|
}
|
|
```
|
|
|
|
Key changes:
|
|
1. Changed the MySQL query to use `information_schema.COLUMNS` with proper parameter binding
|
|
2. Updated the parameter handling for MySQL to pass both table and column parameters
|
|
3. Added an explicit condition for the MySQL driver to handle the parameters correctly
|
|
|
|
## Benefits
|
|
|
|
This change:
|
|
1. Fixes the SQL syntax error when checking if a column exists
|
|
2. Makes the code more robust by using parameterized queries throughout
|
|
3. Provides better protection against SQL injection
|
|
4. Makes the migrations idempotent (can be run multiple times without error)
|
|
|
|
## Future Considerations
|
|
|
|
For all database operations, especially in schema manipulation:
|
|
1. Always use parameterized queries when possible
|
|
2. Test database operations with different database engines
|
|
3. Consider adding more comprehensive error handling in database schema operations
|
|
4. Add unit tests for database schema operations to catch these issues earlier
|