Skip to content

Feature/upsert #224

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

Open
wants to merge 4 commits into
base: 2.x
Choose a base branch
from
Open

Conversation

puzzledpolymath
Copy link

@puzzledpolymath puzzledpolymath commented Jun 14, 2025

This pull request adds support for performing upsert queries. Ticket #50 is what sparked interest for this feature.

🔍 What was changed

  • Each driver (MySQL, Postgres, SQLite and SQLServer) compiler supports an UpsertQuery.
  • Differences between SQL dialects have been accounted for.

🤔 Why?

  1. Upsert allows developers to combine insert and update operations into a single command, reducing the need for explicit existence checks and multiple database calls.
  2. Modern databases support atomic upsert operations, which help maintain data integrity even in concurrent environments.
  3. Upsert reduces the number of database round-trips, eliminating separate existence checks followed by insert or update, likely leading to better performance, especially in high-volume scenarios.

📝 Checklist

📃 Documentation

Note that specifying conflict index column names is redundant and not required for MySQL.

PHP

$upsert = $this->database->upsert('users')
    ->conflicts('email')
    ->columns('email', 'name')
    ->values('[email protected]', 'Adam')
    ->values('[email protected]', 'Bill');
$upsert = $this->database->upsert('users')
    ->conflicts(['email'])
    ->values([
        ['email' => '[email protected]', 'name' => 'Adam'],
        ['email' => '[email protected]', 'name' => 'Bill'],
    ]);

MyQL

INSERT INTO `users` (`email`, `name`)
VALUES
    ('[email protected]', 'Adam'),
    ('[email protected]', 'Bill')
ON DUPLICATE KEY UPDATE
    `email` = VALUES(`email`),
    `name` = VALUES(`name`);

Postgres / SQLite

INSERT INTO `users` (`email`, `name`)
VALUES
    ('[email protected]', 'Adam'),
    ('[email protected]', 'Bill')
ON CONFLICT (`email`) DO UPDATE SET
    `email` = EXCLUDED.`email`,
    `name` = EXCLUDED.`name`

MSSQL

MERGE INTO [users] WITH (holdlock) AS [target] 
USING ( VALUES 
    ('[email protected]', 'Adam'),
    ('[email protected]', 'Bill') 
) AS [source] ([email], [name]) 
ON [target].[email] = [source].[email] 
WHEN MATCHED THEN 
    UPDATE SET 
        [target].[email] = [source].[email], 
        [target].[name] = [source].[name] 
WHEN NOT MATCHED THEN 
    INSERT ([email], [name]) 
    VALUES ([source].[email], [source].[name])

@puzzledpolymath puzzledpolymath requested review from a team as code owners June 14, 2025 10:45
@puzzledpolymath
Copy link
Author

One thing I'm uncertain about or dislike at the moment, is the need to specify conflicting index column names for non MySQL drivers.

While likely not an appropriate location for such logic, perhaps something like below could work. E.g. gather info from the schema to determine unique indexes and their columns.

class UpsertQuery extends ActiveQuery
{
    public function getTokens(): array
    {
        $conflicts = $this->conflicts;

        if ($conflicts === [] && $this->driver) {
            $schema = $this->driver->getSchemaHandler()->getSchema($this->table);
            foreach ($schema->getIndexes() as $index) {
                if ($index->isUnique()) {
                    $conflicts = $conflicts + $index->getColumns();
                }
            }
            $conflicts = array_unique($conflicts);
        }

        return [
            'table'     => $this->table,
            'columns'   => $this->columns,
            'values'    => $this->values,
            'conflicts' => $conflicts,
        ];
    }
}

@puzzledpolymath
Copy link
Author

@roxblnfk is there anything needed from me to get past that labeler error?

Warning: The action requires write permission to add labels to pull requests. For more information please refer to the action documentation: https://github.com/actions/labeler#permissions
Error: Resource not accessible by integration

@roxblnfk
Copy link
Member

@roxblnfk is there anything needed from me to get past that labeler error?

No, don't worry about it.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

💡 Add support for MySQL: ON DUPLICATE KEY UPDATE, PostgreSQL: ON CONFLICT
2 participants