Skip to content
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

Add orderByPriority Method for Custom Sorting in Query Builder V2 #52535

Draft
wants to merge 10 commits into
base: 11.x
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
33 changes: 33 additions & 0 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -2614,6 +2614,39 @@ public function orderBy($column, $direction = 'asc')
return $this;
}

/**
* Apply custom ordering to a query based on a priority array.
*
* @param string $column
* @param array $priority
* @param string $direction
* @return $this
*
* @throws \InvalidArgumentException
*/
public function orderByPriority($column, array $priority, $direction = 'asc')
{
$direction = strtolower($direction);

if (! in_array($direction, ['asc', 'desc'], true)) {
throw new InvalidArgumentException('Order direction must be "asc" or "desc".');
}

if (count($priority) === 0) {
throw new InvalidArgumentException('Order priority array must not be empty.');
}

$grammar = $this->getGrammar();

if (! method_exists($grammar, 'orderByPriority')) {
throw new RuntimeException('The "orderByPriority" function is not supported by this database.');
}

$this->orderByRaw($grammar->orderByPriority($column, $priority, $direction), $priority);

return $this;
}

/**
* Add a descending "order by" clause to the query.
*
Expand Down
15 changes: 15 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MariaDbGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -53,4 +53,19 @@ public function useLegacyGroupLimit(Builder $query)
{
return false;
}

/**
* Apply custom ordering to a query based on a priority array.
*
* @param $column
* @param array $priority
* @param $direction
* @return string
*/
public function orderByPriority($column, array $priority, $direction = 'asc')
Copy link
Contributor

@staudenmeir staudenmeir Aug 20, 2024

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

You can remove this implementation: MariaDbGrammar extends MySqlGrammar and inherits the method from there.

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Correct. I have removed the code from MariaDbGrammar.

{
$placeholders = implode(',', array_fill(0, count($priority), '?'));

return "FIELD($column, $placeholders) $direction";
}
}
15 changes: 15 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -524,4 +524,19 @@ protected function wrapJsonBooleanSelector($value)

return 'json_extract('.$field.$path.')';
}

/**
* Apply custom ordering to a query based on a priority array.
*
* @param $column
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The grammars are missing the parameter types for $column and $direction.

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I have updated the code to add the type for column and direction

* @param array $priority
* @param $direction
* @return string
*/
public function orderByPriority($column, array $priority, $direction = 'asc')
{
$placeholders = implode(',', array_fill(0, count($priority), '?'));

return "FIELD($column, $placeholders) $direction";
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The column name needs to be wrapped with $this->wrap($column). This also affects the other grammars.

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I have applied the wrap function on all grammars and updated the tests accordingly.

}
}
21 changes: 21 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -772,4 +772,25 @@ public function substituteBindingsIntoRawSql($sql, $bindings)

return $query;
}

/**
* Apply custom ordering to a query based on a priority array.
*
* @param $column
* @param array $priority
* @param $direction
* @return string
*/
public function orderByPriority($column, array $priority, $direction = 'asc')
{
$cases = [];

foreach ($priority as $index => $value) {
$cases[] = "WHEN {$column} = ? THEN {$index}";
}

$caseStatement = 'CASE '.implode(' ', $cases).' ELSE '.count($priority).' END';

return "{$caseStatement} {$direction}";
}
}
21 changes: 21 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -456,4 +456,25 @@ protected function wrapJsonSelector($value)

return 'json_extract('.$field.$path.')';
}

/**
* Apply custom ordering to a query based on a priority array.
*
* @param $column
* @param array $priority
* @param $direction
* @return string
*/
public function orderByPriority($column, array $priority, $direction = 'asc')
{
$cases = [];

foreach ($priority as $index => $value) {
$cases[] = "WHEN {$column} = ? THEN {$index}";
}

$caseStatement = 'CASE '.implode(' ', $cases).' ELSE '.count($priority).' END';

return "{$caseStatement} {$direction}";
}
}
19 changes: 19 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -581,4 +581,23 @@ protected function wrapTableValuedFunction($table)

return $table;
}

/**
* @param $column
* @param array $priority
* @param $direction
* @return string
*/
public function orderByPriority($column, array $priority, $direction = 'asc')
{
$cases = [];

foreach ($priority as $index => $value) {
$cases[] = "WHEN {$column} = ? THEN {$index}";
}

$caseStatement = 'CASE '.implode(' ', $cases).' ELSE '.count($priority).' END';

return "{$caseStatement} {$direction}";
}
}
7 changes: 7 additions & 0 deletions tests/Database/DatabaseMariaDbQueryGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -28,4 +28,11 @@ public function testToRawSql()

$this->assertSame('select * from "users" where \'Hello\\\'World?\' IS NOT NULL AND "email" = \'foo\'', $query);
}

public function testOrderByPriority()
{
$grammar = new MariaDbGrammar;
$queryString = $grammar->orderByPriority('name', ['john', 'doe']);
$this->assertSame('FIELD(name, ?,?) asc', $queryString);
}
}
7 changes: 7 additions & 0 deletions tests/Database/DatabaseMySqlQueryGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -28,4 +28,11 @@ public function testToRawSql()

$this->assertSame('select * from "users" where \'Hello\\\'World?\' IS NOT NULL AND "email" = \'foo\'', $query);
}

public function testOrderByPriority()
{
$grammar = new MySqlGrammar;
$queryString = $grammar->orderByPriority('name', ['john', 'doe']);
$this->assertSame('FIELD(name, ?,?) asc', $queryString);
}
}
7 changes: 7 additions & 0 deletions tests/Database/DatabasePostgresQueryGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -28,4 +28,11 @@ public function testToRawSql()

$this->assertSame('select * from "users" where \'{}\' ? \'Hello\\\'\\\'World?\' AND "email" = \'foo\'', $query);
}

public function testOrderByPriority()
{
$grammar = new PostgresGrammar;
$queryString = $grammar->orderByPriority('name', ['john', 'doe']);
$this->assertSame('CASE WHEN name = ? THEN 0 WHEN name = ? THEN 1 ELSE 2 END asc', $queryString);
}
}
7 changes: 7 additions & 0 deletions tests/Database/DatabaseSQLiteQueryGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -28,4 +28,11 @@ public function testToRawSql()

$this->assertSame('select * from "users" where \'Hello\'\'World?\' IS NOT NULL AND "email" = \'foo\'', $query);
}

public function testOrderByPriority()
{
$grammar = new SQLiteGrammar;
$queryString = $grammar->orderByPriority('name', ['john', 'doe']);
$this->assertSame('CASE WHEN name = ? THEN 0 WHEN name = ? THEN 1 ELSE 2 END asc', $queryString);
}
}
7 changes: 7 additions & 0 deletions tests/Database/DatabaseSqlServerQueryGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -28,4 +28,11 @@ public function testToRawSql()

$this->assertSame("select * from [users] where 'Hello''World?' IS NOT NULL AND [email] = 'foo'", $query);
}

public function testOrderByPriority()
{
$grammar = new SqlServerGrammar;
$queryString = $grammar->orderByPriority('name', ['john', 'doe']);
$this->assertSame('CASE WHEN name = ? THEN 0 WHEN name = ? THEN 1 ELSE 2 END asc', $queryString);
}
}