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

SqlSupport refactoring #156

Merged
merged 6 commits into from
Nov 26, 2021
Merged
Show file tree
Hide file tree
Changes from all 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
6 changes: 3 additions & 3 deletions .github/workflows/php.yml
Original file line number Diff line number Diff line change
Expand Up @@ -20,14 +20,14 @@ jobs:
MYSQL_ROOT_PASSWORD: password
MYSQL_DATABASE: powergridtest
ports:
- 3308:3306
- 3307:3306
options: --health-cmd="mysqladmin ping" --health-interval=10s --health-timeout=5s --health-retries=3

postgres:
image: postgres:10.8
image: postgres:9.6
env:
POSTGRES_USER: postgres
POSTGRES_PASSWORD: postgres
POSTGRES_PASSWORD: password
POSTGRES_DB: powergridtest
ports:
- 5433:5432
Expand Down
90 changes: 57 additions & 33 deletions src/Helpers/SqlSupport.php
Original file line number Diff line number Diff line change
Expand Up @@ -8,16 +8,21 @@
class SqlSupport
{
/**
* @var array|string[]
* @var array<int,string>|string[]
*/
private static array $sortStringNumberTypes = ['string', 'varchar', 'char'];

/**
* @return string
*/
public static function like(): string
{
$driverName = DB::getDriverName();
$driverName = self::getDatabaseDriverName();

/*
|--------------------------------------------------------------------------
| Search 'LIKE' (drivers)
|--------------------------------------------------------------------------
| PowerGrid needs to sort with "case-insensitive".
| Here, we adapt the 'LIKE' syntax for each database driver.
*/

$likeSyntax = [
'pgsql' => 'ILIKE',
Expand All @@ -26,41 +31,59 @@ public static function like(): string
return $likeSyntax[$driverName] ?? 'LIKE';
}

/**
* @param string $sortField
* @return string
*/
public static function sortStringAsNumber(string $sortField): string
{
$driverName = DB::getDriverName();

return self::getSortSqlByDriver($sortField, $driverName);
$driverName = self::getDatabaseDriverName();
$driverVersion = self::getDatabaseVersion();

return self::getSortSqlByDriver($sortField, $driverName, $driverVersion);
}

/**
* @param string $sortField
* @param string $driverName
* @param string $driverVersion
* @return string
*/
private static function getSortSqlByDriver(string $sortField, string $driverName, string $driverVersion = '*'): string
public static function getSortSqlByDriver(string $sortField, string $driverName = '', string $driverVersion = ''): string
{
$sqlByDriver = [
'sqlite' => [
'*' => "CAST($sortField AS INTEGER)",
],
if (empty($sortField) || empty($driverName) || empty($driverVersion)) {
throw new Exception('sortField, driverName and driverVersion must be informed');
}

/*
|--------------------------------------------------------------------------
| Supported Databases (drivers)
|--------------------------------------------------------------------------
| PowerGrid needs to sort string as number. I.e: Rooms 1, 1a, 1b, 2, 3... 10.
| Here, we adapt the SQL sorting syntax between databases and versions.
| 0 => default,
| x.x.x => version which the syntax was implemented.
*/

$default = "$sortField+0"; //default, fallback

$supportedVersions = [
'mysql' => [
'*' => "CAST(NULLIF(REGEXP_REPLACE($sortField, '[[:alpha:]]+', ''), '') AS SIGNED INTEGER)",
'0' => $default,
'8.0.4' => "CAST(NULLIF(REGEXP_REPLACE($sortField, '[[:alpha:]]+', ''), '') AS SIGNED INTEGER)",
],
'sqlite' => [
'0' => "CAST($sortField AS INTEGER)",
],
'pgsql' => [
'*' => "CAST(NULLIF(REGEXP_REPLACE($sortField, '\D', '', 'g'), '') AS INTEGER)",
'0' => "CAST(NULLIF(REGEXP_REPLACE($sortField, '\D', '', 'g'), '') AS INTEGER)",
],
'sqlsrv' => [
'*' => "CAST(SUBSTRING($sortField, PATINDEX('%[a-z]%', $sortField), LEN($sortField)-PATINDEX('%[a-z]%', $sortField)) AS INT)",
'0' => "CAST(SUBSTRING($sortField, PATINDEX('%[a-z]%', $sortField), LEN($sortField)-PATINDEX('%[a-z]%', $sortField)) AS INT)",
],
];

return $sqlByDriver[$driverName][$driverVersion] ?? $sortField;
if (!isset($supportedVersions[$driverName])) {
return $default;
}

$syntax = collect($supportedVersions[$driverName])
->filter(function ($syntax, $version) use ($driverVersion) {
return version_compare($version, $driverVersion, '<=');
})
->last();

return is_null($syntax) === true ? $default : $syntax;
}

/**
Expand Down Expand Up @@ -98,12 +121,13 @@ public static function getSortFieldType(string $sortField): ?string
->getName();
}

/**
* @return string
*/
public static function getServerVersion(): string
public static function getDatabaseDriverName(): string
{
return DB::getDriverName();
}

public static function getDatabaseVersion(): string
{
return DB::getPdo()
->getAttribute(constant('PDO::ATTR_SERVER_VERSION'));
return DB::getPdo()->getAttribute(constant('PDO::ATTR_SERVER_VERSION'));
}
}
55 changes: 55 additions & 0 deletions tests/Feature/Helpers/SqlSupportTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
<?php

use PowerComponents\LivewirePowerGrid\Helpers\SqlSupport;

it('finds database driver name', function () {
expect(SqlSupport::getDatabaseDriverName())->not->toBeNull();
});

it('finds database version', function () {
expect(SqlSupport::getDatabaseVersion())->not->toBeNull();
});

it('returns the proper "LIKE" syntax', function () {
$driver = SqlSupport::getDatabaseDriverName();

expect(SqlSupport::like())
->when(
$driver === 'mysql',
fn ($syntax) => $syntax->toBe('LIKE')
)
->when(
$driver === 'sqlite',
fn ($syntax) => $syntax->toBe('LIKE')
)
->when(
$driver === 'sqlsrv',
fn ($syntax) => $syntax->toBe('LIKE')
)
->when(
$driver === 'pgsql',
fn ($syntax) => $syntax->toBe('ILIKE')
)
->not->toBeNull();
});

it('returns sortField', function (array $data) {
expect(SqlSupport::getSortSqlByDriver('field', $data['db'], $data['version']))
->toBe($data['expected']);
})->with([
[['db' => 'sqlite', 'version' => '3.36.0', 'expected' => 'CAST(field AS INTEGER)']],
[['db' => 'mysql', 'version' => '5.5.59-MariaDB', 'expected' => 'field+0']],
[['db' => 'mysql', 'version' => '5.4.1', 'expected' => 'field+0']],
[['db' => 'mysql', 'version' => '5.7.36', 'expected' => 'field+0']],
[['db' => 'mysql', 'version' => '8.0.3', 'expected' => 'field+0']],
[['db' => 'mysql', 'version' => '8.0.4', 'expected' => "CAST(NULLIF(REGEXP_REPLACE(field, '[[:alpha:]]+', ''), '') AS SIGNED INTEGER)"]],
[['db' => 'mysql', 'version' => '8.0.5', 'expected' => "CAST(NULLIF(REGEXP_REPLACE(field, '[[:alpha:]]+', ''), '') AS SIGNED INTEGER)"]],
[['db' => 'pgsql', 'version' => '9.6.24', 'expected' => "CAST(NULLIF(REGEXP_REPLACE(field, '\D', '', 'g'), '') AS INTEGER)"]],
[['db' => 'pgsql', 'version' => '13.5', 'expected' => "CAST(NULLIF(REGEXP_REPLACE(field, '\D', '', 'g'), '') AS INTEGER)"]],
[['db' => 'pgsql', 'version' => '15.5', 'expected' => "CAST(NULLIF(REGEXP_REPLACE(field, '\D', '', 'g'), '') AS INTEGER)"]],
[['db' => 'sqlsrv', 'version' => '9.2', 'expected' => "CAST(SUBSTRING(field, PATINDEX('%[a-z]%', field), LEN(field)-PATINDEX('%[a-z]%', field)) AS INT)"]],
[['db' => 'sqlsrv', 'version' => '14.00.3421', 'expected' => "CAST(SUBSTRING(field, PATINDEX('%[a-z]%', field), LEN(field)-PATINDEX('%[a-z]%', field)) AS INT)"]],
[['db' => 'sqlsrv', 'version' => '20.80', 'expected' => "CAST(SUBSTRING(field, PATINDEX('%[a-z]%', field), LEN(field)-PATINDEX('%[a-z]%', field)) AS INT)"]],
[['db' => 'unsupported-db', 'version' => '29.00.00', 'expected' => 'field+0']],

]);