From 83002198b109c54b71e627ec1efcfc7c864dedca Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Sat, 28 Oct 2023 02:56:41 -0700 Subject: [PATCH] Polymorphic refactor + improvements to select sql rewriting --- pg4wp/driver_pgsql.php | 1203 ++++++++--------- pg4wp/driver_pgsql_rewrite.php | 204 +++ pg4wp/rewriters/AbstractSQLRewriter.php | 26 + pg4wp/rewriters/DeleteSQLRewriter.php | 60 + pg4wp/rewriters/InsertSQLRewriter.php | 124 ++ pg4wp/rewriters/OptimizeTableSQLRewriter.php | 10 + pg4wp/rewriters/SelectSQLRewriter.php | 324 +++++ pg4wp/rewriters/SetNamesSQLRewriter.php | 9 + .../rewriters/ShowFullColumnsSQLRewriter.php | 71 + pg4wp/rewriters/ShowTablesSQLRewriter.php | 9 + pg4wp/rewriters/UpdateSQLRewriter.php | 32 + 11 files changed, 1416 insertions(+), 656 deletions(-) create mode 100644 pg4wp/driver_pgsql_rewrite.php create mode 100644 pg4wp/rewriters/AbstractSQLRewriter.php create mode 100644 pg4wp/rewriters/DeleteSQLRewriter.php create mode 100644 pg4wp/rewriters/InsertSQLRewriter.php create mode 100644 pg4wp/rewriters/OptimizeTableSQLRewriter.php create mode 100644 pg4wp/rewriters/SelectSQLRewriter.php create mode 100644 pg4wp/rewriters/SetNamesSQLRewriter.php create mode 100644 pg4wp/rewriters/ShowFullColumnsSQLRewriter.php create mode 100644 pg4wp/rewriters/ShowTablesSQLRewriter.php create mode 100644 pg4wp/rewriters/UpdateSQLRewriter.php diff --git a/pg4wp/driver_pgsql.php b/pg4wp/driver_pgsql.php index a5fcbe7..9be82cc 100644 --- a/pg4wp/driver_pgsql.php +++ b/pg4wp/driver_pgsql.php @@ -1,10 +1,13 @@ If you want to do it anyway, please set "PG4WP_INSECURE" to true in your "db.php" file.' ); - - // PostgreSQL must connect to a specific database (unlike MySQL) - // Guess at one here and reconnect as required in wpsql_select_db - $dbname = defined('DB_NAME') && DB_NAME ? DB_NAME : 'template1'; - return pg_connect( $GLOBALS['pg4wp_connstr'].' dbname='.$dbname); - } - - // The effective connection happens here - function wpsql_select_db($dbname, $connection_id = 0) - { - $pg_connstr = $GLOBALS['pg4wp_connstr'].' dbname='.$dbname; - - // Note: pg_connect returns existing connection for same connstr - $GLOBALS['pg4wp_conn'] = $conn = pg_connect($pg_connstr); - - if( !$conn) - return $conn; - - $ver = pg_version($conn); - if( isset($ver['server'])) - $GLOBALS['pg4wp_version'] = $ver['server']; - - // Now we should be connected, we "forget" about the connection parameters (if this is not a "test" connection) - if( !defined('WP_INSTALLING') || !WP_INSTALLING) - $GLOBALS['pg4wp_connstr'] = ''; - - // Execute early transmitted commands if needed - if( !empty($GLOBALS['pg4wp_pre_sql'])) - foreach( $GLOBALS['pg4wp_pre_sql'] as $sql2run) - wpsql_query( $sql2run); - - pg4wp_init($conn); - - return $conn; - } - - function wpsql_fetch_array($result) - { - $res = pg_fetch_array($result); - - if( is_array($res) ) - foreach($res as $v => $k ) - $res[$v] = trim($k); - return $res; - } - - function wpsql_query($sql) - { - if( !$GLOBALS['pg4wp_conn']) - { - // Catch SQL to be executed as soon as connected - $GLOBALS['pg4wp_pre_sql'][] = $sql; - return true; - } - - $initial = $sql; - $sql = pg4wp_rewrite( $sql); - - $GLOBALS['pg4wp_result'] = pg_query($GLOBALS['pg4wp_conn'], $sql); - if( (PG4WP_DEBUG || PG4WP_LOG_ERRORS) && $GLOBALS['pg4wp_result'] === false && $err = pg_last_error($GLOBALS['pg4wp_conn'])) - { - $ignore = false; - if( defined('WP_INSTALLING') && WP_INSTALLING) - { - global $table_prefix; - $ignore = strpos($err, 'relation "'.$table_prefix); - } - if( ! $ignore ) - error_log('['.microtime(true)."] Error running :\n$initial\n---- converted to ----\n$sql\n----> $err\n---------------------\n", 3, PG4WP_LOG.'pg4wp_errors.log'); - } - return $GLOBALS['pg4wp_result']; - } - - function wpsql_insert_id($lnk = NULL) - { - global $wpdb; - $ins_field = $GLOBALS['pg4wp_ins_field']; - $table = $GLOBALS['pg4wp_ins_table']; - $lastq = $GLOBALS['pg4wp_last_insert']; - - $seq = $table . '_seq'; - - // Table 'term_relationships' doesn't have a sequence - if( $table == $wpdb->term_relationships) - { - $sql = 'NO QUERY'; - $data = 0; - } - // When using WP_Import plugin, ID is defined in the query - elseif('post_author' == $ins_field && false !== strpos($lastq,'ID')) - { - $sql = 'ID was in query '; - $pattern = '/.+\'(\d+).+$/'; - preg_match($pattern, $lastq, $matches); - $data = $matches[1]; - // We should update the sequence on the next non-INSERT query - $GLOBALS['pg4wp_queued_query'] = "SELECT SETVAL('$seq',(SELECT MAX(\"ID\") FROM $table)+1);"; - } - else - { - $sql = "SELECT CURRVAL('$seq')"; - - $res = pg_query($sql); - if( false !== $res) - $data = pg_fetch_result($res, 0, 0); - elseif( PG4WP_DEBUG || PG4WP_LOG) - { - $log = '['.microtime(true)."] wpsql_insert_id() was called with '$table' and '$ins_field'". - " and returned the error:\n".pg_last_error(). - "\nFor the query:\n".$sql. - "\nThe latest INSERT query was :\n'$lastq'\n"; - error_log( $log, 3, PG4WP_LOG.'pg4wp_errors.log'); - } - } - if( PG4WP_DEBUG && $sql) - error_log( '['.microtime(true)."] Getting inserted ID for '$table' ('$ins_field') : $sql => $data\n", 3, PG4WP_LOG.'pg4wp_insertid.log'); - - return $data; - } - - // Convert MySQL FIELD function to CASE statement - // https://dev.mysql.com/doc/refman/5.7/en/string-functions.html#function_field - // Other implementations: https://stackoverflow.com/q/1309624 - function pg4wp_rewrite_field($matches) - { - $case = 'CASE ' . trim($matches[1]); - $comparands = explode(',', $matches[2]); - foreach($comparands as $i => $comparand) { - $case .= ' WHEN ' . trim($comparand) . ' THEN ' . ($i + 1); - } - $case .= ' ELSE 0 END'; - return $case; - } - - function pg4wp_rewrite( $sql) - { - // Note: Can be called from constructor before $wpdb is set - global $wpdb; - - $logto = 'queries'; - // The end of the query may be protected against changes - $end = ''; - - // Remove unusefull spaces - $initial = $sql = trim($sql); - - if( 0 === strpos($sql, 'SELECT')) - { - $logto = 'SELECT'; - // SQL_CALC_FOUND_ROWS doesn't exist in PostgreSQL but it's needed for correct paging - if( false !== strpos($sql, 'SQL_CALC_FOUND_ROWS')) - { - $sql = str_replace('SQL_CALC_FOUND_ROWS', '', $sql); - $GLOBALS['pg4wp_numrows_query'] = $sql; - if( PG4WP_DEBUG) - error_log( '['.microtime(true)."] Number of rows required for :\n$sql\n---------------------\n", 3, PG4WP_LOG.'pg4wp_NUMROWS.log'); - } - elseif( false !== strpos($sql, 'FOUND_ROWS()')) - { - // Here we convert the latest query into a COUNT query - $sql = $GLOBALS['pg4wp_numrows_query']; - - // Remove the LIMIT clause if it exists - $sql = preg_replace('/\s+LIMIT\s+\d+(\s*,\s*\d+)?/i', '', $sql); - - // Remove the ORDER BY clause if it exists - $sql = preg_replace('/\s+ORDER\s+BY\s+[^)]+/i', '', $sql); - - // Replace the fields in the SELECT clause with COUNT(*) - $sql = preg_replace('/SELECT\s+.*?\s+FROM\s+/is', 'SELECT COUNT(*) FROM ', $sql, 1); - } - - // Ensure that ORDER BY column appears in SELECT DISTINCT fields - $pattern = '/^SELECT DISTINCT.*ORDER BY\s+(\S+)/'; - if( preg_match( $pattern, $sql, $matches) && - strpos( $sql, $matches[1]) > strpos( $sql, 'ORDER BY') && - false === strpos( $sql, '*')) - { - if( false !== strpos( $sql, 'GROUP BY')) - { - $pattern = '/ FROM /'; - $sql = preg_replace( $pattern, ', MIN('.$matches[1].') AS '.$matches[1].' FROM ', $sql, 1); - } - else - { - $pattern = '/ FROM /'; - $sql = preg_replace( $pattern, ', '.$matches[1].' FROM ', $sql, 1); - } - } - - // Convert CONVERT to CAST - $pattern = '/CONVERT\(([^()]*(\(((?>[^()]+)|(?-2))*\))?[^()]*),\s*([^\s]+)\)/x'; - $sql = preg_replace( $pattern, 'CAST($1 AS $4)', $sql); - - // Handle CAST( ... AS CHAR) - $sql = preg_replace( '/CAST\((.+) AS CHAR\)/', 'CAST($1 AS TEXT)', $sql); - - // Handle CAST( ... AS SIGNED) - $sql = preg_replace( '/CAST\((.+) AS SIGNED\)/', 'CAST($1 AS INTEGER)', $sql); - - // Handle COUNT(*)...ORDER BY... - $sql = preg_replace( '/COUNT(.+)ORDER BY.+/s', 'COUNT$1', $sql); - - // In order for users counting to work... - $matches = array(); - if( preg_match_all( '/COUNT[^C]+\),/',$sql, $matches)) - { - foreach( $matches[0] as $num => $one) - { - $sub = substr( $one, 0, -1); - $sql = str_replace( $sub, $sub.' AS count'.$num, $sql); - } - } - - $pattern = '/LIMIT[ ]+(\d+),[ ]*(\d+)/'; - $sql = preg_replace($pattern, 'LIMIT $2 OFFSET $1', $sql); - - $pattern = '/DATE_ADD[ ]*\(([^,]+),([^\)]+)\)/'; - $sql = preg_replace( $pattern, '($1 + $2)', $sql); - - $pattern = '/FIELD[ ]*\(([^\),]+),([^\)]+)\)/'; - $sql = preg_replace_callback( $pattern, 'pg4wp_rewrite_field', $sql); - - $pattern = '/GROUP_CONCAT\(([^()]*(\(((?>[^()]+)|(?-2))*\))?[^()]*)\)/x'; - $sql = preg_replace( $pattern, "string_agg($1, ',')", $sql); - - // Convert MySQL RAND function to PostgreSQL RANDOM function - $pattern = '/RAND[ ]*\([ ]*\)/'; - $sql = preg_replace( $pattern, 'RANDOM()', $sql); - - // UNIX_TIMESTAMP in MYSQL returns an integer - $pattern = '/UNIX_TIMESTAMP\(([^\)]+)\)/'; - $sql = preg_replace( $pattern, 'ROUND(DATE_PART(\'epoch\',$1))', $sql); - - $date_funcs = array( - 'DAYOFMONTH(' => 'EXTRACT(DAY FROM ', - 'YEAR(' => 'EXTRACT(YEAR FROM ', - 'MONTH(' => 'EXTRACT(MONTH FROM ', - 'DAY(' => 'EXTRACT(DAY FROM ', - ); - - $sql = str_replace( 'ORDER BY post_date DESC', 'ORDER BY YEAR(post_date) DESC, MONTH(post_date) DESC', $sql); - $sql = str_replace( 'ORDER BY post_date ASC', 'ORDER BY YEAR(post_date) ASC, MONTH(post_date) ASC', $sql); - $sql = str_replace( array_keys($date_funcs), array_values($date_funcs), $sql); - $curryear = date( 'Y'); - $sql = str_replace( 'FROM \''.$curryear, 'FROM TIMESTAMP \''.$curryear, $sql); - - // MySQL 'IF' conversion - Note : NULLIF doesn't need to be corrected - $pattern = '/ (?prefix.'posts.ID', '' , $sql); - } - $sql = str_replace("!= ''", '<> 0', $sql); - - // MySQL 'LIKE' is case insensitive by default, whereas PostgreSQL 'LIKE' is - $sql = str_replace( ' LIKE ', ' ILIKE ', $sql); - - // INDEXES are not yet supported - if( false !== strpos( $sql, 'USE INDEX (comment_date_gmt)')) - $sql = str_replace( 'USE INDEX (comment_date_gmt)', '', $sql); - - // HB : timestamp fix for permalinks - $sql = str_replace( 'post_date_gmt > 1970', 'post_date_gmt > to_timestamp (\'1970\')', $sql); - - // Akismet sometimes doesn't write 'comment_ID' with 'ID' in capitals where needed ... - if( isset($wpdb) && false !== strpos( $sql, $wpdb->comments)) - $sql = str_replace(' comment_id ', ' comment_ID ', $sql); - - // MySQL treats a HAVING clause without GROUP BY like WHERE - if( false !== strpos($sql, 'HAVING') && false === strpos($sql, 'GROUP BY')) - { - if( false === strpos($sql, 'WHERE')) - $sql = str_replace('HAVING', 'WHERE', $sql); - else - { - $pattern = '/WHERE\s+(.*?)\s+HAVING\s+(.*?)(\s*(?:ORDER|LIMIT|PROCEDURE|INTO|FOR|LOCK|$))/'; - $sql = preg_replace( $pattern, 'WHERE ($1) AND ($2) $3', $sql); - } - } - - // MySQL allows integers to be used as boolean expressions - // where 0 is false and all other values are true. - // - // Although this could occur anywhere with any number, so far it - // has only been observed as top-level expressions in the WHERE - // clause and only with 0. For performance, limit current - // replacements to that. - $pattern_after_where = '(?:\s*$|\s+(GROUP|HAVING|ORDER|LIMIT|PROCEDURE|INTO|FOR|LOCK))'; - $pattern = '/(WHERE\s+)0(\s+AND|\s+OR|' . $pattern_after_where . ')/'; - $sql = preg_replace( $pattern, '$1false$2', $sql); - - $pattern = '/(AND\s+|OR\s+)0(' . $pattern_after_where . ')/'; - $sql = preg_replace( $pattern, '$1false$2', $sql); - - // MySQL supports strings as names, PostgreSQL needs identifiers. - // Limit to after closing parenthesis to reduce false-positives - // Currently only an issue for nextgen-gallery plugin - $pattern = '/\) AS \'([^\']+)\'/'; - $sql = preg_replace( $pattern, ') AS "$1"', $sql); - } // SELECT - elseif( 0 === strpos($sql, 'UPDATE')) - { - $logto = 'UPDATE'; - $pattern = '/LIMIT[ ]+\d+/'; - $sql = preg_replace($pattern, '', $sql); - - // For correct bactick removal - $pattern = '/[ ]*`([^` ]+)`[ ]*=/'; - $sql = preg_replace( $pattern, ' $1 =', $sql); - - // Those are used when we need to set the date to now() in gmt time - $sql = str_replace( "'0000-00-00 00:00:00'", 'now() AT TIME ZONE \'gmt\'', $sql); - - // For correct ID quoting - $pattern = '/(,|\s)[ ]*([^ \']*ID[^ \']*)[ ]*=/'; - $sql = preg_replace( $pattern, '$1 "$2" =', $sql); - - // This will avoid modifications to anything following ' SET ' - list($sql,$end) = explode( ' SET ', $sql, 2); - $end = ' SET '.$end; - } // UPDATE - elseif( 0 === strpos($sql, 'INSERT')) - { - $logto = 'INSERT'; - $sql = str_replace('(0,',"('0',", $sql); - $sql = str_replace('(1,',"('1',", $sql); - - // Fix inserts into wp_categories - if( false !== strpos($sql, 'INSERT INTO '.$wpdb->categories)) - { - $sql = str_replace('"cat_ID",', '', $sql); - $sql = str_replace("VALUES ('0',", "VALUES(", $sql); - } - - // Those are used when we need to set the date to now() in gmt time - $sql = str_replace( "'0000-00-00 00:00:00'", 'now() AT TIME ZONE \'gmt\'', $sql); - - // Multiple values group when calling INSERT INTO don't always work - if( false !== strpos( $sql, $wpdb->options) && false !== strpos( $sql, '), (')) - { - $pattern = '/INSERT INTO.+VALUES/'; - preg_match($pattern, $sql, $matches); - $insert = $matches[0]; - $sql = str_replace( '), (', ');'.$insert.'(', $sql); - } - - // Support for "INSERT ... ON DUPLICATE KEY UPDATE ..." is a dirty hack - // consisting in deleting the row before inserting it - if( false !== $pos = strpos( $sql, 'ON DUPLICATE KEY')) - { - // Get the elements we need (table name, first field, corresponding value) - $pattern = '/INSERT INTO\s+([^\(]+)\(([^,]+)[^\(]+VALUES\s*\(([^,]+)/'; - preg_match($pattern, $sql, $matches); - $table = trim( $matches[1], ' `'); - if( !in_array(trim($matches[1],'` '), array($wpdb->posts,$wpdb->comments))) - { - // Remove 'ON DUPLICATE KEY UPDATE...' and following - $sql = substr( $sql, 0, $pos); - // Add a delete query to handle the maybe existing data - $sql = 'DELETE FROM '.$table.' WHERE '.$matches[2].' = '.$matches[3].';'.$sql; - } - } - elseif( 0 === strpos($sql, 'INSERT IGNORE')) - { - // Note: Requires PostgreSQL 9.0 and USAGE privilege. - // Could do query-specific rewrite using SELECT without FROM - // as in http://stackoverflow.com/a/13342031 - $sql = 'DO $$BEGIN INSERT'.substr($sql, 13).'; EXCEPTION WHEN unique_violation THEN END;$$;'; - } - - // To avoid Encoding errors when inserting data coming from outside - if( preg_match('/^.{1}/us',$sql,$ar) != 1) - $sql = utf8_encode($sql); - - // This will avoid modifications to anything following ' VALUES' - list($sql,$end) = explode( ' VALUES', $sql, 2); - $end = ' VALUES'.$end; - - // When installing, the sequence for table terms has to be updated - if( defined('WP_INSTALLING') && WP_INSTALLING && false !== strpos($sql, 'INSERT INTO `'.$wpdb->terms.'`')) - $end .= ';SELECT setval(\''.$wpdb->terms.'_seq\', (SELECT MAX(term_id) FROM '.$wpdb->terms.')+1);'; - - } // INSERT - elseif( 0 === strpos( $sql, 'DELETE' )) - { - $logto = 'DELETE'; - - // ORDER BY is not supported in DELETE queries, and not required - // when LIMIT is not present - if( false !== strpos( $sql, 'ORDER BY') && false === strpos( $sql, 'LIMIT')) - { - $pattern = '/ORDER BY \S+ (ASC|DESC)?/'; - $sql = preg_replace( $pattern, '', $sql); - } - - // LIMIT is not allowed in DELETE queries - $sql = str_replace( 'LIMIT 1', '', $sql); - $sql = str_replace( ' REGEXP ', ' ~ ', $sql); - - // This handles removal of duplicate entries in table options - if( false !== strpos( $sql, 'DELETE o1 FROM ')) - $sql = "DELETE FROM $wpdb->options WHERE option_id IN " . - "(SELECT o1.option_id FROM $wpdb->options AS o1, $wpdb->options AS o2 " . - "WHERE o1.option_name = o2.option_name " . - "AND o1.option_id < o2.option_id)"; - // Rewrite _transient_timeout multi-table delete query - elseif( 0 === strpos( $sql, 'DELETE a, b FROM wp_options a, wp_options b')) - { - $where = substr( $sql, strpos($sql, 'WHERE ') + 6); - $where = rtrim( $where, " \t\n\r;"); - // Fix string/number comparison by adding check and cast - $where = str_replace( 'AND b.option_value', 'AND b.option_value ~ \'^[0-9]+$\' AND CAST(b.option_value AS BIGINT)', $where); - // Mirror WHERE clause to delete both sides of self-join. - $where2 = strtr( $where, array('a.' => 'b.', 'b.' => 'a.')); - $sql = 'DELETE FROM wp_options a USING wp_options b WHERE '. - '('.$where.') OR ('.$where2.');'; - } - - // Akismet sometimes doesn't write 'comment_ID' with 'ID' in capitals where needed ... - if(isset($wpdb) && $wpdb->comments && false !== strpos( $sql, $wpdb->comments)) - $sql = str_replace(' comment_id ', ' comment_ID ', $sql); - } - // Fix tables listing - elseif( 0 === strpos($sql, 'SHOW TABLES')) - { - $logto = 'SHOWTABLES'; - $sql = 'SELECT tablename FROM pg_tables WHERE schemaname = \'public\';'; - } - // Rewriting optimize table - elseif( 0 === strpos($sql, 'OPTIMIZE TABLE')) - { - $logto = 'OPTIMIZE'; - $sql = str_replace( 'OPTIMIZE TABLE', 'VACUUM', $sql); - } - // Handle 'SET NAMES ... COLLATE ...' - elseif( 0 === strpos($sql, 'SET NAMES') && false !== strpos($sql, 'COLLATE')) - { - $logto = 'SETNAMES'; - $sql = "SET NAMES 'utf8'"; - } - // Load up upgrade and install functions as required - $begin = strtoupper( substr( $sql, 0, 3)); - $search = array( 'SHO', 'ALT', 'DES', 'CRE', 'DRO'); - if( in_array($begin, $search)) - { - require_once( PG4WP_ROOT.'/driver_pgsql_install.php'); - $sql = pg4wp_installing( $sql, $logto); - } - - // WP 2.9.1 uses a comparison where text data is not quoted - $pattern = '/AND meta_value = (-?\d+)/'; - $sql = preg_replace( $pattern, 'AND meta_value = \'$1\'', $sql); - - // Add type cast for meta_value field when it's compared to number - $pattern = '/AND meta_value < (\d+)/'; - $sql = preg_replace($pattern, 'AND meta_value::bigint < $1', $sql); - - // Generic "INTERVAL xx YEAR|MONTH|DAY|HOUR|MINUTE|SECOND" handler - $pattern = '/INTERVAL[ ]+(\d+)[ ]+(YEAR|MONTH|DAY|HOUR|MINUTE|SECOND)/'; - $sql = preg_replace( $pattern, "'\$1 \$2'::interval", $sql); - $pattern = '/DATE_SUB[ ]*\(([^,]+),([^\)]+)\)/'; - $sql = preg_replace( $pattern, '($1::timestamp - $2)', $sql); - - // Remove illegal characters - $sql = str_replace('`', '', $sql); - - // Field names with CAPITALS need special handling - if( false !== strpos($sql, 'ID')) - { - $pattern = '/ID([^ ])/'; - $sql = preg_replace($pattern, 'ID $1', $sql); - $pattern = '/ID$/'; - $sql = preg_replace($pattern, 'ID ', $sql); - $pattern = '/\(ID/'; - $sql = preg_replace($pattern, '( ID', $sql); - $pattern = '/,ID/'; - $sql = preg_replace($pattern, ', ID', $sql); - $pattern = '/[0-9a-zA-Z_]+ID/'; - $sql = preg_replace($pattern, '"$0"', $sql); - $pattern = '/\.ID/'; - $sql = preg_replace($pattern, '."ID"', $sql); - $pattern = '/[\s]ID /'; - $sql = preg_replace($pattern, ' "ID" ', $sql); - $pattern = '/"ID "/'; - $sql = preg_replace($pattern, ' "ID" ', $sql); - } // CAPITALS - - // Empty "IN" statements are erroneous - $sql = str_replace( 'IN (\'\')', 'IN (NULL)', $sql); - $sql = str_replace( 'IN ( \'\' )', 'IN (NULL)', $sql); - $sql = str_replace( 'IN ()', 'IN (NULL)', $sql); - - // Put back the end of the query if it was separated - $sql .= $end; - - // For insert ID catching - if( $logto == 'INSERT') - { - $pattern = '/INSERT INTO (\w+)\s+\([ a-zA-Z_"]+/'; - preg_match($pattern, $sql, $matches); - $GLOBALS['pg4wp_ins_table'] = $matches[1]; - $match_list = explode(' ', $matches[0]); - if( $GLOBALS['pg4wp_ins_table']) - { - $GLOBALS['pg4wp_ins_field'] = trim($match_list[3],' () '); - if(! $GLOBALS['pg4wp_ins_field']) - $GLOBALS['pg4wp_ins_field'] = trim($match_list[4],' () '); - } - $GLOBALS['pg4wp_last_insert'] = $sql; - } - elseif( isset($GLOBALS['pg4wp_queued_query'])) - { - pg_query($GLOBALS['pg4wp_queued_query']); - unset($GLOBALS['pg4wp_queued_query']); - } - - // Correct quoting for PostgreSQL 9.1+ compatibility - $sql = str_replace( "\\'", "''", $sql); - $sql = str_replace( '\"', '"', $sql); - - if( PG4WP_DEBUG) - { - if( $initial != $sql) - error_log( '['.microtime(true)."] Converting :\n$initial\n---- to ----\n$sql\n---------------------\n", 3, PG4WP_LOG.'pg4wp_'.$logto.'.log'); - else - error_log( '['.microtime(true)."] $sql\n---------------------\n", 3, PG4WP_LOG.'pg4wp_unmodified.log'); - } - return $sql; - } - - // Database initialization - function pg4wp_init() - { - // Provide (mostly) MySQL-compatible field function - // Note: MySQL accepts heterogeneous argument types. No easy fix. - // Can define version with typed first arg to cover some cases. - // Note: ROW_NUMBER+unnest doesn't guarantee order, but is simple/fast. - // If it breaks, try https://stackoverflow.com/a/8767450 - $result = pg_query($GLOBALS['pg4wp_conn'],<<If you want to do it anyway, please set "PG4WP_INSECURE" to true in your "db.php" file.'); + } + + // Must connect to a specific database unlike MySQL + $dbname = defined('DB_NAME') && DB_NAME ? DB_NAME : 'template1'; + return pg_connect($GLOBALS['pg4wp_connstr'] . ' dbname=' . $dbname); +} + +/** + * Establishes a connection to a PostgreSQL database. + * + * This function connects to a PostgreSQL database by creating a connection string and using + * pg_connect. If the connection is successful, it stores the PostgreSQL server version into + * a global variable. The function also handles early transmitted SQL commands and initializes + * the connection with pg4wp_init(). + * + * Note: Unlike the MySQL equivalent, pg_connect will return an existing connection if one + * exists with the same connection string. + * + * @param string $dbname The name of the database to connect to. + * @param int $connection_id The connection ID (Unused in this function). + * + * @return resource|bool The connection resource on success, or FALSE on failure. + */ +function wpsql_select_db($dbname, $connection_id = 0) +{ + $pg_connstr = $GLOBALS['pg4wp_connstr'] . ' dbname=' . $dbname; + + // pg_connect returns existing connection for same connection string + $GLOBALS['pg4wp_conn'] = $conn = pg_connect($pg_connstr); + + // Return FALSE if connection failed + if(!$conn) { + return $conn; + } + + // Get and store PostgreSQL server version + $ver = pg_version($conn); + if(isset($ver['server'])) { + $GLOBALS['pg4wp_version'] = $ver['server']; + } + + // Clear the connection string unless this is a test connection + if(!defined('WP_INSTALLING') || !WP_INSTALLING) { + $GLOBALS['pg4wp_connstr'] = ''; + } + + // Execute any pre-defined SQL commands + if(!empty($GLOBALS['pg4wp_pre_sql'])) { + foreach($GLOBALS['pg4wp_pre_sql'] as $sql2run) { + wpsql_query($sql2run); + } + } + + // Initialize connection with custom function + pg4wp_init($conn); + + return $conn; +} + +/** + * Initializes the database environment for pg4wp. + * + * This function sets up a MySQL-compatible `field` function in PostgreSQL. + * Note: In MySQL, the field function accepts arguments of heterogeneous types, + * but in PostgreSQL, it may not. + * + * Note: ROW_NUMBER()+unnest approach is used for performance but might not guarantee order. + * Refer to https://stackoverflow.com/a/8767450 if it breaks. + */ +function pg4wp_init() +{ + // Database connection + $connection = $GLOBALS['pg4wp_conn']; + + /** + * SQL query to create or replace a PostgreSQL function named "field" + * which imitates MySQL's FIELD() function behavior. + * + * - ROW_NUMBER() is a window function in Postgres, used to assign a unique integer to rows. + * - unnest() is a Postgres function that takes an array and returns a set of rows. + * + * The function takes anyelement as the first parameter and anyarray as the second. + * It returns a BIGINT. + * + * SQL is used as the procedural language, and the function is marked as IMMUTABLE. + */ + $sql = <<<'SQL' + CREATE OR REPLACE FUNCTION field(anyelement, VARIADIC anyarray) + RETURNS BIGINT AS $$ + SELECT rownum + FROM ( + SELECT ROW_NUMBER() OVER () AS rownum, elem + FROM unnest($2) elem + ) AS numbered + WHERE numbered.elem = $1 + UNION ALL + SELECT 0 + $$ + LANGUAGE SQL IMMUTABLE; + SQL; + + // Execute the SQL query + $result = pg_query($connection, $sql); + + if ((PG4WP_DEBUG || PG4WP_LOG_ERRORS) && $result === false) { + $error = pg_last_error(); + error_log("[" . microtime(true) . "] Error creating MySQL-compatible field function: $error\n", 3, PG4WP_LOG . 'pg4wp_errors.log'); + } +} + +/** + * Executes a SQL query on a Postgres database. + * + * This function handles the SQL query by executing it on a Postgres database, + * if the global connection is available. Otherwise, it stores the SQL + * statement for later execution. It also handles errors and debugging. + * + * @param string $sql The SQL query string. + * @return resource|bool The query result resource on success, or FALSE on failure. + * + * Differences from MySQL equivalents: + * - Uses pg_query() instead of mysql_query() for executing the query. + * - Error handling is done using pg_last_error() instead of mysql_error(). + * - SQL rewriting is performed by the pg4wp_rewrite() function. + */ +function wpsql_query($sql) +{ + // Check if a connection to Postgres database is established + if (!$GLOBALS['pg4wp_conn']) { + // Store SQL query for later execution when connection is available + $GLOBALS['pg4wp_pre_sql'][] = $sql; + return true; + } + + // Store the initial SQL query + $initial = $sql; + // Rewrite the SQL query for compatibility with Postgres + $sql = pg4wp_rewrite($sql); + + // Execute the SQL query and store the result + if (PG4WP_DEBUG) { + $GLOBALS['pg4wp_result'] = pg_query($GLOBALS['pg4wp_conn'], $sql); + } else { + $GLOBALS['pg4wp_result'] = @pg_query($GLOBALS['pg4wp_conn'], $sql); + } + + // Handle errors and logging + if ((PG4WP_DEBUG || PG4WP_LOG_ERRORS) && $GLOBALS['pg4wp_result'] === false && $err = pg_last_error($GLOBALS['pg4wp_conn'])) { + $ignore = false; + // Ignore errors if WordPress is in the installation process + if (defined('WP_INSTALLING') && WP_INSTALLING) { + global $table_prefix; + $ignore = strpos($err, 'relation "' . $table_prefix); + } + if (!$ignore) { + error_log('[' . microtime(true) . "] Error running :\n$initial\n---- converted to ----\n$sql\n----> $err\n---------------------\n", 3, PG4WP_LOG . 'pg4wp_errors.log'); + } + } + + // Return the query result + return $GLOBALS['pg4wp_result']; +} + +/** + * Fetches a result row as an associative and numeric array from a Postgres query result. + * + * This function calls the pg_fetch_array() function to fetch the next row from a Postgres result set + * and trims any leading or trailing whitespace from each of the values. + * + * Differences from MySQL Equivalent: + * 1. It uses pg_fetch_array() instead of mysql_fetch_array(). + * 2. It trims the values of the resulting array, which is specific to this implementation. + * + * @param resource $result The result resource returned by a Postgres query. + * @return array|bool An array of the next row in the result set, or false if there are no more rows. + */ +function wpsql_fetch_array($result) +{ + // Fetch the next row as an array + $res = pg_fetch_array($result); + + // Check if the result is an array and trim its values + if (is_array($res)) { + foreach ($res as $v => $k) { + $res[$v] = trim($k); + } + } + + // Return the trimmed array or false if there are no more rows + return $res; +} + +/** + * Fetches the ID generated for an AUTO_INCREMENT column by the previous INSERT query. + * + * @param resource|null $lnk A PostgreSQL connection resource. Default is `null`. + * + * @return mixed The ID generated for an AUTO_INCREMENT column by the previous INSERT query on success; `false` on failure. + * + * Note: + * 1. In PostgreSQL, this function uses CURRVAL() on the appropriate sequence to get the last inserted ID. + * 2. In MySQL, last inserted ID is generally fetched using mysql_insert_id() or mysqli_insert_id(). + */ +function wpsql_insert_id($lnk = null) +{ + global $wpdb; + $data = null; + $ins_field = $GLOBALS['pg4wp_ins_field']; + $table = $GLOBALS['pg4wp_ins_table']; + $lastq = $GLOBALS['pg4wp_last_insert']; + $seq = $table . '_seq'; + + // Special case for 'term_relationships' table, which does not have a sequence in PostgreSQL. + if ($table == $wpdb->term_relationships) { + // PostgreSQL: Using CURRVAL() to get the current value of the sequence. + $sql = "SELECT CURRVAL('$seq')"; + $res = pg_query($sql); + if (false !== $res) { + $data = pg_fetch_result($res, 0, 0); + } + } + // Special case when using WP_Import plugin where ID is defined in the query itself. + elseif ('post_author' == $ins_field && false !== strpos($lastq, 'ID')) { + // No PostgreSQL specific operation here. + $sql = 'ID was in query '; + $pattern = '/.+\'(\d+).+$/'; + preg_match($pattern, $lastq, $matches); + $data = $matches[1]; + + // PostgreSQL: Setting the value of the sequence based on the latest inserted ID. + $GLOBALS['pg4wp_queued_query'] = "SELECT SETVAL('$seq',(SELECT MAX(\"ID\") FROM $table)+1);"; + } else { + // PostgreSQL: Using CURRVAL() to get the current value of the sequence. + $sql = "SELECT CURRVAL('$seq')"; + $res = pg_query($GLOBALS['pg4wp_conn'], $sql); + if (false !== $res) { + $data = pg_fetch_result($res, 0, 0); + } elseif (PG4WP_DEBUG || PG4WP_LOG) { + $log = '[' . microtime(true) . "] wpsql_insert_id() was called with '$table' and '$ins_field'" . + " and returned the error:\n" . pg_last_error($GLOBALS['pg4wp_conn']) . + "\nFor the query:\n" . $sql . + "\nThe latest INSERT query was :\n'$lastq'\n"; + error_log($log, 3, PG4WP_LOG . 'pg4wp_errors.log'); + } + } + + if (PG4WP_DEBUG && $sql) { + error_log('[' . microtime(true) . "] Getting inserted ID for '$table' ('$ins_field') : $sql => $data\n", 3, PG4WP_LOG . 'pg4wp_insertid.log'); + } + + return $data; +} + +/** + * Fetch a specific result row's field value from a PostgreSQL result resource. + * Quick fix for wpsql_result() error and missing wpsql_errno() function + * Source : http://vitoriodelage.wordpress.com/2014/06/06/add-missing-wpsql_errno-in-pg4wp-plugin/ + * + * @param resource $result The Postgres query result resource. + * @param int $i The row number from which to get the value (0-based). + * @param string|null $fieldname Optional. The field name to fetch. + * + * @return mixed Field value or false if no such row exists. + * + * Note: + * 1. This function uses `pg_fetch_result` to get a single field's value from a row. + * 2. In MySQL, you could use `mysql_result` to accomplish something similar. + */ +function wpsql_result($result, $i, $fieldname = null) +{ + if (is_resource($result)) { + if ($fieldname) { + return pg_fetch_result($result, $i, $fieldname); + } else { + return pg_fetch_result($result, $i); + } + } +} + +/** + * Returns the SQLSTATE error code for the last query executed on the connection. + * + * @param resource $connection The Postgres database connection resource. + * + * @return string|false SQLSTATE error code or false if no error. + * + * Note: + * 1. This function uses `pg_get_result` to get the result resource of the last query. + * 2. `pg_result_status` returns the status of the result. + * 3. `pg_result_error_field` is used to get the SQLSTATE error code. + * 4. In MySQL, you could use `mysqli_errno` to get the error code directly. + */ +function wpsql_errno($connection) +{ + $result = pg_get_result($connection); + if ($result === false) { + return false; + } + + $result_status = pg_result_status($result); + return pg_result_error_field($result_status, PGSQL_DIAG_SQLSTATE); +} + + +/** + * Checks if a connection to a PostgreSQL database is alive. + * + * @param resource $conn The PostgreSQL connection resource. + * @return bool Returns true if the connection is alive, false otherwise. + */ +function wpsql_ping($conn) +{ + return pg_ping($conn); +} + +/** + * Gets the number of rows in a PostgreSQL result. + * + * @param resource $result The PostgreSQL result resource. + * @return int Returns the number of rows. + */ +function wpsql_num_rows($result) +{ + return pg_num_rows($result); +} + +/** + * Alias for wpsql_num_rows. Gets the number of rows in a PostgreSQL result. + * + * @param resource $result The PostgreSQL result resource. + * @return int Returns the number of rows. + */ +function wpsql_numrows($result) +{ + return pg_num_rows($result); +} + +/** + * Gets the number of fields in a PostgreSQL result. + * + * @param resource $result The PostgreSQL result resource. + * @return int Returns the number of fields. + */ +function wpsql_num_fields($result) +{ + return pg_num_fields($result); +} + +/** + * Mock function to mimic MySQL's fetch_field function. + * + * @param resource $result The PostgreSQL result resource. + * @return string Returns 'tablename' as a placeholder. + */ +function wpsql_fetch_field($result) +{ + return 'tablename'; +} + +/** + * Fetches one row from a PostgreSQL result as an object. + * + * @param resource $result The PostgreSQL result resource. + * @return object Returns an object containing the data. + */ +function wpsql_fetch_object($result) +{ + return pg_fetch_object($result); +} + +/** + * Frees a PostgreSQL result resource. + * + * @param resource $result The PostgreSQL result resource. + * @return bool Returns true on success, false otherwise. + */ +function wpsql_free_result($result) +{ + if ($result === null) { + return true; + } + + return pg_free_result($result); +} + +/** + * Gets the number of affected rows by the last PostgreSQL query. + * + * @return int Returns the number of affected rows. + */ +function wpsql_affected_rows() +{ + if($GLOBALS['pg4wp_result'] === false) { + return 0; + } + + return pg_affected_rows($GLOBALS['pg4wp_result']); +} + +/** + * Fetches one row from a PostgreSQL result as an enumerated array. + * + * @param resource $result The PostgreSQL result resource. + * @return array Returns an array containing the row data. + */ +function wpsql_fetch_row($result) +{ + return pg_fetch_row($result); +} + +/** + * Sets the row offset for a PostgreSQL result resource. + * + * @param resource $result The PostgreSQL result resource. + * @param int $offset The row offset. + * @return bool Returns true on success, false otherwise. + */ +function wpsql_data_seek($result, $offset) +{ + return pg_result_seek($result, $offset); +} + +/** + * Gets the last error message from a PostgreSQL connection. + * + * @return string Returns the error message. + */ +function wpsql_error() +{ + if($GLOBALS['pg4wp_conn']) { + return pg_last_error($GLOBALS['pg4wp_conn']); + } + + return ''; +} + +/** + * Fetches one row from a PostgreSQL result as an associative array. + * + * @param resource $result The PostgreSQL result resource. + * @return array Returns an associative array containing the row data. + */ +function wpsql_fetch_assoc($result) +{ + return pg_fetch_assoc($result); +} + +/** + * Escapes a string for use in a PostgreSQL query. + * + * @param string $s The string to escape. + * @return string Returns the escaped string. + */ +function wpsql_escape_string($s) +{ + return pg_escape_string($GLOBALS['pg4wp_conn'], $s); +} + +/** + * Escapes a string for use in a PostgreSQL query with a specified connection. + * + * @param string $s The string to escape. + * @param resource $c The PostgreSQL connection resource. + * @return string Returns the escaped string. + */ +function wpsql_real_escape_string($s, $c = null) +{ + return pg_escape_string($c, $s); +} + +/** + * Mock function to mimic MySQL's get_server_info function. + * + * @return string Returns '8.0.35' as a placeholder. + */ +function wpsql_get_server_info() +{ + return '8.0.35'; // Just want to fool wordpress ... +} + + +/** + * Mock function to mimic MySQL's get_client_info function. + * + * @return string Returns '8.0.35' as a placeholder. + */ +function wpsql_get_client_info() +{ + return '8.0.35'; // Just want to fool wordpress ... +} \ No newline at end of file diff --git a/pg4wp/driver_pgsql_rewrite.php b/pg4wp/driver_pgsql_rewrite.php new file mode 100644 index 0000000..8841a6c --- /dev/null +++ b/pg4wp/driver_pgsql_rewrite.php @@ -0,0 +1,204 @@ +rewrite(); + $logto = strtoupper($rewriter->type()); + switch ($rewriter->type()) { + case 'Update': + // This will avoid modifications to anything following ' SET ' + list($sql, $end) = explode(' SET ', $sql, 2); + $end = ' SET ' . $end; + break; + case 'Insert': + // This will avoid modifications to anything following ' VALUES' + list($sql, $end) = explode(' VALUES', $sql, 2); + $end = ' VALUES' . $end; + + // When installing, the sequence for table terms has to be updated + if(defined('WP_INSTALLING') && WP_INSTALLING && false !== strpos($sql, 'INSERT INTO `' . $wpdb->terms . '`')) { + $end .= ';SELECT setval(\'' . $wpdb->terms . '_seq\', (SELECT MAX(term_id) FROM ' . $wpdb->terms . ')+1);'; + } + break; + case 'Insert': + break; + default: + } + + $sql = loadInstallFunctions($sql, $logto); + $sql = correctMetaValue($sql); + $sql = handleInterval($sql); + $sql = cleanAndCapitalize($sql); + $sql = correctEmptyInStatements($sql); + $sql = correctQuoting($sql); + + // Put back the end of the query if it was separated + $sql .= $end; + + // For insert ID catching + if($logto == 'INSERT') { + $pattern = '/INSERT INTO (\w+)\s+\([ a-zA-Z_"]+/'; + preg_match($pattern, $sql, $matches); + $GLOBALS['pg4wp_ins_table'] = $matches[1]; + $match_list = explode(' ', $matches[0]); + if($GLOBALS['pg4wp_ins_table']) { + $GLOBALS['pg4wp_ins_field'] = trim($match_list[3], ' () '); + if(!$GLOBALS['pg4wp_ins_field']) { + $GLOBALS['pg4wp_ins_field'] = trim($match_list[4], ' () '); + } + } + $GLOBALS['pg4wp_last_insert'] = $sql; + } elseif(isset($GLOBALS['pg4wp_queued_query'])) { + pg_query($GLOBALS['pg4wp_queued_query']); + unset($GLOBALS['pg4wp_queued_query']); + } + + if(PG4WP_DEBUG) { + if($initial != $sql) { + error_log('[' . microtime(true) . "] Converting :\n$initial\n---- to ----\n$sql\n---------------------\n", 3, PG4WP_LOG . 'pg4wp_' . $logto . '.log'); + } else { + error_log('[' . microtime(true) . "] $sql\n---------------------\n", 3, PG4WP_LOG . 'pg4wp_unmodified.log'); + } + } + return $sql; +} + +/** + * Load upgrade and install functions as required. + * + * @param string $sql SQL query string + * @param string $logto Logging type + * @return string Modified SQL query string + */ +function loadInstallFunctions($sql, &$logto) +{ + $begin = strtoupper(substr($sql, 0, 3)); + $search = array('SHO', 'ALT', 'DES', 'CRE', 'DRO'); + if (in_array($begin, $search)) { + require_once(PG4WP_ROOT . '/driver_pgsql_install.php'); + $sql = pg4wp_installing($sql, $logto); + } + return $sql; +} + +/** + * Correct the meta_value field for WP 2.9.1 and add type cast. + * + * @param string $sql SQL query string + * @return string Modified SQL query string + */ +function correctMetaValue($sql) +{ + // WP 2.9.1 uses a comparison where text data is not quoted + $sql = preg_replace('/AND meta_value = (-?\d+)/', 'AND meta_value = \'$1\'', $sql); + // Add type cast for meta_value field when it's compared to number + $sql = preg_replace('/AND meta_value < (\d+)/', 'AND meta_value::bigint < $1', $sql); + return $sql; +} + +/** + * Handle interval expressions in SQL query. + * + * @param string $sql SQL query string + * @return string Modified SQL query string + */ +function handleInterval($sql) +{ + // Generic "INTERVAL xx YEAR|MONTH|DAY|HOUR|MINUTE|SECOND" handler + $sql = preg_replace('/INTERVAL[ ]+(\d+)[ ]+(YEAR|MONTH|DAY|HOUR|MINUTE|SECOND)/', "'\$1 \$2'::interval", $sql); + // DATE_SUB handling + $sql = preg_replace('/DATE_SUB[ ]*\(([^,]+),([^\)]+)\)/', '($1::timestamp - $2)', $sql); + return $sql; +} + +/** + * Clean SQL query from illegal characters and handle capitalization. + * + * @param string $sql SQL query string + * @return string Modified SQL query string + */ +function cleanAndCapitalize($sql) +{ + // Remove illegal characters + $sql = str_replace('`', '', $sql); + // Field names with CAPITALS need special handling + if (false !== strpos($sql, 'ID')) { + $patterns = [ + '/ID([^ ])/' => 'ID $1', + '/ID$/' => 'ID ', + '/\(ID/' => '( ID', + '/,ID/' => ', ID', + '/[0-9a-zA-Z_]+ID/' => '"$0"', + '/\.ID/' => '."ID"', + '/[\s]ID /' => ' "ID" ', + '/"ID "/' => ' "ID" ' + ]; + foreach ($patterns as $pattern => $replacement) { + $sql = preg_replace($pattern, $replacement, $sql); + } + } + return $sql; +} + +/** + * Correct empty IN statements in SQL query. + * + * @param string $sql SQL query string + * @return string Modified SQL query string + */ +function correctEmptyInStatements($sql) +{ + $search = ['IN (\'\')', 'IN ( \'\' )', 'IN ()']; + $replace = 'IN (NULL)'; + $sql = str_replace($search, $replace, $sql); + return $sql; +} + +/** + * Correct quoting for PostgreSQL 9.1+ compatibility. + * + * @param string $sql SQL query string + * @return string Modified SQL query string + */ +function correctQuoting($sql) +{ + $sql = str_replace("\\'", "''", $sql); + $sql = str_replace('\"', '"', $sql); + return $sql; +} diff --git a/pg4wp/rewriters/AbstractSQLRewriter.php b/pg4wp/rewriters/AbstractSQLRewriter.php new file mode 100644 index 0000000..020e72e --- /dev/null +++ b/pg4wp/rewriters/AbstractSQLRewriter.php @@ -0,0 +1,26 @@ +originalSQL = $sql; + } + + abstract public function rewrite(): string; + + public function original(): string + { + return $this->originalSQL; + } + + public function type(): string + { + // Get the called class name and remove the "SQLRewriter" suffix to get the SQL type + $className = get_called_class(); + $type = str_replace('SQLRewriter', '', $className); + return $type; + } +} diff --git a/pg4wp/rewriters/DeleteSQLRewriter.php b/pg4wp/rewriters/DeleteSQLRewriter.php new file mode 100644 index 0000000..32eae3b --- /dev/null +++ b/pg4wp/rewriters/DeleteSQLRewriter.php @@ -0,0 +1,60 @@ +original(); + + // ORDER BY is not supported in DELETE queries, and not required + // when LIMIT is not present + if(false !== strpos($sql, 'ORDER BY') && false === strpos($sql, 'LIMIT')) { + $pattern = '/ORDER BY \S+ (ASC|DESC)?/'; + $sql = preg_replace($pattern, '', $sql); + } + + // LIMIT is not allowed in DELETE queries + $sql = str_replace('LIMIT 1', '', $sql); + $sql = str_replace(' REGEXP ', ' ~ ', $sql); + + // This handles removal of duplicate entries in table options + if(false !== strpos($sql, 'DELETE o1 FROM ')) { + $sql = "DELETE FROM $wpdb->options WHERE option_id IN " . + "(SELECT o1.option_id FROM $wpdb->options AS o1, $wpdb->options AS o2 " . + "WHERE o1.option_name = o2.option_name " . + "AND o1.option_id < o2.option_id)"; + } + // Rewrite _transient_timeout multi-table delete query + elseif(0 === strpos($sql, 'DELETE a, b FROM wp_options a, wp_options b')) { + $where = substr($sql, strpos($sql, 'WHERE ') + 6); + $where = rtrim($where, " \t\n\r;"); + // Fix string/number comparison by adding check and cast + $where = str_replace('AND b.option_value', 'AND b.option_value ~ \'^[0-9]+$\' AND CAST(b.option_value AS BIGINT)', $where); + // Mirror WHERE clause to delete both sides of self-join. + $where2 = strtr($where, array('a.' => 'b.', 'b.' => 'a.')); + $sql = 'DELETE FROM wp_options a USING wp_options b WHERE ' . + '(' . $where . ') OR (' . $where2 . ');'; + } + + // Rewrite _transient_timeout multi-table delete query + elseif(0 === strpos($sql, 'DELETE a, b FROM wp_sitemeta a, wp_sitemeta b')) { + $where = substr($sql, strpos($sql, 'WHERE ') + 6); + $where = rtrim($where, " \t\n\r;"); + // Fix string/number comparison by adding check and cast + $where = str_replace('AND b.meta_value', 'AND b.meta_value ~ \'^[0-9]+$\' AND CAST(b.meta_value AS BIGINT)', $where); + // Mirror WHERE clause to delete both sides of self-join. + $where2 = strtr($where, array('a.' => 'b.', 'b.' => 'a.')); + $sql = 'DELETE FROM wp_sitemeta a USING wp_sitemeta b WHERE ' . + '(' . $where . ') OR (' . $where2 . ');'; + } + + // Akismet sometimes doesn't write 'comment_ID' with 'ID' in capitals where needed ... + if(false !== strpos($sql, $wpdb->comments)) { + $sql = str_replace(' comment_id ', ' comment_ID ', $sql); + } + + return $sql; + } +} diff --git a/pg4wp/rewriters/InsertSQLRewriter.php b/pg4wp/rewriters/InsertSQLRewriter.php new file mode 100644 index 0000000..81f8d74 --- /dev/null +++ b/pg4wp/rewriters/InsertSQLRewriter.php @@ -0,0 +1,124 @@ +original(); + + $sql = str_replace('(0,', "('0',", $sql); + $sql = str_replace('(1,', "('1',", $sql); + + // Fix inserts into wp_categories + if(false !== strpos($sql, 'INSERT INTO ' . $wpdb->categories)) { + $sql = str_replace('"cat_ID",', '', $sql); + $sql = str_replace("VALUES ('0',", "VALUES(", $sql); + } + + // Those are used when we need to set the date to now() in gmt time + $sql = str_replace("'0000-00-00 00:00:00'", 'now() AT TIME ZONE \'gmt\'', $sql); + + // Multiple values group when calling INSERT INTO don't always work + if(false !== strpos($sql, $wpdb->options) && false !== strpos($sql, '), (')) { + $pattern = '/INSERT INTO.+VALUES/'; + preg_match($pattern, $sql, $matches); + $insert = $matches[0]; + $sql = str_replace('), (', ');' . $insert . '(', $sql); + } + + // Swap ON DUPLICATE KEY SYNTAX + if(false !== $pos = strpos($sql, 'ON DUPLICATE KEY UPDATE')) { + $splitStatements = function (string $sql): array { + $statements = []; + $buffer = ''; + $quote = null; + + for ($i = 0, $len = strlen($sql); $i < $len; $i++) { + $char = $sql[$i]; + + if ($quote) { + if ($char === $quote && $sql[$i - 1] !== '\\') { + $quote = null; + } + } elseif ($char === '"' || $char === "'") { + $quote = $char; + } elseif ($char === ';') { + $statements[] = $buffer . ';'; + $buffer = ''; + continue; + } + + $buffer .= $char; + } + + if (!empty($buffer)) { + $statements[] = $buffer; + } + + return $statements; + }; + + $statements = $splitStatements($sql); + + foreach ($statements as $statement) { + $statement = trim($statement); + + // Skip empty statements + if (empty($statement)) { + continue; + } + + // Replace backticks with double quotes for PostgreSQL compatibility + $statement = str_replace('`', '"', $statement); + + // Find index positions for the SQL components + $insertIndex = strpos($statement, 'INSERT INTO'); + $valuesIndex = strpos($statement, 'VALUES'); + $onDuplicateKeyIndex = strpos($statement, 'ON DUPLICATE KEY UPDATE'); + + // Extract SQL components + $tableSection = trim(substr($statement, $insertIndex, $valuesIndex - $insertIndex)); + $valuesSection = trim(substr($statement, $valuesIndex, $onDuplicateKeyIndex - $valuesIndex)); + $updateSection = trim(str_replace('ON DUPLICATE KEY UPDATE', '', substr($statement, $onDuplicateKeyIndex))); + + // Extract and clean up column names from the update section + $updateCols = explode(',', $updateSection); + $updateCols = array_map(function ($col) { + return trim(explode('=', $col)[0]); + }, $updateCols); + + // Choose a primary key for ON CONFLICT + $primaryKey = 'option_name'; + if (!in_array($primaryKey, $updateCols)) { + $primaryKey = 'meta_name'; + if (!in_array($primaryKey, $updateCols)) { + $primaryKey = $updateCols[0] ?? ''; + } + } + + // Construct the PostgreSQL ON CONFLICT DO UPDATE section + $updateSection = implode(', ', array_map(fn($col) => "$col = EXCLUDED.$col", $updateCols)); + + // Construct the PostgreSQL query + $postgresSQL = sprintf('%s %s ON CONFLICT (%s) DO UPDATE SET %s', $tableSection, $valuesSection, $primaryKey, $updateSection); + + // Append to the converted statements list + $convertedStatements[] = $postgresSQL; + } + + $sql = implode('; ', $convertedStatements); + } elseif(0 === strpos($sql, 'INSERT IGNORE')) { + // Note: Requires PostgreSQL 9.5 + $sql = 'INSERT' . substr($sql, 13) . ' ON CONFLICT DO NOTHING'; + } + + // To avoid Encoding errors when inserting data coming from outside + if(preg_match('/^.{1}/us', $sql, $ar) != 1) { + $sql = utf8_encode($sql); + } + + return $sql; + } +} diff --git a/pg4wp/rewriters/OptimizeTableSQLRewriter.php b/pg4wp/rewriters/OptimizeTableSQLRewriter.php new file mode 100644 index 0000000..1ce2c9e --- /dev/null +++ b/pg4wp/rewriters/OptimizeTableSQLRewriter.php @@ -0,0 +1,10 @@ +original(); + return str_replace('OPTIMIZE TABLE', 'VACUUM', $sql); + } +} diff --git a/pg4wp/rewriters/SelectSQLRewriter.php b/pg4wp/rewriters/SelectSQLRewriter.php new file mode 100644 index 0000000..6f68f17 --- /dev/null +++ b/pg4wp/rewriters/SelectSQLRewriter.php @@ -0,0 +1,324 @@ +original(); + + // SQL_CALC_FOUND_ROWS doesn't exist in PostgreSQL but it's needed for correct paging + if(false !== strpos($sql, 'SQL_CALC_FOUND_ROWS')) { + $sql = str_replace('SQL_CALC_FOUND_ROWS', '', $sql); + $GLOBALS['pg4wp_numrows_query'] = $sql; + if(PG4WP_DEBUG) { + error_log('[' . microtime(true) . "] Number of rows required for :\n$sql\n---------------------\n", 3, PG4WP_LOG . 'pg4wp_NUMROWS.log'); + } + } + + if(false !== strpos($sql, 'FOUND_ROWS()')) { + // Here we convert the latest query into a COUNT query + $sql = $GLOBALS['pg4wp_numrows_query']; + + // Remove the LIMIT clause if it exists + $sql = preg_replace('/\s+LIMIT\s+\d+(\s*,\s*\d+)?/i', '', $sql); + + // Remove the ORDER BY clause if it exists + $sql = preg_replace('/\s+ORDER\s+BY\s+[^)]+/i', '', $sql); + + // Replace the fields in the SELECT clause with COUNT(*) + $sql = preg_replace('/SELECT\s+.*?\s+FROM\s+/is', 'SELECT COUNT(*) FROM ', $sql, 1); + } + + $sql = $this->ensureOrderByInSelect($sql); + + // Convert CONVERT to CAST + $pattern = '/CONVERT\(([^()]*(\(((?>[^()]+)|(?-2))*\))?[^()]*),\s*([^\s]+)\)/x'; + $sql = preg_replace($pattern, 'CAST($1 AS $4)', $sql); + + // Handle CAST( ... AS CHAR) + $sql = preg_replace('/CAST\((.+) AS CHAR\)/', 'CAST($1 AS TEXT)', $sql); + + // Handle CAST( ... AS SIGNED) + $sql = preg_replace('/CAST\((.+) AS SIGNED\)/', 'CAST($1 AS INTEGER)', $sql); + + // Handle COUNT(*)...ORDER BY... + $sql = preg_replace('/COUNT(.+)ORDER BY.+/s', 'COUNT$1', $sql); + + // In order for users counting to work... + $matches = array(); + if(preg_match_all('/COUNT[^C]+\),/', $sql, $matches)) { + foreach($matches[0] as $num => $one) { + $sub = substr($one, 0, -1); + $sql = str_replace($sub, $sub . ' AS count' . $num, $sql); + } + } + + $sql = $this->convertToPostgresLimitSyntax($sql); + $sql = $this->ensureGroupByOrAggregate($sql); + + $pattern = '/DATE_ADD[ ]*\(([^,]+),([^\)]+)\)/'; + $sql = preg_replace($pattern, '($1 + $2)', $sql); + + // Convert MySQL FIELD function to CASE statement + $pattern = '/FIELD[ ]*\(([^\),]+),([^\)]+)\)/'; + // https://dev.mysql.com/doc/refman/5.7/en/string-functions.html#function_field + // Other implementations: https://stackoverflow.com/q/1309624 + $sql = preg_replace_callback($pattern, function ($matches) { + $case = 'CASE ' . trim($matches[1]); + $comparands = explode(',', $matches[2]); + foreach($comparands as $i => $comparand) { + $case .= ' WHEN ' . trim($comparand) . ' THEN ' . ($i + 1); + } + $case .= ' ELSE 0 END'; + return $case; + }, $sql); + + $pattern = '/GROUP_CONCAT\(([^()]*(\(((?>[^()]+)|(?-2))*\))?[^()]*)\)/x'; + $sql = preg_replace($pattern, "string_agg($1, ',')", $sql); + + // Convert MySQL RAND function to PostgreSQL RANDOM function + $pattern = '/RAND[ ]*\([ ]*\)/'; + $sql = preg_replace($pattern, 'RANDOM()', $sql); + + // UNIX_TIMESTAMP in MYSQL returns an integer + $pattern = '/UNIX_TIMESTAMP\(([^\)]+)\)/'; + $sql = preg_replace($pattern, 'ROUND(DATE_PART(\'epoch\',$1))', $sql); + + $date_funcs = array( + 'DAYOFMONTH(' => 'EXTRACT(DAY FROM ', + 'YEAR(' => 'EXTRACT(YEAR FROM ', + 'MONTH(' => 'EXTRACT(MONTH FROM ', + 'DAY(' => 'EXTRACT(DAY FROM ', + ); + + $sql = str_replace('ORDER BY post_date DESC', 'ORDER BY YEAR(post_date) DESC, MONTH(post_date) DESC', $sql); + $sql = str_replace('ORDER BY post_date ASC', 'ORDER BY YEAR(post_date) ASC, MONTH(post_date) ASC', $sql); + $sql = str_replace(array_keys($date_funcs), array_values($date_funcs), $sql); + $curryear = date('Y'); + $sql = str_replace('FROM \'' . $curryear, 'FROM TIMESTAMP \'' . $curryear, $sql); + + // MySQL 'IF' conversion - Note : NULLIF doesn't need to be corrected + $pattern = '/ (?prefix . 'posts.ID', '', $sql); + } + $sql = str_replace("!= ''", '<> 0', $sql); + + // MySQL 'LIKE' is case insensitive by default, whereas PostgreSQL 'LIKE' is + $sql = str_replace(' LIKE ', ' ILIKE ', $sql); + + // INDEXES are not yet supported + if(false !== strpos($sql, 'USE INDEX (comment_date_gmt)')) { + $sql = str_replace('USE INDEX (comment_date_gmt)', '', $sql); + } + + // HB : timestamp fix for permalinks + $sql = str_replace('post_date_gmt > 1970', 'post_date_gmt > to_timestamp (\'1970\')', $sql); + + // Akismet sometimes doesn't write 'comment_ID' with 'ID' in capitals where needed ... + if(isset($wpdb) && $wpdb->comments && false !== strpos($sql, $wpdb->comments)) { + $sql = str_replace(' comment_id ', ' comment_ID ', $sql); + } + + // MySQL treats a HAVING clause without GROUP BY like WHERE + if(false !== strpos($sql, 'HAVING') && false === strpos($sql, 'GROUP BY')) { + if(false === strpos($sql, 'WHERE')) { + $sql = str_replace('HAVING', 'WHERE', $sql); + } else { + $pattern = '/WHERE\s+(.*?)\s+HAVING\s+(.*?)(\s*(?:ORDER|LIMIT|PROCEDURE|INTO|FOR|LOCK|$))/'; + $sql = preg_replace($pattern, 'WHERE ($1) AND ($2) $3', $sql); + } + } + + // MySQL allows integers to be used as boolean expressions + // where 0 is false and all other values are true. + // + // Although this could occur anywhere with any number, so far it + // has only been observed as top-level expressions in the WHERE + // clause and only with 0. For performance, limit current + // replacements to that. + $pattern_after_where = '(?:\s*$|\s+(GROUP|HAVING|ORDER|LIMIT|PROCEDURE|INTO|FOR|LOCK))'; + $pattern = '/(WHERE\s+)0(\s+AND|\s+OR|' . $pattern_after_where . ')/'; + $sql = preg_replace($pattern, '$1false$2', $sql); + + $pattern = '/(AND\s+|OR\s+)0(' . $pattern_after_where . ')/'; + $sql = preg_replace($pattern, '$1false$2', $sql); + + // MySQL supports strings as names, PostgreSQL needs identifiers. + // Limit to after closing parenthesis to reduce false-positives + // Currently only an issue for nextgen-gallery plugin + $pattern = '/\) AS \'([^\']+)\'/'; + $sql = preg_replace($pattern, ') AS "$1"', $sql); + + return $sql; + } + + /** + * Ensure the columns used in the ORDER BY clause are also present in the SELECT clause. + * + * @param string $sql Original SQL query string. + * @return string Modified SQL query string. + */ + protected function ensureOrderByInSelect(string $sql): string + { + // Extract the SELECT and ORDER BY clauses + preg_match('/SELECT\s+(.*?)\s+FROM/si', $sql, $selectMatches); + preg_match('/ORDER BY(.*?)(ASC|DESC|$)/si', $sql, $orderMatches); + preg_match('/GROUP BY(.*?)(ASC|DESC|$)/si', $sql, $groupMatches); + + // If the SELECT clause is missing, return the original query + if (!$selectMatches) { + return $sql; + } + + // If both ORDER BY and GROUP BY clauses are missing, return the original query + if (!$orderMatches && !$groupMatches) { + return $sql; + } + + $selectClause = trim($selectMatches[1]); + $orderByClause = $orderMatches ? trim($orderMatches[1]) : null; + $groupClause = $groupMatches ? trim($groupMatches[1]) : null; + $modified = false; + + // Check for wildcard in SELECT + if (strpos($selectClause, '*') !== false) { + return $sql; // Cannot handle wildcards, return original query + } + + // Handle ORDER BY columns + if ($orderByClause) { + $orderByColumns = explode(',', $orderByClause); + foreach ($orderByColumns as $col) { + $col = trim($col); + if (strpos($selectClause, $col) === false) { + $selectClause .= ', ' . $col; + $modified = true; + } + } + } + + // Handle GROUP BY columns + if ($groupClause && !$modified) { + $groupColumns = explode(',', $groupClause); + foreach ($groupColumns as $col) { + $col = trim($col); + if (strpos($selectClause, $col) === false) { + $selectClause .= ', ' . $col; + $modified = true; + } + } + } + + if (!$modified) { + return $sql; + } + + // Find the exact position for the replacement + $selectStartPos = strpos($sql, $selectMatches[1]); + if ($selectStartPos === false) { + return $sql; // If for some reason the exact match is not found, return the original query + } + $postgresSql = substr_replace($sql, $selectClause, $selectStartPos, strlen($selectMatches[1])); + + return $postgresSql; + } + + protected function ensureGroupByOrAggregate(string $sql): string + { + // Check for system or session variables + if (preg_match('/@@[a-zA-Z0-9_]+/', $sql)) { + return $sql; + } + + // Regular expression to capture main SQL components + $regex = '/(SELECT\s+)(.*?)(\s+FROM\s+)([^ ]+)(\s+WHERE\s+.*?(?= ORDER BY | GROUP BY | LIMIT |$))?(ORDER BY.*?(?= LIMIT |$))?(LIMIT.*?$)?/is'; + + // Capture main SQL components using regex + if (!preg_match($regex, $sql, $matches)) { + return $sql; + } + + $selectClause = $matches[2] ?? ''; + $fromClause = $matches[4] ?? ''; + $whereClause = $matches[5] ?? ''; + $orderClause = $matches[6] ?? ''; + $limitClause = $matches[7] ?? ''; + + if (empty($selectClause) || empty($fromClause)) { + return $sql; + } + + $columns = explode(',', $selectClause); + $aggregateColumns = []; + $nonAggregateColumns = []; + + foreach ($columns as $col) { + $col = trim($col); + if (preg_match('/(COUNT|SUM|AVG|MIN|MAX)\s*?\(/i', $col)) { + $aggregateColumns[] = $col; + } else { + $nonAggregateColumns[] = $col; + } + } + + // Only add a GROUP BY clause if there are both aggregate and non-aggregate columns in SELECT + if (empty($aggregateColumns) || empty($nonAggregateColumns)) { + return $sql; + } + + $groupByClause = "GROUP BY " . implode(", ", $nonAggregateColumns); + + // Assemble new SQL query + $postgresSql = "SELECT $selectClause FROM $fromClause"; + + if (!empty(trim($whereClause))) { + $postgresSql .= " $whereClause"; + } + + $postgresSql .= " $groupByClause"; + + if (!empty(trim($orderClause))) { + $postgresSql .= " $orderClause"; + } + + if (!empty(trim($limitClause))) { + $postgresSql .= " $limitClause"; + } + + return $postgresSql; + } + + /** + * Convert MySQL LIMIT syntax to PostgreSQL LIMIT syntax + * + * @param string $sql MySQL query string + * @return string PostgreSQL query string + */ + protected function convertToPostgresLimitSyntax($sql) + { + // Use regex to find "LIMIT m, n" syntax in query + if (preg_match('/LIMIT\s+(\d+),\s*(\d+)/i', $sql, $matches)) { + $offset = $matches[1]; + $limit = $matches[2]; + + // Replace MySQL LIMIT syntax with PostgreSQL LIMIT syntax + $postgresLimitSyntax = "LIMIT $limit OFFSET $offset"; + $postgresSql = preg_replace('/LIMIT\s+\d+,\s*\d+/i', $postgresLimitSyntax, $sql); + + return $postgresSql; + } + + // Return original query if no MySQL LIMIT syntax is found + return $sql; + } + +} diff --git a/pg4wp/rewriters/SetNamesSQLRewriter.php b/pg4wp/rewriters/SetNamesSQLRewriter.php new file mode 100644 index 0000000..d378cc9 --- /dev/null +++ b/pg4wp/rewriters/SetNamesSQLRewriter.php @@ -0,0 +1,9 @@ +original(); + $table = $this->extractTableNameFromShowColumns($sql); + return $this->generatePostgresShowColumns($table); + } + + /** + * Extracts table name from a "SHOW FULL COLUMNS" SQL statement. + * + * @param string $sql The SQL statement + * @return string|null The table name if found, or null otherwise + */ + protected function extractTableNameFromShowColumns($sql) { + $pattern = "/SHOW FULL COLUMNS FROM ['\"`]?([^'\"`]+)['\"`]?/i"; + if (preg_match($pattern, $sql, $matches)) { + return $matches[1]; + } + return null; + } + + /** + * Generates a PostgreSQL-compatible SQL query to mimic MySQL's "SHOW FULL COLUMNS". + * + * @param string $tableName The table name + * @return string The generated SQL query + */ + function generatePostgresShowColumns($tableName) { + $sql = << 0 + AND NOT a.attisdropped + AND a.attrelid = ( + SELECT c.oid + FROM pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = '$tableName' + AND n.nspname = 'public' + ) + ORDER BY + a.attnum; + SQL; + + return $sql; + } +} diff --git a/pg4wp/rewriters/ShowTablesSQLRewriter.php b/pg4wp/rewriters/ShowTablesSQLRewriter.php new file mode 100644 index 0000000..39bf255 --- /dev/null +++ b/pg4wp/rewriters/ShowTablesSQLRewriter.php @@ -0,0 +1,9 @@ +original(); + + $pattern = '/LIMIT[ ]+\d+/'; + $sql = preg_replace($pattern, '', $sql); + + // Fix update wp_options + $pattern = "/UPDATE `wp_options` SET `option_value` = NULL WHERE `option_name` = '(.+)'/"; + $match = "UPDATE `wp_options` SET `option_value` = '' WHERE `option_name` = '$1'"; + $sql = preg_replace($pattern, $match, $sql); + + // For correct bactick removal + $pattern = '/[ ]*`([^` ]+)`[ ]*=/'; + $sql = preg_replace($pattern, ' $1 =', $sql); + + // Those are used when we need to set the date to now() in gmt time + $sql = str_replace("'0000-00-00 00:00:00'", 'now() AT TIME ZONE \'gmt\'', $sql); + + // For correct ID quoting + $pattern = '/(,|\s)[ ]*([^ \']*ID[^ \']*)[ ]*=/'; + $sql = preg_replace($pattern, '$1 "$2" =', $sql); + + return $sql; + } +}