add date casting examples

This commit is contained in:
Matthew Bucci
2024-10-18 22:41:40 -07:00
parent 129aa7f171
commit 5d8407d244
3 changed files with 144 additions and 0 deletions

View File

@@ -68,8 +68,40 @@ class SelectSQLRewriter extends AbstractSQLRewriter
// HANDLE REGEXP // HANDLE REGEXP
$sql = preg_replace('/REGEXP/', '~', $sql); $sql = preg_replace('/REGEXP/', '~', $sql);
// Replace utc_timestamp with equivalent
$sql = str_replace("utc_timestamp()", "CURRENT_TIMESTAMP AT TIME ZONE 'UTC'", $sql); $sql = str_replace("utc_timestamp()", "CURRENT_TIMESTAMP AT TIME ZONE 'UTC'", $sql);
// Remove quotes from order by statmeents
$sql = preg_replace("/ORDER BY\s+'(\w+)'\s*(ASC|DESC)?/i", "ORDER BY $1 $2", $sql);
// remove backticks
$sql = preg_replace('/`/', '', $sql);
// rewrite DATE function
$sql = preg_replace('/DATE\(([^)]+)\)/i', '$1::date', $sql);
// Replace SUBSTRING_INDEX with PostgreSQL equivalent (split_part)
// Match the structure: SUBSTRING_INDEX(..., 'delimiter', number)
$sql = preg_replace_callback(
'/SUBSTRING_INDEX\(\s*(.+?)\s*,\s*\'([^\']+)\'\s*,\s*(\d+)\s*\)/i',
function ($matches) {
// Convert to split_part(column, 'delimiter', number)
$column = $matches[1];
$delimiter = $matches[2];
$number = $matches[3];
// If the number is positive, use split_part directly,
// else we can adjust for negative numbers by manually counting parts (not supported by split_part).
if ($number > 0) {
return "split_part($column, '$delimiter', $number)";
} else {
// Handle the negative case if needed (split_part doesn't directly support negative indexing).
return "reverse(split_part(reverse($column), '$delimiter', " . abs($number) . "))";
}
},
$sql
);
// In order for users counting to work... // In order for users counting to work...
$matches = array(); $matches = array();
if(preg_match_all('/COUNT[^C]+\),/', $sql, $matches)) { if(preg_match_all('/COUNT[^C]+\),/', $sql, $matches)) {

View File

@@ -33,6 +33,8 @@ final class parseTest extends TestCase
$this->assertSame($GLOBALS['pg4wp_ins_field'], "post_author"); $this->assertSame($GLOBALS['pg4wp_ins_field'], "post_author");
} }
protected function setUp(): void protected function setUp(): void
{ {
global $wpdb; global $wpdb;

View File

@@ -785,6 +785,116 @@ final class rewriteTest extends TestCase
$this->assertSame(trim($expected), trim($postgresql)); $this->assertSame(trim($expected), trim($postgresql));
} }
public function test_it_handles_order_by_on_non_integer()
{
$sql = <<<SQL
SELECT 'date' FROM `wp_statistics_pages` ORDER BY 'page_id' ASC LIMIT 1
SQL;
$expected = <<<SQL
SELECT 'date', 'page_id' FROM wp_statistics_pages ORDER BY page_id ASC LIMIT 1
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
public function test_it_replaces_backticks_with_quotes()
{
$sql = <<<SQL
SELECT `location`, COUNT(`location`) AS `count` FROM `wp_statistics_visitor` WHERE `last_counter` BETWEEN '2024-09-20' AND '2024-10-19' GROUP BY `location` ORDER BY `count` DESC LIMIT 10
SQL;
$expected = <<<SQL
SELECT location, COUNT(location) AS count, location ORDER BY count FROM wp_statistics_visitor WHERE last_counter BETWEEN '2024-09-20' AND '2024-10-19' GROUP BY location, location ORDER BY count
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
public function test_it_replaces_backticks_substring_index_with_split_part()
{
$sql = <<<SQL
SELECT SUBSTRING_INDEX(REPLACE( REPLACE( referred, 'http://', '') , 'https://' , '') , '/', 1 ) as `domain`, count(referred) as `number`
FROM wp_statistics_visitor WHERE `referred` REGEXP "^(https?://|www\.)[\.A-Za-z0-9\-]+\.[a-zA-Z]{2,4}"
AND referred <> ''
AND LENGTH(referred) >=12
AND `last_counter` BETWEEN '2024-09-20' AND '2024-10-19'
AND `referred` NOT LIKE 'http://wordpress.localhost%'
AND `referred` NOT LIKE 'http://www.wordpress.localhost%'
AND `referred` NOT LIKE 'https://wordpress.localhost%'
AND `referred` NOT LIKE 'https://www.wordpress.localhost%'
AND `referred` NOT LIKE 'ftp://wordpress.localhost%'
AND `referred` NOT LIKE 'ftp://www.wordpress.localhost%'
GROUP BY domain
ORDER BY `number` DESC LIMIT 10
SQL;
$expected = <<<SQL
SELECT split_part(replace(replace(referred, 'http://', ''), 'https://', ''), '/', 1) as domain, count(referred) as number
FROM wp_statistics_visitor WHERE referred ~ '^(https?://|www\.)[\.A-Za-z0-9\-]+\.[a-zA-Z]{2,4}'
AND referred <> ''
AND LENGTH(referred) >= 12
AND last_counter BETWEEN '2024-09-20' AND '2024-10-19'
AND referred NOT LIKE 'http://wordpress.localhost%'
AND referred NOT LIKE 'http://www.wordpress.localhost%'
AND referred NOT LIKE 'https://wordpress.localhost%'
AND referred NOT LIKE 'https://www.wordpress.localhost%'
AND referred NOT LIKE 'ftp://wordpress.localhost%'
AND referred NOT LIKE 'ftp://www.wordpress.localhost%'
GROUP BY domain
ORDER BY number DESC
LIMIT 10;
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
public function test_it_converts_to_date_casting()
{
$sql = <<<SQL
SELECT search.last_counter AS date, COUNT(DISTINCT search.visitor) AS visitors, search.engine FROM wp_statistics_search AS search WHERE DATE(search.last_counter) BETWEEN '2024-10-13' AND '2024-10-19' GROUP BY search.last_counter, search.engine ORDER BY date DESC
SQL;
$expected = <<<SQL
SELECT search.last_counter AS date, COUNT(DISTINCT search.visitor) AS visitors, search.engine FROM wp_statistics_search AS search WHERE search.last_counter::date BETWEEN '2024-10-13' AND '2024-10-19' GROUP BY search.last_counter, search.engine ORDER BY date DESC;
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
public function test_it_converts_to_date_casting_another_example()
{
$sql = <<<SQL
SELECT SUM(pages.count) as views, pages.date as date FROM wp_statistics_pages AS pages WHERE DATE(pages.date) BETWEEN '2024-10-13' AND '2024-10-19' GROUP BY pages.date
SQL;
$expected = <<<SQL
SELECT SUM(pages.count) AS views, pages.date AS date FROM wp_statistics_pages AS pages WHERE pages.date::date BETWEEN '2024-10-13' AND '2024-10-19' GROUP BY pages.date;
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
public function test_it_correctly_handles_alias_orderBys()
{
$sql = <<<SQL
SELECT visitor.last_counter as date, COUNT(visitor.ID) as visitors FROM wp_statistics_visitor AS visitor WHERE DATE(visitor.last_counter) BETWEEN '2024-10-13' AND '2024-10-19' GROUP BY visitor.last_counter
SQL;
$expected = <<<SQL
SELECT visitor.last_counter::date AS date, COUNT(visitor.id) AS visitors FROM wp_statistics_visitor AS visitor WHERE visitor.last_counter::date BETWEEN '2024-10-13' AND '2024-10-19' GROUP BY visitor.last_counter::date;
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
protected function setUp(): void protected function setUp(): void
{ {
global $wpdb; global $wpdb;