From 3fafd0e017a6f1c9d952e0723d811210cc824b4f Mon Sep 17 00:00:00 2001 From: Daniel Ang Date: Fri, 26 Nov 2021 16:02:59 +0100 Subject: [PATCH 1/6] Downgrade postgres --- .github/workflows/php.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.github/workflows/php.yml b/.github/workflows/php.yml index b1099cbd..fae67660 100644 --- a/.github/workflows/php.yml +++ b/.github/workflows/php.yml @@ -24,7 +24,7 @@ jobs: 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 From 5fc27cc59f3559663fa63f7284e82b51481fee85 Mon Sep 17 00:00:00 2001 From: Daniel Ang Date: Fri, 26 Nov 2021 16:06:33 +0100 Subject: [PATCH 2/6] Refactor SqlSupport --- src/Helpers/SqlSupport.php | 72 +++++++++++++----------- tests/Feature/Helpers/SqlSupportTest.php | 32 +++++++++++ 2 files changed, 71 insertions(+), 33 deletions(-) create mode 100644 tests/Feature/Helpers/SqlSupportTest.php diff --git a/src/Helpers/SqlSupport.php b/src/Helpers/SqlSupport.php index 6999fd69..484065f0 100644 --- a/src/Helpers/SqlSupport.php +++ b/src/Helpers/SqlSupport.php @@ -8,16 +8,13 @@ class SqlSupport { /** - * @var array|string[] + * @var array|string[] */ private static array $sortStringNumberTypes = ['string', 'varchar', 'char']; - /** - * @return string - */ public static function like(): string { - $driverName = DB::getDriverName(); + $driverName = self::getDatabaseName(); $likeSyntax = [ 'pgsql' => 'ILIKE', @@ -26,41 +23,49 @@ 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::getDatabaseName(); + $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'); + } + + $default = "$sortField+0"; + + $supportedVersions = [ 'mysql' => [ - '*' => "CAST(NULLIF(REGEXP_REPLACE($sortField, '[[:alpha:]]+', ''), '') AS SIGNED INTEGER)", + '0' => "$sortField+0", + '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; } /** @@ -98,12 +103,13 @@ public static function getSortFieldType(string $sortField): ?string ->getName(); } - /** - * @return string - */ - public static function getServerVersion(): string + public static function getDatabaseName(): 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')); } } diff --git a/tests/Feature/Helpers/SqlSupportTest.php b/tests/Feature/Helpers/SqlSupportTest.php new file mode 100644 index 00000000..f17d443e --- /dev/null +++ b/tests/Feature/Helpers/SqlSupportTest.php @@ -0,0 +1,32 @@ +not->toBeNull(); +}); + +it('finds database version', function () { + expect(SqlSupport::getDatabaseVersion())->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']], + +]); From 2955304443593758ac6f40907d0673b573e5fde6 Mon Sep 17 00:00:00 2001 From: Daniel Ang Date: Fri, 26 Nov 2021 16:20:40 +0100 Subject: [PATCH 3/6] Change mysql to match main version --- .github/workflows/php.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.github/workflows/php.yml b/.github/workflows/php.yml index fae67660..30f353e5 100644 --- a/.github/workflows/php.yml +++ b/.github/workflows/php.yml @@ -20,7 +20,7 @@ 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: From 98415a0dd5717499fb42e01d76f5af076c49b907 Mon Sep 17 00:00:00 2001 From: Daniel Ang Date: Fri, 26 Nov 2021 16:23:50 +0100 Subject: [PATCH 4/6] Update password according to docker file --- .github/workflows/php.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.github/workflows/php.yml b/.github/workflows/php.yml index 30f353e5..2a20e674 100644 --- a/.github/workflows/php.yml +++ b/.github/workflows/php.yml @@ -27,7 +27,7 @@ jobs: image: postgres:9.6 env: POSTGRES_USER: postgres - POSTGRES_PASSWORD: postgres + POSTGRES_PASSWORD: password POSTGRES_DB: powergridtest ports: - 5433:5432 From 8e3481d82438713fd8d5bbd62f066d6f594551d6 Mon Sep 17 00:00:00 2001 From: Daniel Ang Date: Fri, 26 Nov 2021 17:11:43 +0100 Subject: [PATCH 5/6] Improve method name and add comments --- src/Helpers/SqlSupport.php | 28 +++++++++++++++++++----- tests/Feature/Helpers/SqlSupportTest.php | 4 ++-- 2 files changed, 25 insertions(+), 7 deletions(-) diff --git a/src/Helpers/SqlSupport.php b/src/Helpers/SqlSupport.php index 484065f0..a4320236 100644 --- a/src/Helpers/SqlSupport.php +++ b/src/Helpers/SqlSupport.php @@ -14,7 +14,15 @@ class SqlSupport public static function like(): string { - $driverName = self::getDatabaseName(); + $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', @@ -25,7 +33,7 @@ public static function like(): string public static function sortStringAsNumber(string $sortField): string { - $driverName = self::getDatabaseName(); + $driverName = self::getDatabaseDriverName(); $driverVersion = self::getDatabaseVersion(); return self::getSortSqlByDriver($sortField, $driverName, $driverVersion); @@ -37,11 +45,21 @@ public static function getSortSqlByDriver(string $sortField, string $driverName throw new Exception('sortField, driverName and driverVersion must be informed'); } - $default = "$sortField+0"; + /* + |-------------------------------------------------------------------------- + | 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' => [ - '0' => "$sortField+0", + '0' => $default, '8.0.4' => "CAST(NULLIF(REGEXP_REPLACE($sortField, '[[:alpha:]]+', ''), '') AS SIGNED INTEGER)", ], 'sqlite' => [ @@ -103,7 +121,7 @@ public static function getSortFieldType(string $sortField): ?string ->getName(); } - public static function getDatabaseName(): string + public static function getDatabaseDriverName(): string { return DB::getDriverName(); } diff --git a/tests/Feature/Helpers/SqlSupportTest.php b/tests/Feature/Helpers/SqlSupportTest.php index f17d443e..612f66e4 100644 --- a/tests/Feature/Helpers/SqlSupportTest.php +++ b/tests/Feature/Helpers/SqlSupportTest.php @@ -2,8 +2,8 @@ use PowerComponents\LivewirePowerGrid\Helpers\SqlSupport; -it('finds database name', function () { - expect(SqlSupport::getDatabaseName())->not->toBeNull(); +it('finds database driver name', function () { + expect(SqlSupport::getDatabaseDriverName())->not->toBeNull(); }); it('finds database version', function () { From 73f7fc8356572fad9a8887970b32804409992cfa Mon Sep 17 00:00:00 2001 From: Daniel Ang Date: Fri, 26 Nov 2021 17:33:24 +0100 Subject: [PATCH 6/6] Adds test for SqlSupport::like --- tests/Feature/Helpers/SqlSupportTest.php | 23 +++++++++++++++++++++++ 1 file changed, 23 insertions(+) diff --git a/tests/Feature/Helpers/SqlSupportTest.php b/tests/Feature/Helpers/SqlSupportTest.php index 612f66e4..f07a5c45 100644 --- a/tests/Feature/Helpers/SqlSupportTest.php +++ b/tests/Feature/Helpers/SqlSupportTest.php @@ -10,6 +10,29 @@ 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']);