Skip to content

Instantly share code, notes, and snippets.

@adamziel
Last active February 7, 2023 17:50
Show Gist options
  • Save adamziel/d4d2f335a7671054d9ccee8d723ec0e8 to your computer and use it in GitHub Desktop.
Save adamziel/d4d2f335a7671054d9ccee8d723ec0e8 to your computer and use it in GitHub Desktop.
POC: CREATE TABLE translation MySQL -> SQLite with SqlParser
<?php
// require autoload
use PhpMyAdmin\SqlParser\Context;
use PhpMyAdmin\SqlParser\Components\CreateDefinition;
use PhpMyAdmin\SqlParser\Components\DataType;
use PhpMyAdmin\SqlParser\Statements\CreateStatement;
require_once __DIR__.'/../vendor/autoload.php';
function queries() {
$fp = fopen(__DIR__.'/wp-phpunit.sql', 'r');
// Read $fp line by line. Extract an array of multiline Queries. Queries are delimited by /* \d+ */
$buf = '';
while ($line = fgets($fp)) {
if (1 === preg_match('/^\/\* [0-9]+ \*\//', $line)) {
if(trim($buf)) {
yield trim($buf);
}
$buf = substr($line, strpos($line, '*/') + 2);
}
else {
$buf .= $line;
}
}
fclose($fp);
}
// Create fulltext index -> select 1=1;
// Remove: collate / default character set
//
$field_types_translation = [
'bit' => 'integer',
'bool' => 'integer',
'boolean' => 'integer',
'tinyint' => 'integer',
'smallint' => 'integer',
'mediumint' => 'integer',
'int' => 'integer',
'integer' => 'integer',
'bigint' => 'integer',
'float' => 'real',
'double' => 'real',
'decimal' => 'real',
'dec' => 'real',
'numeric' => 'real',
'fixed' => 'real',
'date' => 'text',
'datetime' => 'text',
'timestamp' => 'text',
'time' => 'text',
'year' => 'text',
'char' => 'text',
'varchar' => 'text',
'binary' => 'integer',
'varbinary' => 'blob',
'tinyblob' => 'blob',
'tinytext' => 'text',
'blob' => 'blob',
'text' => 'text',
'mediumblob' => 'blob',
'mediumtext' => 'text',
'longblob' => 'blob',
'longtext' => 'text',
];
$sqlite = new PDO('sqlite::memory:');
foreach(queries() as $k=>$query) {
$tokens = \PhpMyAdmin\SqlParser\Lexer::getTokens($query);
$token = $tokens->getNext();
if($token->value !== 'CREATE') {
continue;
}
echo '**MySQL query:**'.PHP_EOL;
echo $query.PHP_EOL.PHP_EOL;
$p = new \PhpMyAdmin\SqlParser\Parser($query);
$stmt = $p->statements[0];
$stmt->entityOptions->options = array();
$inline_primary_key = false;
$extra_queries = array();;
foreach($stmt->fields as $k=>$field) {
if($field->type && $field->type->name) {
$typelc = strtolower($field->type->name);
if(isset($field_types_translation[$typelc])) {
$field->type->name = $field_types_translation[$typelc];
}
$field->type->parameters = array();
unset($field->type->options->options[DataType::$DATA_TYPE_OPTIONS['UNSIGNED']]);
}
if($field->options && $field->options->options) {
if(isset($field->options->options[CreateDefinition::$FIELD_OPTIONS['AUTO_INCREMENT']])) {
$field->options->options[CreateDefinition::$FIELD_OPTIONS['AUTO_INCREMENT']] = 'PRIMARY KEY AUTOINCREMENT';
$inline_primary_key = true;
unset($field->options->options[CreateDefinition::$FIELD_OPTIONS['PRIMARY KEY']]);
}
}
if($field->key) {
if($field->key->type === 'PRIMARY KEY'){
if($inline_primary_key) {
unset($stmt->fields[$k]);
}
} else if($field->key->type === 'KEY' || $field->key->type === 'UNIQUE KEY'){
$columns = array();
foreach($field->key->columns as $column) {
$columns[] = $column['name'];
}
$unique = "";
if($field->key->type === 'UNIQUE KEY') {
$unique = "UNIQUE ";
}
$extra_queries[] = 'CREATE '.$unique.' INDEX "'.$stmt->name.'__'.$field->key->name.'" ON "'.$stmt->name.'" ("'.implode('", "', $columns).'")';
unset($stmt->fields[$k]);
}
}
}
Context::setMode(Context::SQL_MODE_ANSI_QUOTES);
$updated_query = $stmt->build();
echo '**SQLite queries:**'.PHP_EOL;
echo $updated_query . PHP_EOL;
$sqlite->exec($updated_query);
foreach($extra_queries as $query) {
echo $query . PHP_EOL . PHP_EOL;
$sqlite->exec($query);
}
echo '--------------------'.PHP_EOL.PHP_EOL;
}
**MySQL query:**
CREATE TABLE wptests_users (
ID bigint(20) unsigned NOT NULL auto_increment,
user_login varchar(60) NOT NULL default '',
`user_pass` varchar(255) NOT NULL default '',
user_nicename varchar(50) NOT NULL default '',
user_email varchar(100) NOT NULL default '',
user_url varchar(100) NOT NULL default '',
user_registered datetime NOT NULL default '0000-00-00 00:00:00',
user_activation_key varchar(255) NOT NULL default '',
user_status int(11) NOT NULL default '0',
display_name varchar(250) NOT NULL default '',
PRIMARY KEY (ID),
KEY user_login_key (user_login),
KEY user_nicename (user_nicename),
KEY user_email (user_email)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_users (
"user_login" text NOT NULL DEFAULT '',
"user_pass" text NOT NULL DEFAULT '',
"user_nicename" text NOT NULL DEFAULT '',
"user_email" text NOT NULL DEFAULT '',
"user_url" text NOT NULL DEFAULT '',
"user_registered" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"user_activation_key" text NOT NULL DEFAULT '',
"user_status" integer NOT NULL DEFAULT '0',
"display_name" text NOT NULL DEFAULT ''
)
CREATE INDEX "wptests_users__user_login_key" ON "wptests_users" ("user_login")
CREATE INDEX "wptests_users__user_nicename" ON "wptests_users" ("user_nicename")
CREATE INDEX "wptests_users__user_email" ON "wptests_users" ("user_email")
--------------------
**MySQL query:**
CREATE TABLE wptests_usermeta (
umeta_id bigint(20) unsigned NOT NULL auto_increment,
user_id bigint(20) unsigned NOT NULL default '0',
meta_key varchar(255) default NULL,
meta_value longtext,
PRIMARY KEY (umeta_id),
KEY user_id (user_id),
KEY meta_key (meta_key(191))
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_usermeta (
"user_id" integer NOT NULL DEFAULT '0',
"meta_key" text DEFAULT NULL,
"meta_value" text
)
CREATE INDEX "wptests_usermeta__user_id" ON "wptests_usermeta" ("user_id")
CREATE INDEX "wptests_usermeta__meta_key" ON "wptests_usermeta" ("meta_key")
--------------------
**MySQL query:**
CREATE TABLE wptests_termmeta (
meta_id bigint(20) unsigned NOT NULL auto_increment,
term_id bigint(20) unsigned NOT NULL default '0',
meta_key varchar(255) default NULL,
meta_value longtext,
PRIMARY KEY (meta_id),
KEY term_id (term_id),
KEY meta_key (meta_key(191))
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_termmeta (
"term_id" integer NOT NULL DEFAULT '0',
"meta_key" text DEFAULT NULL,
"meta_value" text
)
CREATE INDEX "wptests_termmeta__term_id" ON "wptests_termmeta" ("term_id")
CREATE INDEX "wptests_termmeta__meta_key" ON "wptests_termmeta" ("meta_key")
--------------------
**MySQL query:**
CREATE TABLE wptests_terms (
term_id bigint(20) unsigned NOT NULL auto_increment,
name varchar(200) NOT NULL default '',
slug varchar(200) NOT NULL default '',
term_group bigint(10) NOT NULL default 0,
PRIMARY KEY (term_id),
KEY slug (slug(191)),
KEY name (name(191))
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_terms (
"name" text NOT NULL DEFAULT '',
"slug" text NOT NULL DEFAULT '',
"term_group" integer NOT NULL DEFAULT 0
)
CREATE INDEX "wptests_terms__slug" ON "wptests_terms" ("slug")
CREATE INDEX "wptests_terms__name" ON "wptests_terms" ("name")
--------------------
**MySQL query:**
CREATE TABLE wptests_term_taxonomy (
term_taxonomy_id bigint(20) unsigned NOT NULL auto_increment,
term_id bigint(20) unsigned NOT NULL default 0,
taxonomy varchar(32) NOT NULL default '',
description longtext NOT NULL,
parent bigint(20) unsigned NOT NULL default 0,
count bigint(20) NOT NULL default 0,
PRIMARY KEY (term_taxonomy_id),
UNIQUE KEY term_id_taxonomy (term_id,taxonomy),
KEY taxonomy (taxonomy)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_term_taxonomy (
"term_id" integer NOT NULL DEFAULT 0,
"taxonomy" text NOT NULL DEFAULT '',
"description" text NOT NULL,
"parent" integer NOT NULL DEFAULT 0,
"count" integer NOT NULL DEFAULT 0
)
CREATE UNIQUE INDEX "wptests_term_taxonomy__term_id_taxonomy" ON "wptests_term_taxonomy" ("term_id", "taxonomy")
CREATE INDEX "wptests_term_taxonomy__taxonomy" ON "wptests_term_taxonomy" ("taxonomy")
--------------------
**MySQL query:**
CREATE TABLE wptests_term_relationships (
object_id bigint(20) unsigned NOT NULL default 0,
term_taxonomy_id bigint(20) unsigned NOT NULL default 0,
term_order int(11) NOT NULL default 0,
PRIMARY KEY (object_id,term_taxonomy_id),
KEY term_taxonomy_id (term_taxonomy_id)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_term_relationships (
"object_id" integer NOT NULL DEFAULT 0,
"term_taxonomy_id" integer NOT NULL DEFAULT 0,
"term_order" integer NOT NULL DEFAULT 0,
PRIMARY KEY ("object_id","term_taxonomy_id")
)
CREATE INDEX "wptests_term_relationships__term_taxonomy_id" ON "wptests_term_relationships" ("term_taxonomy_id")
--------------------
**MySQL query:**
CREATE TABLE wptests_commentmeta (
meta_id bigint(20) unsigned NOT NULL auto_increment,
comment_id bigint(20) unsigned NOT NULL default '0',
meta_key varchar(255) default NULL,
meta_value longtext,
PRIMARY KEY (meta_id),
KEY comment_id (comment_id),
KEY meta_key (meta_key(191))
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_commentmeta (
"comment_id" integer NOT NULL DEFAULT '0',
"meta_key" text DEFAULT NULL,
"meta_value" text
)
CREATE INDEX "wptests_commentmeta__comment_id" ON "wptests_commentmeta" ("comment_id")
CREATE INDEX "wptests_commentmeta__meta_key" ON "wptests_commentmeta" ("meta_key")
--------------------
**MySQL query:**
CREATE TABLE wptests_comments (
comment_ID bigint(20) unsigned NOT NULL auto_increment,
comment_post_ID bigint(20) unsigned NOT NULL default '0',
comment_author tinytext NOT NULL,
comment_author_email varchar(100) NOT NULL default '',
comment_author_url varchar(200) NOT NULL default '',
comment_author_IP varchar(100) NOT NULL default '',
comment_date datetime NOT NULL default '0000-00-00 00:00:00',
comment_date_gmt datetime NOT NULL default '0000-00-00 00:00:00',
comment_content text NOT NULL,
comment_karma int(11) NOT NULL default '0',
comment_approved varchar(20) NOT NULL default '1',
comment_agent varchar(255) NOT NULL default '',
comment_type varchar(20) NOT NULL default 'comment',
comment_parent bigint(20) unsigned NOT NULL default '0',
user_id bigint(20) unsigned NOT NULL default '0',
PRIMARY KEY (comment_ID),
KEY comment_post_ID (comment_post_ID),
KEY comment_approved_date_gmt (comment_approved,comment_date_gmt),
KEY comment_date_gmt (comment_date_gmt),
KEY comment_parent (comment_parent),
KEY comment_author_email (comment_author_email(10))
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_comments (
"comment_post_ID" integer NOT NULL DEFAULT '0',
"comment_author" text NOT NULL,
"comment_author_email" text NOT NULL DEFAULT '',
"comment_author_url" text NOT NULL DEFAULT '',
"comment_author_IP" text NOT NULL DEFAULT '',
"comment_date" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"comment_date_gmt" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"comment_content" text NOT NULL,
"comment_karma" integer NOT NULL DEFAULT '0',
"comment_approved" text NOT NULL DEFAULT '1',
"comment_agent" text NOT NULL DEFAULT '',
"comment_type" text NOT NULL DEFAULT 'comment',
"comment_parent" integer NOT NULL DEFAULT '0',
"user_id" integer NOT NULL DEFAULT '0'
)
CREATE INDEX "wptests_comments__comment_post_ID" ON "wptests_comments" ("comment_post_ID")
CREATE INDEX "wptests_comments__comment_approved_date_gmt" ON "wptests_comments" ("comment_approved", "comment_date_gmt")
CREATE INDEX "wptests_comments__comment_date_gmt" ON "wptests_comments" ("comment_date_gmt")
CREATE INDEX "wptests_comments__comment_parent" ON "wptests_comments" ("comment_parent")
CREATE INDEX "wptests_comments__comment_author_email" ON "wptests_comments" ("comment_author_email")
--------------------
**MySQL query:**
CREATE TABLE wptests_links (
link_id bigint(20) unsigned NOT NULL auto_increment,
link_url varchar(255) NOT NULL default '',
link_name varchar(255) NOT NULL default '',
link_image varchar(255) NOT NULL default '',
link_target varchar(25) NOT NULL default '',
link_description varchar(255) NOT NULL default '',
link_visible varchar(20) NOT NULL default 'Y',
link_owner bigint(20) unsigned NOT NULL default '1',
link_rating int(11) NOT NULL default '0',
link_updated datetime NOT NULL default '0000-00-00 00:00:00',
link_rel varchar(255) NOT NULL default '',
link_notes mediumtext NOT NULL,
link_rss varchar(255) NOT NULL default '',
PRIMARY KEY (link_id),
KEY link_visible (link_visible)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_links (
"link_url" text NOT NULL DEFAULT '',
"link_name" text NOT NULL DEFAULT '',
"link_image" text NOT NULL DEFAULT '',
"link_target" text NOT NULL DEFAULT '',
"link_description" text NOT NULL DEFAULT '',
"link_visible" text NOT NULL DEFAULT 'Y',
"link_owner" integer NOT NULL DEFAULT '1',
"link_rating" integer NOT NULL DEFAULT '0',
"link_updated" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"link_rel" text NOT NULL DEFAULT '',
"link_notes" text NOT NULL,
"link_rss" text NOT NULL DEFAULT ''
)
CREATE INDEX "wptests_links__link_visible" ON "wptests_links" ("link_visible")
--------------------
**MySQL query:**
CREATE TABLE wptests_options (
option_id bigint(20) unsigned NOT NULL auto_increment,
option_name varchar(191) NOT NULL default '',
option_value longtext NOT NULL,
autoload varchar(20) NOT NULL default 'yes',
PRIMARY KEY (option_id),
UNIQUE KEY option_name (option_name),
KEY autoload (autoload)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_options (
"option_name" text NOT NULL DEFAULT '',
"option_value" text NOT NULL,
"autoload" text NOT NULL DEFAULT 'yes'
)
CREATE UNIQUE INDEX "wptests_options__option_name" ON "wptests_options" ("option_name")
CREATE INDEX "wptests_options__autoload" ON "wptests_options" ("autoload")
--------------------
**MySQL query:**
CREATE TABLE wptests_postmeta (
meta_id bigint(20) unsigned NOT NULL auto_increment,
post_id bigint(20) unsigned NOT NULL default '0',
meta_key varchar(255) default NULL,
meta_value longtext,
PRIMARY KEY (meta_id),
KEY post_id (post_id),
KEY meta_key (meta_key(191))
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_postmeta (
"post_id" integer NOT NULL DEFAULT '0',
"meta_key" text DEFAULT NULL,
"meta_value" text
)
CREATE INDEX "wptests_postmeta__post_id" ON "wptests_postmeta" ("post_id")
CREATE INDEX "wptests_postmeta__meta_key" ON "wptests_postmeta" ("meta_key")
--------------------
**MySQL query:**
CREATE TABLE wptests_posts (
ID bigint(20) unsigned NOT NULL auto_increment,
post_author bigint(20) unsigned NOT NULL default '0',
post_date datetime NOT NULL default '0000-00-00 00:00:00',
post_date_gmt datetime NOT NULL default '0000-00-00 00:00:00',
post_content longtext NOT NULL,
post_title text NOT NULL,
post_excerpt text NOT NULL,
post_status varchar(20) NOT NULL default 'publish',
comment_status varchar(20) NOT NULL default 'open',
ping_status varchar(20) NOT NULL default 'open',
post_password varchar(255) NOT NULL default '',
post_name varchar(200) NOT NULL default '',
to_ping text NOT NULL,
pinged text NOT NULL,
post_modified datetime NOT NULL default '0000-00-00 00:00:00',
post_modified_gmt datetime NOT NULL default '0000-00-00 00:00:00',
post_content_filtered longtext NOT NULL,
post_parent bigint(20) unsigned NOT NULL default '0',
guid varchar(255) NOT NULL default '',
menu_order int(11) NOT NULL default '0',
post_type varchar(20) NOT NULL default 'post',
post_mime_type varchar(100) NOT NULL default '',
comment_count bigint(20) NOT NULL default '0',
PRIMARY KEY (ID),
KEY post_name (post_name(191)),
KEY type_status_date (post_type,post_status,post_date,ID),
KEY post_parent (post_parent),
KEY post_author (post_author)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci
**SQLite queries:**
CREATE TABLE wptests_posts (
"post_author" integer NOT NULL DEFAULT '0',
"post_date" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"post_date_gmt" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"post_content" text NOT NULL,
"post_title" text NOT NULL,
"post_excerpt" text NOT NULL,
"post_status" text NOT NULL DEFAULT 'publish',
"comment_status" text NOT NULL DEFAULT 'open',
"ping_status" text NOT NULL DEFAULT 'open',
"post_password" text NOT NULL DEFAULT '',
"post_name" text NOT NULL DEFAULT '',
"to_ping" text NOT NULL,
"pinged" text NOT NULL,
"post_modified" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"post_modified_gmt" text NOT NULL DEFAULT '0000-00-00 00:00:00',
"post_content_filtered" text NOT NULL,
"post_parent" integer NOT NULL DEFAULT '0',
"guid" text NOT NULL DEFAULT '',
"menu_order" integer NOT NULL DEFAULT '0',
"post_type" text NOT NULL DEFAULT 'post',
"post_mime_type" text NOT NULL DEFAULT '',
"comment_count" integer NOT NULL DEFAULT '0'
)
CREATE INDEX "wptests_posts__post_name" ON "wptests_posts" ("post_name")
CREATE INDEX "wptests_posts__type_status_date" ON "wptests_posts" ("post_type", "post_status", "post_date", "ID")
CREATE INDEX "wptests_posts__post_parent" ON "wptests_posts" ("post_parent")
CREATE INDEX "wptests_posts__post_author" ON "wptests_posts" ("post_author")
--------------------
<?php
// This gets to query #17k out of #338k in WP Unit test suite
// require autoload
use PhpMyAdmin\SqlParser\Context;
use PhpMyAdmin\SqlParser\Components\CreateDefinition;
use PhpMyAdmin\SqlParser\Components\DataType;
use PhpMyAdmin\SqlParser\Statements\CreateStatement;
use PhpMyAdmin\SqlParser\Statements\SelectStatement;
require_once __DIR__.'/../vendor/autoload.php';
function queries() {
$fp = fopen(__DIR__.'/wp-phpunit.sql', 'r');
// Read $fp line by line. Extract an array of multiline Queries. Queries are delimited by /* \d+ */
$buf = '';
while ($line = fgets($fp)) {
if (1 === preg_match('/^\/\* [0-9]+ \*\//', $line)) {
if(trim($buf)) {
yield trim($buf);
}
$buf = substr($line, strpos($line, '*/') + 2);
}
else {
$buf .= $line;
}
}
fclose($fp);
}
function wooQueries() {
yield <<<'Q'
CREATE TABLE wp_actionscheduler_actions (
action_id bigint(20) unsigned NOT NULL auto_increment,
hook varchar(191) NOT NULL,
status varchar(20) NOT NULL,
scheduled_date_gmt datetime NULL default '0000-00-00 00:00:00',
scheduled_date_local datetime NULL default '0000-00-00 00:00:00',
args varchar(191),
schedule longtext,
group_id bigint(20) unsigned NOT NULL default '0',
attempts int(11) NOT NULL default '0',
last_attempt_gmt datetime NULL default '0000-00-00 00:00:00',
last_attempt_local datetime NULL default '0000-00-00 00:00:00',
claim_id bigint(20) unsigned NOT NULL default '0',
extended_args varchar(8000) DEFAULT NULL,
PRIMARY KEY (action_id),
KEY hook (hook(191)),
KEY status (status),
KEY scheduled_date_gmt (scheduled_date_gmt),
KEY args (args(191)),
KEY group_id (group_id),
KEY last_attempt_gmt (last_attempt_gmt),
KEY `claim_id_status_scheduled_date_gmt` (`claim_id`, `status`, `scheduled_date_gmt`)
) DEFAULT CHARACTER SET utf8;
Q;
yield <<<'Q'
CREATE TABLE wp_actionscheduler_claims (
claim_id bigint(20) unsigned NOT NULL auto_increment,
date_created_gmt datetime NULL default '0000-00-00 00:00:00',
PRIMARY KEY (claim_id),
KEY date_created_gmt (date_created_gmt)
) DEFAULT CHARACTER SET utf8;
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_tax_rate_locations (
location_id BIGINT UNSIGNED NOT NULL auto_increment,
location_code varchar(200) NOT NULL,
tax_rate_id BIGINT UNSIGNED NOT NULL,
location_type varchar(40) NOT NULL,
PRIMARY KEY (location_id),
KEY tax_rate_id (tax_rate_id),
KEY location_type_code (location_type(10),location_code(20))
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_payment_tokens (
token_id BIGINT UNSIGNED NOT NULL auto_increment,
gateway_id varchar(200) NOT NULL,
token text NOT NULL,
user_id BIGINT UNSIGNED NOT NULL DEFAULT '0',
type varchar(200) NOT NULL,
is_default tinyint(1) NOT NULL DEFAULT '0',
PRIMARY KEY (token_id),
KEY user_id (user_id)
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_log (
log_id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
timestamp datetime NOT NULL,
level smallint(4) NOT NULL,
source varchar(200) NOT NULL,
message longtext NOT NULL,
context longtext NULL,
PRIMARY KEY (log_id),
KEY level (level)
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_wc_webhooks (
webhook_id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
status varchar(200) NOT NULL,
name text NOT NULL,
user_id BIGINT UNSIGNED NOT NULL,
delivery_url text NOT NULL,
secret text NOT NULL,
topic varchar(200) NOT NULL,
date_created datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
date_created_gmt datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
date_modified datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
date_modified_gmt datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
api_version smallint(4) NOT NULL,
failure_count smallint(10) NOT NULL DEFAULT '0',
pending_delivery tinyint(1) NOT NULL DEFAULT '0',
PRIMARY KEY (webhook_id),
KEY user_id (user_id)
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_wc_product_attributes_lookup (
product_id bigint(20) NOT NULL,
product_or_parent_id bigint(20) NOT NULL,
taxonomy varchar(32) NOT NULL,
term_id bigint(20) NOT NULL,
is_variation_attribute tinyint(1) NOT NULL,
in_stock tinyint(1) NOT NULL,
INDEX is_variation_attribute_term_id (is_variation_attribute, term_id),
PRIMARY KEY ( `product_or_parent_id`, `term_id`, `product_id`, `taxonomy` )
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_actionscheduler_groups (
group_id bigint(20) unsigned NOT NULL auto_increment,
slug varchar(255) NOT NULL,
PRIMARY KEY (group_id),
KEY slug (slug(191))
) DEFAULT CHARACTER SET utf8;
Q;
yield <<<'Q'
CREATE TABLE wp_actionscheduler_logs (
log_id bigint(20) unsigned NOT NULL auto_increment,
action_id bigint(20) unsigned NOT NULL,
message text NOT NULL,
log_date_gmt datetime NULL default '0000-00-00 00:00:00',
log_date_local datetime NULL default '0000-00-00 00:00:00',
PRIMARY KEY (log_id),
KEY action_id (action_id),
KEY log_date_gmt (log_date_gmt)
) DEFAULT CHARACTER SET utf8;
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_sessions (
session_id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
session_key char(32) NOT NULL,
session_value longtext NOT NULL,
session_expiry BIGINT UNSIGNED NOT NULL,
PRIMARY KEY (session_id),
UNIQUE KEY session_key (session_key)
)
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_downloadable_product_permissions (
permission_id BIGINT UNSIGNED NOT NULL auto_increment,
download_id varchar(36) NOT NULL,
product_id BIGINT UNSIGNED NOT NULL,
order_id BIGINT UNSIGNED NOT NULL DEFAULT 0,
order_key varchar(200) NOT NULL,
user_email varchar(200) NOT NULL,
user_id BIGINT UNSIGNED NULL,
downloads_remaining varchar(9) NULL,
access_granted datetime NOT NULL default '0000-00-00 00:00:00',
access_expires datetime NULL default null,
download_count BIGINT UNSIGNED NOT NULL DEFAULT 0,
PRIMARY KEY (permission_id),
KEY download_order_key_product (product_id,order_id,order_key(16),download_id),
KEY download_order_product (download_id,order_id,product_id),
KEY order_id (order_id),
KEY user_order_remaining_expires (user_id,order_id,downloads_remaining,access_expires)
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_attribute_taxonomies (
attribute_id BIGINT UNSIGNED NOT NULL auto_increment,
attribute_name varchar(200) NOT NULL,
attribute_label varchar(200) NULL,
attribute_type varchar(20) NOT NULL,
attribute_orderby varchar(20) NOT NULL,
attribute_public int(1) NOT NULL DEFAULT 1,
PRIMARY KEY (attribute_id),
KEY attribute_name (attribute_name(20))
) ;
Q;
yield <<<'Q'
CREATE TABLE wp_woocommerce_api_keys (
key_id BIGINT UNSIGNED NOT NULL auto_increment,
user_id BIGINT UNSIGNED NOT NULL,
description varchar(200) NULL,
permissions varchar(10) NOT NULL,
consumer_key char(64) NOT NULL,
consumer_secret char(43) NOT NULL,
nonces longtext NULL,
truncated_key char(7) NOT NULL,
last_access datetime NULL default null,
PRIMARY KEY (key_id),
KEY consumer_key (consumer_key),
KEY consumer_secret (consumer_secret)
)
Q;
}
// Create fulltext index -> select 1=1;
// Remove: collate / default character set
//
$field_types_translation = [
'bit' => 'integer',
'bool' => 'integer',
'boolean' => 'integer',
'tinyint' => 'integer',
'smallint' => 'integer',
'mediumint' => 'integer',
'int' => 'integer',
'integer' => 'integer',
'bigint' => 'integer',
'float' => 'real',
'double' => 'real',
'decimal' => 'real',
'dec' => 'real',
'numeric' => 'real',
'fixed' => 'real',
'date' => 'text',
'datetime' => 'text',
'timestamp' => 'text',
'time' => 'text',
'year' => 'text',
'char' => 'text',
'varchar' => 'text',
'binary' => 'integer',
'varbinary' => 'blob',
'tinyblob' => 'blob',
'tinytext' => 'text',
'blob' => 'blob',
'text' => 'text',
'mediumblob' => 'blob',
'mediumtext' => 'text',
'longblob' => 'blob',
'longtext' => 'text',
];
$sqlite = new PDO('sqlite::memory:');
foreach(queries() as $k=>$query) {
$tokens = \PhpMyAdmin\SqlParser\Lexer::getTokens($query);
$token = $tokens->getNext();
if($k > 1000) break;
if($token->value !== 'CREATE') {
continue;
}
echo '**MySQL query:**'.PHP_EOL;
echo $query.PHP_EOL.PHP_EOL;
$p = new \PhpMyAdmin\SqlParser\Parser($query);
$stmt = $p->statements[0];
$stmt->entityOptions->options = array();
$inline_primary_key = false;
$extra_queries = array();;
foreach($stmt->fields as $k=>$field) {
if($field->type && $field->type->name) {
$typelc = strtolower($field->type->name);
if(isset($field_types_translation[$typelc])) {
$field->type->name = $field_types_translation[$typelc];
}
$field->type->parameters = array();
unset($field->type->options->options[DataType::$DATA_TYPE_OPTIONS['UNSIGNED']]);
}
if($field->options && $field->options->options) {
if(isset($field->options->options[CreateDefinition::$FIELD_OPTIONS['AUTO_INCREMENT']])) {
$field->options->options[CreateDefinition::$FIELD_OPTIONS['AUTO_INCREMENT']] = 'PRIMARY KEY AUTOINCREMENT';
$inline_primary_key = true;
unset($field->options->options[CreateDefinition::$FIELD_OPTIONS['PRIMARY KEY']]);
}
}
if($field->key) {
if($field->key->type === 'PRIMARY KEY'){
if($inline_primary_key) {
unset($stmt->fields[$k]);
}
} else if(
$field->key->type === 'KEY' ||
$field->key->type === 'INDEX' ||
$field->key->type === 'UNIQUE KEY'
){
$columns = array();
foreach($field->key->columns as $column) {
$columns[] = $column['name'];
}
$unique = "";
if($field->key->type === 'UNIQUE KEY') {
$unique = "UNIQUE ";
}
$extra_queries[] = 'CREATE '.$unique.' INDEX "'.$stmt->name.'__'.$field->key->name.'" ON "'.$stmt->name.'" ("'.implode('", "', $columns).'")';
unset($stmt->fields[$k]);
}
}
}
Context::setMode(Context::SQL_MODE_ANSI_QUOTES);
$updated_query = $stmt->build();
echo '**SQLite queries:**'.PHP_EOL;
echo $updated_query . PHP_EOL;
$sqlite->exec($updated_query);
foreach($extra_queries as $query) {
echo $query . PHP_EOL . PHP_EOL;
$sqlite->exec($query);
}
echo '--------------------'.PHP_EOL.PHP_EOL;
}
foreach(queries() as $k=>$query) {
if($k < 17000) continue;
$tokens = \PhpMyAdmin\SqlParser\Lexer::getTokens($query);
$token = $tokens->getNext();
if($token->value !== 'SELECT') {
continue;
}
if(
strpos($query, 'information_schema.TABLES') !== false
|| strpos($query, '@example') !== false
|| strpos($query, 'FOUND_ROWS') !== false
) {
continue;
}
echo '**MySQL query:**'.PHP_EOL;
echo $query.PHP_EOL.PHP_EOL;
$p = new \PhpMyAdmin\SqlParser\Parser($query);
$stmt = $p->statements[0];
if($stmt->options && $stmt->options->options){
unset($stmt->options->options[SelectStatement::$OPTIONS['SQL_CALC_FOUND_ROWS']]);
}
foreach($stmt->expr as $expr){
foreach([['YEAR', '%Y'], ['MONTH', '%M'], ['DAY', '%d']] as [$unit, $format]) {
if(str_starts_with($expr->expr, $unit) ) {
$expr->expr = 'strftime("'.strtolower($format).'", '.substr($expr->expr, strpos($expr->expr, '(')+1, -1).')';
}
}
}
foreach($stmt->group??[] as $group){
if($group->expr && $group->expr->expr){
foreach([['YEAR', '%Y'], ['MONTH', '%M'], ['DAY', '%d']] as [$unit, $format]) {
if(str_starts_with($group->expr->expr, $unit) ) {
$group->expr->expr = 'strftime("'.strtolower($format).'", '.substr($group->expr->expr, strpos($group->expr->expr, '(')+1, -1).')';
}
}
}
}
foreach($stmt->order??[] as $order){
if($order->expr && $order->expr->expr){
if($order->expr->expr === 'rand()') {
$order->expr->expr = 'random()';
}
}
}
Context::setMode(Context::SQL_MODE_ANSI_QUOTES);
$updated_query = $stmt->build();
$extra_queries = array();
echo '**SQLite queries:**'.PHP_EOL;
echo $updated_query . PHP_EOL;
try {
$sqlite->exec($updated_query);
} catch(\Exception $e) {
print_r($stmt);
throw $e;
}
foreach($extra_queries as $query) {
$query = str_replace(' ID ', '"ID" ', $query);
echo $query . PHP_EOL . PHP_EOL;
try {
$sqlite->exec($query);
} catch(\Exception $e) {
print_r($stmt);
throw $e;
}
}
echo '--------------------'.PHP_EOL.PHP_EOL;
}
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment