Skip to content

Commit

Permalink
Fluent: add MERGE
Browse files Browse the repository at this point in the history
  • Loading branch information
forrest79 committed Jan 16, 2024
1 parent b975de8 commit 17aff3f
Show file tree
Hide file tree
Showing 12 changed files with 551 additions and 156 deletions.
153 changes: 151 additions & 2 deletions docs/fluent.md
Original file line number Diff line number Diff line change
Expand Up @@ -92,7 +92,7 @@ Every query is `SELECT` at first, until you call `->insert(...)`, `->update(...)
- `whereAnd(array $conditions = []): Complex` (or `whereOr(...)` / `havingAnd(...)` / `havingOr()`) - with these methods, you can generate condition groups. Ale provided conditions are connected with logic `AND` for `whereAnd()` and `havingAnd()` and with logic `OR` for `whereOr()` and `havingOr()`. All these methods return `Complex` object (more about this later). `$conditions` items can be simple `string`, another `array` (this is a little bit magic - this works as `where()`/`having()` method - first item in this `array` is conditions and next items are parameters), `Complex` or `Db\Sql`.


- `groupBy(string ...$columns)`: - generates `GROUP BY` statement, one or more `string` parameters must be provided.
- `groupBy(string ...$columns)` - generates `GROUP BY` statement, one or more `string` parameters must be provided.


- `orderBy(...$columns): Query` - generates `ORDER BY` statement, one or more parameters must be provided. Parameter can be simple `string`, another `Query` or `Db\Sql`.
Expand All @@ -116,7 +116,7 @@ Every query is `SELECT` at first, until you call `->insert(...)`, `->update(...)
- `rows(array $rows)` - this method can be used to insert multiple rows in one query. `$rows` is an `array` of arrays. Each array is one row (the same as for the `values()` method). All rows must have the same columns. Method can be called multiple and all rows are merged.


- `update(?string $table = NULL, ?string $alias = NULL)`: — set query for update. If the main table is not set, you must set it or rewrite with the `$table` parameter. `$alias` can be provided, when you want to use `UPDATE ... FROM ...`.
- `update(?string $table = NULL, ?string $alias = NULL)` - set query for update. If the main table is not set, you must set it or rewrite with the `$table` parameter. `$alias` can be provided, when you want to use `UPDATE ... FROM ...`.


- `set(array $data)` - sets data to update. Rules for the data are the same as for the `values()` method.
Expand All @@ -128,6 +128,18 @@ Every query is `SELECT` at first, until you call `->insert(...)`, `->update(...)
- `returning(array $returning)` - generates `RETURNING` statement for `INSERT`, `UPDATE` or `DELETE`. Syntax for `$returning` is the same as for the `select()` method.


- `merge(?string $into = NULL, ?string $alias = NULL)` - set query for merge. If the main table is not set, you must set it or rewrite with the `$into` parameter. `$alias` can be provided.


- `using($dataSource, ?string $alias = NULL, $onCondition = NULL)` - set a data source for a merge command. `$dataSource` can be simple string, `Db\Sql\Query` or `Fluent\Query`. `$onCondition` can be simple `string` or other `Complex` or `Db\Sql`. `Db\Sql` can be used for some complex expression, where you need to use `?` and parameters. On condition can be added or extended with the `on()` method.


- `whenMatched($then, $onCondition = NULL)` - add matched branch to a merge command. `$then` is simple string or `Db\Sql` and `$onCondition` can be simple `string` or other `Complex` or `Db\Sql`. `Db\Sql` can be used for some complex expression, where you need to use `?` and parameters.


- `whenNotMatched($then, $onCondition = NULL)` - add not matched branch to a merge command. `$then` is simple string or `Db\Sql` and `$onCondition` can be simple `string` or other `Complex` or `Db\Sql`. `Db\Sql` can be used for some complex expression, where you need to use `?` and parameters.


- `truncate(?string $table = NULL)` - truncates table. If the main table is not set, you must provide/rewrite it with the `$table` parameter.


Expand Down Expand Up @@ -422,6 +434,143 @@ $deleteRows = $connection
dump($deleteRows); // (integer) 1
```

### Merge

Oficial docs: https://www.postgresql.org/docs/current/sql-merge.html

`MERGE` command was added in the PostgreSQL v15. You can use it to conditionally insert, update, or delete rows of a table.

Simple use can look like:

```php
$query = $connection
->merge('customer_account', 'ca')
->using('recent_transactions', 't', 't.customer_id = ca.customer_id')
->whenMatched('UPDATE SET balance = balance + transaction_value')
->whenNotMatched('INSERT (customer_id, balance) VALUES (t.customer_id, t.transaction_value)');

dump($query); // (Query) MERGE INTO customer_account AS ca USING recent_transactions AS t ON t.customer_id = ca.customer_id WHEN MATCHED THEN UPDATE SET balance = balance + transaction_value WHEN NOT MATCHED THEN INSERT (customer_id, balance) VALUES (t.customer_id, t.transaction_value)
```

The `ON` condition can be used with the `on()` method:

```php
$query = $connection
->merge('customer_account', 'ca')
->using('recent_transactions', 't')
->on('t', 't.customer_id = ca.customer_id')
->whenMatched('UPDATE SET balance = balance + transaction_value')
->whenNotMatched('INSERT (customer_id, balance) VALUES (t.customer_id, t.transaction_value)');

dump($query); // (Query) MERGE INTO customer_account AS ca USING recent_transactions AS t ON t.customer_id = ca.customer_id WHEN MATCHED THEN UPDATE SET balance = balance + transaction_value WHEN NOT MATCHED THEN INSERT (customer_id, balance) VALUES (t.customer_id, t.transaction_value)
```

The `WHEN (NOT) MATCHED` branches can have conditions:

```php
$query = $connection
->merge('wines', 'w')
->using('wine_stock_changes', 's', 's.winename = w.winename')
->whenNotMatched('INSERT VALUES(s.winename, s.stock_delta)', 's.stock_delta > 0')
->whenMatched('UPDATE SET stock = w.stock + s.stock_delta', Forrest79\PhPgSql\Fluent\Complex::createAnd()->add('w.stock + s.stock_delta > ?', 0))
->whenMatched('DELETE');

dump($query); // (Query) MERGE INTO wines AS w USING wine_stock_changes AS s ON s.winename = w.winename WHEN NOT MATCHED AND s.stock_delta > 0 THEN INSERT VALUES(s.winename, s.stock_delta) WHEN MATCHED AND w.stock + s.stock_delta > $1 THEN UPDATE SET stock = w.stock + s.stock_delta WHEN MATCHED THEN DELETE [Params: (array) [0]]
```

@todo DO NOTHING

#### Upsert

The `MERGE` command can be used for simply upsert (perform UPDATE and if recond not exists yet perform INSERT). The query could look like this:

```sql
MERGE INTO users AS u
USING (VALUES ('Bob', FALSE)) AS source (nick, active) ON u.nick = source.nick
WHEN MATCHED THEN
UPDATE SET active = source.active
WHEN NOT MATCHED THEN
INSERT (nick, active) VALUES (source.nick, source.active);
```

Unfortunately, this can't be used simply with the parameters:

```sql
MERGE INTO users AS u
USING (VALUES (?, ?)) AS source (nick, active) ON u.nick = source.nick
WHEN MATCHED THEN
UPDATE SET active = source.active
WHEN NOT MATCHED THEN
INSERT (nick, active) VALUES (source.nick, source.active);
```

Because DB needs to know the parameter types and all parameters are treated as text. You must use a concrete cast like this:

```sql
MERGE INTO users AS u
USING (VALUES (?, ?::boolean)) AS source (nick, active) ON u.nick = source.nick
WHEN MATCHED THEN
UPDATE SET active = source.active
WHEN NOT MATCHED THEN
INSERT (nick, active) VALUES (source.nick, source.active);
```

For a query like this, it's not a problem. But when you want to prepare a common method for more tables and parameters, you must use a little trick.

```sql
MERGE INTO users AS u
USING (SELECT 1) AS x ON u.nick = $1
WHEN MATCHED THEN
UPDATE SET active = $2
WHEN NOT MATCHED THEN
INSERT (nick, active) VALUES ($1, $2);
```
And this is how this could be prepared with the fluent interface:

```php
$updateRow = $connection
->merge('users', 'u')
->using('(SELECT 1)', 'x', 'u.nick = $1')
->whenMatched('UPDATE SET active = $2')
->whenNotMatched(Forrest79\PhPgSql\Db\Sql\Expression::create('INSERT (nick, active) VALUES ($1, $2)', 'Bob', 'f'))
->getAffectedRows();

dump($updateRow); // (integer) 1

$updatedRows = $connection->query('SELECT nick, active FROM users WHERE nick = ?', 'Bob')->fetchAll();

table($updatedRows);
/**
---------------------------------
| nick | active |
|===============================|
| (string) 'Bob' | (bool) FALSE |
---------------------------------
*/

$insertRow = $connection
->merge('users', 'u')
->using('(SELECT 1)', 'x', 'u.nick = $1')
->whenMatched('UPDATE SET active = $2')
->whenNotMatched(Forrest79\PhPgSql\Db\Sql\Expression::create('INSERT (nick, active) VALUES ($1, $2)', 'Margaret', 't'))
->getAffectedRows();

dump($updateRow); // (integer) 1

$insertedRows = $connection->query('SELECT nick, active FROM users WHERE nick = ?', 'Margaret')->fetchAll();

table($insertedRows);
/**
-------------------------------------
| nick | active |
|===================================|
| (string) 'Margaret' | (bool) TRUE |
-------------------------------------
*/
```

> IMPORTANT: with this trick, when `$1`, `$2`, ... is used instead of `?`, `?`, ... we must use bool parameters as `t` and `f`. Automatic bool parameters replacing remove `?` from the query and bool parameter from the parameter list and put string `'TRUE'` or `'FALSE'` right into the query. When `$1` is used, bool parameter is still removed from the list, but the query is untouched, so there will be fewer parameters than `$1`, `$2`, ... in the query.
### Truncate

Just with table name:
Expand Down
4 changes: 4 additions & 0 deletions phpcs.xml
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,10 @@
<exclude-pattern>src/Fluent/QueryBuilder.php</exclude-pattern>
</rule>

<rule ref="SlevomatCodingStandard.Classes.ClassConstantVisibility.MissingConstantVisibility">
<exclude-pattern>src/Fluent/Sql.php</exclude-pattern>
</rule>

<rule ref="SlevomatCodingStandard.Classes.ModernClassNameReference.ClassNameReferencedViaFunctionCall">
<exclude-pattern>src/Fluent/Exceptions/ComplexException.php</exclude-pattern>
<exclude-pattern>tests/Integration/DocsTest.php</exclude-pattern>
Expand Down
2 changes: 1 addition & 1 deletion phpstan.neon
Original file line number Diff line number Diff line change
Expand Up @@ -156,7 +156,7 @@ parameters:
# === PHPStan imperfection ===

-
message: "#^Property Forrest79\\\\PhPgSql\\\\Fluent\\\\Query::\\$params \\(array\\{select: array\\<int\\|string, BackedEnum\\|Forrest79\\\\PhPgSql\\\\Db\\\\Sql\\|Forrest79\\\\PhPgSql\\\\Fluent\\\\Query\\|int\\|string\\>, distinct: bool, tables: array\\<string, array\\{string, string\\}\\>, table\\-types: array\\{main: string\\|null, from: list\\<string\\>, joins: list\\<string\\>\\}, join\\-conditions: array\\<string, Forrest79\\\\PhPgSql\\\\Fluent\\\\Complex\\>, lateral\\-tables: array\\<string, string\\>, where: Forrest79\\\\PhPgSql\\\\Fluent\\\\Complex\\|null, groupBy: array\\<string\\>, \\.\\.\\.\\}\\) does not accept .+\\.$#"
message: "#^Property Forrest79\\\\PhPgSql\\\\Fluent\\\\Query::\\$params \\(array\\{select: array\\<int\\|string, BackedEnum\\|Forrest79\\\\PhPgSql\\\\Db\\\\Sql\\|Forrest79\\\\PhPgSql\\\\Fluent\\\\Query\\|int\\|string\\>, distinct: bool, tables: array\\<string, array\\{string, string\\}\\>, table\\-types: array\\{main: string\\|null, from: list\\<string\\>, joins: list\\<string\\>, using: string\\|null\\}, on\\-conditions: array\\<string, Forrest79\\\\PhPgSql\\\\Fluent\\\\Complex\\>, lateral\\-tables: array\\<string, string\\>, where: Forrest79\\\\PhPgSql\\\\Fluent\\\\Complex\\|null, groupBy: array\\<string\\>, \\.\\.\\.\\}\\) does not accept .+\\.$#"
path: src/Fluent/Query.php
count: 5

Expand Down
28 changes: 15 additions & 13 deletions src/Fluent/Connection.php
Original file line number Diff line number Diff line change
Expand Up @@ -393,57 +393,59 @@ public function delete(?string $from = NULL, ?string $alias = NULL): Query


/**
* @param array<int|string, string|int|Query|Db\Sql> $returning
* @return QueryExecute
* @throws Exceptions\QueryException
*/
public function merge(?string $into = NULL, ?string $alias = NULL): Query
public function returning(array $returning): Query
{
return $this->createQuery()->merge($into, $alias);
return $this->createQuery()->returning($returning);
}


/**
* @param string|Query|Db\Sql $dataSource values, table or query
* @param string|Complex|Db\Sql|NULL $onCondition
* @return QueryExecute
* @throws Exceptions\QueryException
*/
public function using($dataSource, ?string $alias = NULL, $onCondition = NULL): Query
public function merge(?string $into = NULL, ?string $alias = NULL): Query
{
return $this->createQuery()->using($dataSource, $alias, $onCondition);
return $this->createQuery()->merge($into, $alias);
}


/**
* @param string|Query|Db\Sql $dataSource values, table or query
* @param string|Complex|Db\Sql|NULL $onCondition
* @return QueryExecute
* @throws Exceptions\QueryException
*/
public function whenMatched(string $then, $onCondition = NULL): Query
public function using($dataSource, ?string $alias = NULL, $onCondition = NULL): Query
{
return $this->createQuery()->whenMatched($then, $onCondition);
return $this->createQuery()->using($dataSource, $alias, $onCondition);
}


/**
* @param string|Db\Sql $then
* @param string|Complex|Db\Sql|NULL $onCondition
* @return QueryExecute
* @throws Exceptions\QueryException
*/
public function whenNotMatched(string $then, $onCondition = NULL): Query
public function whenMatched($then, $onCondition = NULL): Query
{
return $this->createQuery()->whenNotMatched($then, $onCondition);
return $this->createQuery()->whenMatched($then, $onCondition);
}


/**
* @param array<int|string, string|int|Query|Db\Sql> $returning
* @param string|Db\Sql $then
* @param string|Complex|Db\Sql|NULL $onCondition
* @return QueryExecute
* @throws Exceptions\QueryException
*/
public function returning(array $returning): Query
public function whenNotMatched($then, $onCondition = NULL): Query
{
return $this->createQuery()->returning($returning);
return $this->createQuery()->whenNotMatched($then, $onCondition);
}


Expand Down
34 changes: 19 additions & 15 deletions src/Fluent/Exceptions/QueryBuilderException.php
Original file line number Diff line number Diff line change
Expand Up @@ -6,15 +6,16 @@ class QueryBuilderException extends Exception
{
public const BAD_QUERY_TYPE = 1;
public const NO_COLUMNS_TO_SELECT = 2;
public const NO_JOIN_CONDITIONS = 3;
public const NO_ON_CONDITION = 3;
public const NO_DATA_TO_INSERT = 4;
public const NO_DATA_TO_UPDATE = 5;
public const DATA_CANT_CONTAIN_ARRAY = 6;
public const NO_MAIN_TABLE = 7;
public const BAD_PARAMS_COUNT = 8;
public const BAD_PARAM = 9;
public const NO_CORRESPONDING_TABLE = 10;
public const SELECT_ALL_COLUMNS_CANT_BE_COMBINED_WITH_CONCRETE_COLUMN_FOR_INSERT_SELECT_WITH_COLUMN_DETECTION = 11;
public const NO_CORRESPONDING_TABLE = 9;
public const SELECT_ALL_COLUMNS_CANT_BE_COMBINED_WITH_CONCRETE_COLUMN_FOR_INSERT_SELECT_WITH_COLUMN_DETECTION = 10;
public const NO_USING = 11;
public const NO_WHEN = 12;


public static function badQueryType(string $type): self
Expand All @@ -29,9 +30,9 @@ public static function noColumnsToSelect(): self
}


public static function noJoinConditions(string $alias): self
public static function noOnCondition(string $alias): self
{
return new self(\sprintf('No join conditions for table alias \'%s\'.', $alias), self::NO_JOIN_CONDITIONS);
return new self(\sprintf('There is no conditions for ON for table alias \'%s\'.', $alias), self::NO_ON_CONDITION);
}


Expand Down Expand Up @@ -65,15 +66,6 @@ public static function badParamsCount(string $condition, int $expected, int $act
}


/**
* @param array<string> $validValues
*/
public static function badParam(string $param, string $value, array $validValues): self
{
return new self(\sprintf('Bad param \'%s\' with value \'%s\'. Valid values are \'%s\'.', $param, $value, \implode('\', \'', $validValues)), self::BAD_PARAM);
}


/**
* @param array<string> $aliases
*/
Expand All @@ -88,4 +80,16 @@ public static function selectAllColumnsCantBeCombinedWithConcreteColumnForInsert
return new self('You can\'t use \'SELECT *\' and also some concrete column for INSERT - SELECT with column detection.', self::SELECT_ALL_COLUMNS_CANT_BE_COMBINED_WITH_CONCRETE_COLUMN_FOR_INSERT_SELECT_WITH_COLUMN_DETECTION);
}


public static function noUsing(): self
{
return new self('No USING for MERGE.', self::NO_USING);
}


public static function noWhen(): self
{
return new self('No WHEN for MERGE.', self::NO_WHEN);
}

}
7 changes: 7 additions & 0 deletions src/Fluent/Exceptions/QueryException.php
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ class QueryException extends Exception
public const PARAM_MUST_BE_SCALAR_OR_ENUM_OR_EXPRESSION = 5;
public const CANT_UPDATE_QUERY_AFTER_EXECUTE = 6;
public const YOU_MUST_EXECUTE_QUERY_BEFORE_THAT = 7;
public const ONLY_ONE_USING = 8;


public static function onlyOneMainTable(): self
Expand Down Expand Up @@ -57,4 +58,10 @@ public static function youMustExecuteQueryBeforeThat(): self
return new self('You must execute query before that', self::YOU_MUST_EXECUTE_QUERY_BEFORE_THAT);
}


public static function onlyOneUsing(): self
{
return new self('USING can be set only once.', self::ONLY_ONE_USING);
}

}
Loading

0 comments on commit 17aff3f

Please sign in to comment.