From 824982e46f259046280d6cfda922c67e396c074d Mon Sep 17 00:00:00 2001 From: wkaiz Date: Wed, 17 Sep 2025 23:06:29 -0700 Subject: [PATCH] Add MySQL and ProxySQL rule generators and tests Introduces MySQLGenerator and ProxySQLGenerator classes for generating SQL rewrite rules, along with corresponding tester classes and scripts for automated rule and test execution. Adds SQL test cases and generated rule files for FilterMerge, ProjectMerge, JoinCommute, FilterReduceTrue, and FilterReduceFalse patterns for both MySQL and ProxySQL environments. --- .../org/qed/Generated/MySQLGenerator.java | 155 ++++++++++++++++++ .../java/org/qed/Generated/MySQLTester.java | 43 +++++ .../org/qed/Generated/ProxySQLGenerator.java | 135 +++++++++++++++ .../org/qed/Generated/ProxySQLTester.java | 57 +++++++ .../Generated/Test-MySQL/FilterMerge1Test.sql | 2 + .../Generated/Test-MySQL/FilterMerge2Test.sql | 2 + .../Generated/Test-MySQL/JoinCommute1Test.sql | 3 + .../Generated/Test-MySQL/JoinCommute2Test.sql | 3 + .../Test-MySQL/ProjectMerge1Test.sql | 1 + .../Test-MySQL/ProjectMerge2Test.sql | 1 + .../Tests-ProxySQL/FilterMergeTest.sql | 1 + .../Tests-ProxySQL/FilterReduceFalseTest.sql | 1 + .../Tests-ProxySQL/FilterReduceTrueTest.sql | 1 + .../Tests-ProxySQL/JoinCommuteTest.sql | 1 + .../Tests-ProxySQL/ProjectMergeTest.sql | 1 + .../org/qed/Generated/mysql/FilterMerge1.sql | 5 + .../org/qed/Generated/mysql/FilterMerge2.sql | 5 + .../org/qed/Generated/mysql/JoinCommute1.sql | 5 + .../org/qed/Generated/mysql/JoinCommute2.sql | 5 + .../org/qed/Generated/mysql/ProjectMerge1.sql | 5 + .../org/qed/Generated/mysql/ProjectMerge2.sql | 5 + .../qed/Generated/proxysql/FilterMerge.sql | 6 + .../Generated/proxysql/FilterReduceFalse.sql | 6 + .../Generated/proxysql/FilterReduceTrue.sql | 6 + .../qed/Generated/proxysql/JoinCommute.sql | 6 + .../qed/Generated/proxysql/ProjectMerge.sql | 6 + .../java/org/qed/Generated/script-mysql.py | 93 +++++++++++ .../java/org/qed/Generated/script-proxysql.sh | 58 +++++++ 28 files changed, 618 insertions(+) create mode 100644 src/main/java/org/qed/Generated/MySQLGenerator.java create mode 100644 src/main/java/org/qed/Generated/MySQLTester.java create mode 100644 src/main/java/org/qed/Generated/ProxySQLGenerator.java create mode 100644 src/main/java/org/qed/Generated/ProxySQLTester.java create mode 100644 src/main/java/org/qed/Generated/Test-MySQL/FilterMerge1Test.sql create mode 100644 src/main/java/org/qed/Generated/Test-MySQL/FilterMerge2Test.sql create mode 100644 src/main/java/org/qed/Generated/Test-MySQL/JoinCommute1Test.sql create mode 100644 src/main/java/org/qed/Generated/Test-MySQL/JoinCommute2Test.sql create mode 100644 src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge1Test.sql create mode 100644 src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge2Test.sql create mode 100644 src/main/java/org/qed/Generated/Tests-ProxySQL/FilterMergeTest.sql create mode 100644 src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceFalseTest.sql create mode 100644 src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceTrueTest.sql create mode 100644 src/main/java/org/qed/Generated/Tests-ProxySQL/JoinCommuteTest.sql create mode 100644 src/main/java/org/qed/Generated/Tests-ProxySQL/ProjectMergeTest.sql create mode 100644 src/main/java/org/qed/Generated/mysql/FilterMerge1.sql create mode 100644 src/main/java/org/qed/Generated/mysql/FilterMerge2.sql create mode 100644 src/main/java/org/qed/Generated/mysql/JoinCommute1.sql create mode 100644 src/main/java/org/qed/Generated/mysql/JoinCommute2.sql create mode 100644 src/main/java/org/qed/Generated/mysql/ProjectMerge1.sql create mode 100644 src/main/java/org/qed/Generated/mysql/ProjectMerge2.sql create mode 100644 src/main/java/org/qed/Generated/proxysql/FilterMerge.sql create mode 100644 src/main/java/org/qed/Generated/proxysql/FilterReduceFalse.sql create mode 100644 src/main/java/org/qed/Generated/proxysql/FilterReduceTrue.sql create mode 100644 src/main/java/org/qed/Generated/proxysql/JoinCommute.sql create mode 100644 src/main/java/org/qed/Generated/proxysql/ProjectMerge.sql create mode 100644 src/main/java/org/qed/Generated/script-mysql.py create mode 100644 src/main/java/org/qed/Generated/script-proxysql.sh diff --git a/src/main/java/org/qed/Generated/MySQLGenerator.java b/src/main/java/org/qed/Generated/MySQLGenerator.java new file mode 100644 index 0000000..c8a6e48 --- /dev/null +++ b/src/main/java/org/qed/Generated/MySQLGenerator.java @@ -0,0 +1,155 @@ +package org.qed.Generated; + +import org.qed.Generated.RRuleInstances.JoinCommute; +import org.qed.RelRN; +import org.qed.RexRN; + +import java.util.ArrayList; +import java.util.List; +import java.util.concurrent.atomic.AtomicInteger; + +public class MySQLGenerator { + + private int subqueryCounter = 0; + private final String tableName; + private final List columnNames; + + public MySQLGenerator(String tableName, List columnNames) { + this.tableName = tableName; + this.columnNames = columnNames; + } + + private static class FlattenedSQLParts { + String fromClause = ""; + List projections = new ArrayList<>(); + List conditions = new ArrayList<>(); + } + + public String translate(String name, RelRN before, RelRN after) { + String beforeSQL; + String afterSQL; + + if (name.equals("JoinCommute")) { + subqueryCounter = 0; + beforeSQL = transformNested(before, true, false, new AtomicInteger(0)); + subqueryCounter = 0; + afterSQL = transformNested(before, true, true, new AtomicInteger(0)); + } else { + subqueryCounter = 0; + beforeSQL = transformNested(before, true, false, new AtomicInteger(0)); + afterSQL = transformFlatten(after); + } + + return "INSERT INTO query_rewrite.rewrite_rules\n" + + " (pattern, replacement) VALUES(\n" + + " '" + beforeSQL + "',\n" + + " '" + afterSQL + "'\n" + + ");"; + } + + private String transformNested(RelRN node, boolean isRoot, boolean swapJoinSides, AtomicInteger filterIndex) { + if (node instanceof RelRN.Scan) { + return "SELECT * FROM " + tableName; + } else if (node instanceof RelRN.Project project) { + String cols = String.join(", ", columnNames); + if (project.source() instanceof RelRN.Scan) { + return "SELECT " + cols + " FROM " + tableName; + } + String innerSQL = transformNested(project.source(), false, swapJoinSides, filterIndex); + String alias = "t" + (subqueryCounter++); + return "SELECT " + cols + " FROM (" + innerSQL + ") AS " + alias; + } else if (node instanceof RelRN.Filter filter) { + String innerSQL = transformNested(filter.source(), false, swapJoinSides, filterIndex); + int currentIndex = filterIndex.getAndIncrement(); + String condition = (currentIndex < columnNames.size()) + ? columnNames.get(currentIndex) + " = ?" + : columnNames.get(0) + " = ?"; + + if (isRoot) { + return innerSQL + " WHERE " + condition; + } else { + String alias = "t" + (subqueryCounter++); + return "SELECT * FROM (" + innerSQL + " WHERE " + condition + ") AS " + alias; + } + } else if (node instanceof RelRN.Join join) { + String leftAlias = "t0"; + String rightAlias = "t1"; + + RelRN firstNode = swapJoinSides ? join.right() : join.left(); + String firstAlias = swapJoinSides ? rightAlias : leftAlias; + RelRN secondNode = swapJoinSides ? join.left() : join.right(); + String secondAlias = swapJoinSides ? leftAlias : rightAlias; + + String firstSQL = "(" + transformNested(firstNode, false, swapJoinSides, filterIndex) + ")"; + String secondSQL = "(" + transformNested(secondNode, false, swapJoinSides, filterIndex) + ")"; + + String joinCond = renderJoinCondition(join.cond(), leftAlias, rightAlias, swapJoinSides); + + String joinExpr = + firstSQL + " AS " + firstAlias + + " " + join.ty().semantics().name() + " JOIN " + + secondSQL + " AS " + secondAlias + + " ON " + joinCond; + + if (isRoot) { + return "SELECT * FROM " + joinExpr; + } else { + String alias = "t" + (subqueryCounter++); + return "SELECT * FROM (" + joinExpr + ") AS " + alias; + } + + } else if (node instanceof JoinCommute.ProjectionRelRN projRN) { + return transformNested(projRN.source(), isRoot, swapJoinSides, filterIndex); + } else { + throw new UnsupportedOperationException("Unsupported RelRN: " + node); + } + } + + private String renderJoinCondition(RexRN cond, String leftAlias, String rightAlias, boolean swap) { + if (cond instanceof RexRN.Pred p) { + if (p.sources().get(0) instanceof RexRN.JoinField jf) { + String colName = columnNames.get(jf.ordinal()); + String first = swap ? rightAlias : leftAlias; + String second = swap ? leftAlias : rightAlias; + return first + "." + colName + " = " + second + "." + colName; + } + } + throw new UnsupportedOperationException("Unsupported join condition: " + cond); + } + + public String transformFlatten(RelRN node) { + FlattenedSQLParts parts = new FlattenedSQLParts(); + collectFlattenedParts(node, parts); + String selectClause = parts.projections.isEmpty() ? "SELECT *" : "SELECT " + String.join(", ", parts.projections); + String whereClause = parts.conditions.isEmpty() ? "" : " WHERE " + String.join(" AND ", parts.conditions); + return selectClause + " FROM " + parts.fromClause + whereClause; + } + + private void collectFlattenedParts(RelRN node, FlattenedSQLParts parts) { + switch (node) { + case RelRN.Scan scan -> parts.fromClause = tableName; + case RelRN.Project project -> { + collectFlattenedParts(project.source(), parts); + parts.projections.addAll(columnNames); + } + case RelRN.Filter filter -> { + collectFlattenedParts(filter.source(), parts); + collectPredConditions(filter.cond(), parts.conditions); + } + default -> throw new UnsupportedOperationException("Unsupported RelRN for flatten: " + node); + } + } + + private void collectPredConditions(RexRN pred, List conditions) { + if (pred instanceof RexRN.Pred) { + int currentConditions = conditions.size(); + if (currentConditions < columnNames.size()) { + conditions.add(columnNames.get(currentConditions) + " = ?"); + } + } else if (pred instanceof RexRN.And and) { + for (RexRN child : and.sources()) { + collectPredConditions(child, conditions); + } + } + } +} \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/MySQLTester.java b/src/main/java/org/qed/Generated/MySQLTester.java new file mode 100644 index 0000000..f5707fa --- /dev/null +++ b/src/main/java/org/qed/Generated/MySQLTester.java @@ -0,0 +1,43 @@ +package org.qed.Generated; + +import org.qed.*; +import java.io.IOException; +import java.nio.file.Files; +import java.nio.file.Path; +import java.util.List; + +public class MySQLTester { + + public static String genPath = "src/main/java/org/qed/Generated/mysql"; + + public static String tableName = "testdb.users"; + public static List columnNames = List.of("id", "status"); + + public static void main(String[] args) { + var filterRule = new org.qed.Generated.RRuleInstances.FilterMerge(); + new MySQLTester().serializeWithNumericSuffix(filterRule, genPath); + + var projectRule = new org.qed.Generated.RRuleInstances.ProjectMerge(); + new MySQLTester().serializeWithNumericSuffix(projectRule, genPath); + + var joinCommute = new org.qed.Generated.RRuleInstances.JoinCommute(); + new MySQLTester().serializeWithNumericSuffix(joinCommute, genPath); + } + + public void serializeWithNumericSuffix(RRule rule, String path) { + serialize(rule, path, tableName, columnNames, 1); + serialize(rule, path, tableName, List.of(columnNames.get(1), columnNames.get(0)), 2); + } + + private void serialize(RRule rule, String path, String tableName, List colNames, int fileIndex) { + var generator = new MySQLGenerator(tableName, colNames); + var codeGen = generator.translate(rule.name(), rule.before(), rule.after()); + try { + Files.createDirectories(Path.of(path)); + String fileName = rule.name() + fileIndex + ".sql"; + Files.write(Path.of(path, fileName), codeGen.getBytes()); + } catch (IOException ioe) { + System.err.println(ioe.getMessage()); + } + } +} diff --git a/src/main/java/org/qed/Generated/ProxySQLGenerator.java b/src/main/java/org/qed/Generated/ProxySQLGenerator.java new file mode 100644 index 0000000..846b627 --- /dev/null +++ b/src/main/java/org/qed/Generated/ProxySQLGenerator.java @@ -0,0 +1,135 @@ +package org.qed.Generated; + +import org.qed.Generated.RRuleInstances.JoinCommute; +import org.qed.RelRN; +import org.qed.RexRN; + +import java.util.HashMap; +import java.util.Map; +import java.util.concurrent.atomic.AtomicInteger; +import java.util.stream.Collectors; + +public class ProxySQLGenerator { + + private final Map predicateToGroupIndex = new HashMap<>(); + private final AtomicInteger groupCounter = new AtomicInteger(1); + private boolean isReduceTrueRule = false; + + public String translate(int ruleId, String name, RelRN before, RelRN after) { + predicateToGroupIndex.clear(); + groupCounter.set(1); + this.isReduceTrueRule = false; + + String matchPattern = generateMatchPattern(before); + String replacePattern = generateReplacePattern(after); + + return String.format( + """ + INSERT INTO mysql_query_rules (rule_id, active, match_pattern, replace_pattern) + VALUES ( + %d, 1, + '^%s', + '%s' + );""", + ruleId, matchPattern, replacePattern + ); + } + + private String generateMatchPattern(RelRN node) { + return switch (node) { + case RelRN.Filter filter -> { + if (filter.cond() instanceof RexRN.True) { + this.isReduceTrueRule = true; + groupCounter.addAndGet(2); + yield "SELECT (.*) FROM (.*) WHERE TRUE"; + } + + if (filter.cond() instanceof RexRN.False) { + groupCounter.addAndGet(2); + yield "SELECT (.*) FROM (.*) WHERE FALSE"; + } + + String sourcePattern = generateMatchPattern(filter.source()); + String conditionRegex = "(.*) = (.*)"; + if (filter.source() instanceof RelRN.Scan) { + int conditionGroupStart = groupCounter.get(); + groupCounter.addAndGet(2); + predicateToGroupIndex.put(filter.cond(), conditionGroupStart); + yield sourcePattern + " WHERE " + conditionRegex; + } else { + groupCounter.getAndIncrement(); + int conditionGroupStart = groupCounter.get(); + groupCounter.addAndGet(2); + predicateToGroupIndex.put(filter.cond(), conditionGroupStart); + yield String.format("SELECT \\* FROM \\(%s\\) AS (.*) WHERE %s", sourcePattern, conditionRegex); + } + } + case RelRN.Project project -> { + if (project.source() instanceof RelRN.Project innerProject && innerProject.source() instanceof RelRN.Scan) { + yield "SELECT (.*) FROM \\(SELECT (.*) FROM (.*)\\) AS (.*)"; + } + throw new UnsupportedOperationException("This generator only supports the specific Project(Project(Scan)) pattern."); + } + case RelRN.Join join -> { + if (join.left() instanceof RelRN.Scan && join.right() instanceof RelRN.Scan) { + yield "SELECT \\* FROM (.*) AS (.*?) INNER JOIN (.*) AS (.*?) ON (.*?)\\.(.*?) = (.*?)\\.(.*)"; + } + throw new UnsupportedOperationException("This generator only supports simple Scan-Join-Scan patterns."); + } + case RelRN.Scan scan -> { + groupCounter.getAndIncrement(); + yield "SELECT \\* FROM (.*)"; + } + default -> throw new UnsupportedOperationException("Unsupported RelRN for match pattern: " + node.getClass().getSimpleName()); + }; + } + + private String generateReplacePattern(RelRN node) { + return switch (node) { + case RelRN.Empty empty -> { + yield "SELECT \\1 FROM \\2 LIMIT 0"; + } + case JoinCommute.ProjectionRelRN proj -> { + if (proj.source() instanceof RelRN.Join) { + yield "SELECT * FROM \\3 AS \\4 INNER JOIN \\1 AS \\2 ON \\7.\\8 = \\5.\\6"; + } + throw new UnsupportedOperationException("Unsupported 'after' pattern for JoinCommute."); + } + case RelRN.Filter filter -> { + String fromClause = generateReplacePattern(filter.source()); + String whereClause = buildWhereClause(filter.cond()); + yield String.format("%s WHERE %s", fromClause, whereClause); + } + case RelRN.Project project -> { + if (project.source() instanceof RelRN.Scan) { + yield "SELECT \\1 FROM \\3"; + } + throw new UnsupportedOperationException("Unsupported 'after' pattern for ProjectMerge."); + } + case RelRN.Scan scan -> { + if (this.isReduceTrueRule) { + yield "SELECT \\1 FROM \\2"; + } else { + yield "SELECT * FROM \\1"; + } + } + default -> throw new UnsupportedOperationException("Unsupported RelRN for replace pattern: " + node.getClass().getSimpleName()); + }; + } + + private String buildWhereClause(RexRN condition) { + return switch (condition) { + case RexRN.And andNode -> andNode.sources().stream() + .map(this::buildWhereClause) + .collect(Collectors.joining(" AND ")); + case RexRN.Pred pred -> { + Integer groupIndex = predicateToGroupIndex.get(pred); + if (groupIndex == null) { + throw new IllegalStateException("Predicate from 'after' tree not found in 'before' tree: " + pred); + } + yield String.format("\\%d = \\%d", groupIndex, groupIndex + 1); + } + default -> throw new UnsupportedOperationException("Unsupported RexRN for WHERE clause: " + condition.getClass().getSimpleName()); + }; + } +} \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/ProxySQLTester.java b/src/main/java/org/qed/Generated/ProxySQLTester.java new file mode 100644 index 0000000..349857a --- /dev/null +++ b/src/main/java/org/qed/Generated/ProxySQLTester.java @@ -0,0 +1,57 @@ +package org.qed.Generated; + +import org.qed.RRule; +import org.qed.Generated.RRuleInstances.FilterMerge; +import org.qed.Generated.RRuleInstances.ProjectMerge; +import org.qed.Generated.RRuleInstances.JoinCommute; +import org.qed.Generated.RRuleInstances.FilterReduceFalse; +import org.qed.Generated.RRuleInstances.FilterReduceTrue; // Import the new rule + +import java.io.IOException; +import java.nio.file.Files; +import java.nio.file.Path; +import java.util.List; + +public class ProxySQLTester { + + public static final String OUTPUT_PATH = "src/main/java/org/qed/Generated/proxysql"; + + private int nextRuleId = 10; + + public static void main(String[] args) { + var tester = new ProxySQLTester(); + + List rulesToGenerate = List.of( + new FilterMerge(), + new ProjectMerge(), + new JoinCommute(), + new FilterReduceFalse(), + new FilterReduceTrue() + ); + + for (RRule rule : rulesToGenerate) { + tester.generateRuleFile(rule); + System.out.println(); + } + } + + public void generateRuleFile(RRule rule) { + int currentRuleId = this.nextRuleId; + this.nextRuleId += 10; + + var generator = new ProxySQLGenerator(); + String ruleSql = generator.translate(currentRuleId, rule.name(), rule.before(), rule.after()); + + try { + Path outputDir = Path.of(OUTPUT_PATH); + Files.createDirectories(outputDir); + + String fileName = rule.name() + ".sql"; + Path filePath = outputDir.resolve(fileName); + Files.writeString(filePath, ruleSql); + + } catch (IOException | UnsupportedOperationException e) { + e.printStackTrace(); + } + } +} \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Test-MySQL/FilterMerge1Test.sql b/src/main/java/org/qed/Generated/Test-MySQL/FilterMerge1Test.sql new file mode 100644 index 0000000..884f26c --- /dev/null +++ b/src/main/java/org/qed/Generated/Test-MySQL/FilterMerge1Test.sql @@ -0,0 +1,2 @@ +SELECT * FROM (SELECT * FROM testdb.users WHERE id = 1) AS t0 +WHERE status = 'active'; \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Test-MySQL/FilterMerge2Test.sql b/src/main/java/org/qed/Generated/Test-MySQL/FilterMerge2Test.sql new file mode 100644 index 0000000..62c05e2 --- /dev/null +++ b/src/main/java/org/qed/Generated/Test-MySQL/FilterMerge2Test.sql @@ -0,0 +1,2 @@ +SELECT * FROM (SELECT * FROM testdb.users WHERE status = 'active') AS t0 +WHERE id = 1; \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Test-MySQL/JoinCommute1Test.sql b/src/main/java/org/qed/Generated/Test-MySQL/JoinCommute1Test.sql new file mode 100644 index 0000000..00a2a85 --- /dev/null +++ b/src/main/java/org/qed/Generated/Test-MySQL/JoinCommute1Test.sql @@ -0,0 +1,3 @@ +SELECT * FROM (SELECT * FROM testdb.users) AS t0 +INNER JOIN (SELECT * FROM testdb.users) AS t1 +ON t0.id = t1.id; diff --git a/src/main/java/org/qed/Generated/Test-MySQL/JoinCommute2Test.sql b/src/main/java/org/qed/Generated/Test-MySQL/JoinCommute2Test.sql new file mode 100644 index 0000000..c213c1d --- /dev/null +++ b/src/main/java/org/qed/Generated/Test-MySQL/JoinCommute2Test.sql @@ -0,0 +1,3 @@ +SELECT * FROM (SELECT * FROM testdb.users) AS t0 +INNER JOIN (SELECT * FROM testdb.users) AS t1 +ON t0.status = t1.status; diff --git a/src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge1Test.sql b/src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge1Test.sql new file mode 100644 index 0000000..4800f37 --- /dev/null +++ b/src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge1Test.sql @@ -0,0 +1 @@ +SELECT id, status FROM (SELECT id, status FROM testdb.users) AS t0; \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge2Test.sql b/src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge2Test.sql new file mode 100644 index 0000000..57bcffb --- /dev/null +++ b/src/main/java/org/qed/Generated/Test-MySQL/ProjectMerge2Test.sql @@ -0,0 +1 @@ +SELECT status, id FROM (SELECT status, id FROM testdb.users) AS t0; \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterMergeTest.sql b/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterMergeTest.sql new file mode 100644 index 0000000..a418bc4 --- /dev/null +++ b/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterMergeTest.sql @@ -0,0 +1 @@ +SELECT * FROM (SELECT * FROM testdb.users WHERE status = 'active') AS t0 WHERE id = 1; \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceFalseTest.sql b/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceFalseTest.sql new file mode 100644 index 0000000..d100168 --- /dev/null +++ b/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceFalseTest.sql @@ -0,0 +1 @@ +SELECT name FROM testdb.users WHERE FALSE; diff --git a/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceTrueTest.sql b/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceTrueTest.sql new file mode 100644 index 0000000..a6a709f --- /dev/null +++ b/src/main/java/org/qed/Generated/Tests-ProxySQL/FilterReduceTrueTest.sql @@ -0,0 +1 @@ +SELECT * FROM testdb.users WHERE TRUE; diff --git a/src/main/java/org/qed/Generated/Tests-ProxySQL/JoinCommuteTest.sql b/src/main/java/org/qed/Generated/Tests-ProxySQL/JoinCommuteTest.sql new file mode 100644 index 0000000..a881320 --- /dev/null +++ b/src/main/java/org/qed/Generated/Tests-ProxySQL/JoinCommuteTest.sql @@ -0,0 +1 @@ +SELECT * FROM testdb.users AS u INNER JOIN testdb.orders AS o ON u.id = o.user_id; \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/Tests-ProxySQL/ProjectMergeTest.sql b/src/main/java/org/qed/Generated/Tests-ProxySQL/ProjectMergeTest.sql new file mode 100644 index 0000000..bcefcd6 --- /dev/null +++ b/src/main/java/org/qed/Generated/Tests-ProxySQL/ProjectMergeTest.sql @@ -0,0 +1 @@ +SELECT name FROM (SELECT name FROM testdb.users) AS t0; diff --git a/src/main/java/org/qed/Generated/mysql/FilterMerge1.sql b/src/main/java/org/qed/Generated/mysql/FilterMerge1.sql new file mode 100644 index 0000000..3579e90 --- /dev/null +++ b/src/main/java/org/qed/Generated/mysql/FilterMerge1.sql @@ -0,0 +1,5 @@ +INSERT INTO query_rewrite.rewrite_rules + (pattern, replacement) VALUES( + 'SELECT * FROM (SELECT * FROM testdb.users WHERE id = ?) AS t0 WHERE status = ?', + 'SELECT * FROM testdb.users WHERE id = ? AND status = ?' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/mysql/FilterMerge2.sql b/src/main/java/org/qed/Generated/mysql/FilterMerge2.sql new file mode 100644 index 0000000..a48e50c --- /dev/null +++ b/src/main/java/org/qed/Generated/mysql/FilterMerge2.sql @@ -0,0 +1,5 @@ +INSERT INTO query_rewrite.rewrite_rules + (pattern, replacement) VALUES( + 'SELECT * FROM (SELECT * FROM testdb.users WHERE status = ?) AS t0 WHERE id = ?', + 'SELECT * FROM testdb.users WHERE status = ? AND id = ?' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/mysql/JoinCommute1.sql b/src/main/java/org/qed/Generated/mysql/JoinCommute1.sql new file mode 100644 index 0000000..67a32bc --- /dev/null +++ b/src/main/java/org/qed/Generated/mysql/JoinCommute1.sql @@ -0,0 +1,5 @@ +INSERT INTO query_rewrite.rewrite_rules + (pattern, replacement) VALUES( + 'SELECT * FROM (SELECT * FROM testdb.users) AS t0 INNER JOIN (SELECT * FROM testdb.users) AS t1 ON t0.id = t1.id', + 'SELECT * FROM (SELECT * FROM testdb.users) AS t1 INNER JOIN (SELECT * FROM testdb.users) AS t0 ON t1.id = t0.id' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/mysql/JoinCommute2.sql b/src/main/java/org/qed/Generated/mysql/JoinCommute2.sql new file mode 100644 index 0000000..3805762 --- /dev/null +++ b/src/main/java/org/qed/Generated/mysql/JoinCommute2.sql @@ -0,0 +1,5 @@ +INSERT INTO query_rewrite.rewrite_rules + (pattern, replacement) VALUES( + 'SELECT * FROM (SELECT * FROM testdb.users) AS t0 INNER JOIN (SELECT * FROM testdb.users) AS t1 ON t0.status = t1.status', + 'SELECT * FROM (SELECT * FROM testdb.users) AS t1 INNER JOIN (SELECT * FROM testdb.users) AS t0 ON t1.status = t0.status' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/mysql/ProjectMerge1.sql b/src/main/java/org/qed/Generated/mysql/ProjectMerge1.sql new file mode 100644 index 0000000..4544506 --- /dev/null +++ b/src/main/java/org/qed/Generated/mysql/ProjectMerge1.sql @@ -0,0 +1,5 @@ +INSERT INTO query_rewrite.rewrite_rules + (pattern, replacement) VALUES( + 'SELECT id, status FROM (SELECT id, status FROM testdb.users) AS t0', + 'SELECT id, status FROM testdb.users' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/mysql/ProjectMerge2.sql b/src/main/java/org/qed/Generated/mysql/ProjectMerge2.sql new file mode 100644 index 0000000..df80c53 --- /dev/null +++ b/src/main/java/org/qed/Generated/mysql/ProjectMerge2.sql @@ -0,0 +1,5 @@ +INSERT INTO query_rewrite.rewrite_rules + (pattern, replacement) VALUES( + 'SELECT status, id FROM (SELECT status, id FROM testdb.users) AS t0', + 'SELECT status, id FROM testdb.users' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/proxysql/FilterMerge.sql b/src/main/java/org/qed/Generated/proxysql/FilterMerge.sql new file mode 100644 index 0000000..ab08153 --- /dev/null +++ b/src/main/java/org/qed/Generated/proxysql/FilterMerge.sql @@ -0,0 +1,6 @@ +INSERT INTO mysql_query_rules (rule_id, active, match_pattern, replace_pattern) +VALUES ( + 10, 1, + '^SELECT \* FROM \(SELECT \* FROM (.*) WHERE (.*) = (.*)\) AS (.*) WHERE (.*) = (.*)', + 'SELECT * FROM \1 WHERE \2 = \3 AND \5 = \6' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/proxysql/FilterReduceFalse.sql b/src/main/java/org/qed/Generated/proxysql/FilterReduceFalse.sql new file mode 100644 index 0000000..0ae9c6c --- /dev/null +++ b/src/main/java/org/qed/Generated/proxysql/FilterReduceFalse.sql @@ -0,0 +1,6 @@ +INSERT INTO mysql_query_rules (rule_id, active, match_pattern, replace_pattern) +VALUES ( + 40, 1, + '^SELECT (.*) FROM (.*) WHERE FALSE', + 'SELECT \1 FROM \2 LIMIT 0' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/proxysql/FilterReduceTrue.sql b/src/main/java/org/qed/Generated/proxysql/FilterReduceTrue.sql new file mode 100644 index 0000000..4ca4ae4 --- /dev/null +++ b/src/main/java/org/qed/Generated/proxysql/FilterReduceTrue.sql @@ -0,0 +1,6 @@ +INSERT INTO mysql_query_rules (rule_id, active, match_pattern, replace_pattern) +VALUES ( + 50, 1, + '^SELECT (.*) FROM (.*) WHERE TRUE', + 'SELECT \1 FROM \2' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/proxysql/JoinCommute.sql b/src/main/java/org/qed/Generated/proxysql/JoinCommute.sql new file mode 100644 index 0000000..0d91e1f --- /dev/null +++ b/src/main/java/org/qed/Generated/proxysql/JoinCommute.sql @@ -0,0 +1,6 @@ +INSERT INTO mysql_query_rules (rule_id, active, match_pattern, replace_pattern) +VALUES ( + 30, 1, + '^SELECT \* FROM (.*) AS (.*?) INNER JOIN (.*) AS (.*?) ON (.*?)\.(.*?) = (.*?)\.(.*)', + 'SELECT * FROM \3 AS \4 INNER JOIN \1 AS \2 ON \7.\8 = \5.\6' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/proxysql/ProjectMerge.sql b/src/main/java/org/qed/Generated/proxysql/ProjectMerge.sql new file mode 100644 index 0000000..8af9ae2 --- /dev/null +++ b/src/main/java/org/qed/Generated/proxysql/ProjectMerge.sql @@ -0,0 +1,6 @@ +INSERT INTO mysql_query_rules (rule_id, active, match_pattern, replace_pattern) +VALUES ( + 20, 1, + '^SELECT (.*) FROM \(SELECT (.*) FROM (.*)\) AS (.*)', + 'SELECT \1 FROM \3' +); \ No newline at end of file diff --git a/src/main/java/org/qed/Generated/script-mysql.py b/src/main/java/org/qed/Generated/script-mysql.py new file mode 100644 index 0000000..14c8c6c --- /dev/null +++ b/src/main/java/org/qed/Generated/script-mysql.py @@ -0,0 +1,93 @@ +import mysql.connector +from pathlib import Path + +# Database connection info +MYSQL_USER = "root" +MYSQL_PASSWORD = "wkaiz" +MYSQL_DATABASE = "query_rewrite" + +# Paths (relative to script.py) +RULE_DIR = Path("mysql") +TEST_DIR = Path("Test-MySQL") + +# Connect to MySQL +conn = mysql.connector.connect( + host="localhost", + user=MYSQL_USER, + password=MYSQL_PASSWORD, + database=MYSQL_DATABASE +) +cursor = conn.cursor() + +# Iterate over all .sql files in rule directory +for rule_file in RULE_DIR.glob("*.sql"): + # Match test file (rule_file.stem + "test.sql") + test_file = TEST_DIR / f"{rule_file.stem}test.sql" + + if not test_file.exists(): + print(f"⚠️ No matching test file found for {rule_file.name}, skipping.") + continue + + print(f"\n=== Running rule {rule_file.name} with test {test_file.name} ===") + + # Load and execute rule SQL + with rule_file.open("r", encoding="utf-8") as f: + sql_commands = f.read() + + for cmd in sql_commands.split(";"): + cmd = cmd.strip() + if cmd: + try: + cursor.execute(cmd + ";") + except mysql.connector.Error as e: + print(f"❌ Error executing command in {rule_file.name}: {e}") + continue + + conn.commit() + print(f"{rule_file} executed successfully.") + + # Delete all rules except the last one + cursor.execute(""" + DELETE FROM rewrite_rules + WHERE id < ( + SELECT max_id FROM (SELECT MAX(id) AS max_id FROM rewrite_rules) AS t + ); + """) + conn.commit() + print("Deleted all rules except the last one.") + + # Flush rewrite rules + cursor.execute("CALL flush_rewrite_rules();") + conn.commit() + print("Flushed rewrite rules.") + + # Show current rules + cursor.execute("SELECT * FROM rewrite_rules;") + print("Current rules in table:") + for row in cursor.fetchall(): + print(row) + + # Load and run test query + with test_file.open("r", encoding="utf-8") as f: + test_query = f.read().strip() + + try: + cursor.execute(test_query) + results = cursor.fetchall() + print("\nTest query results:") + for row in results: + print(row) + except mysql.connector.Error as e: + print(f"❌ Error running test query {test_file.name}: {e}") + continue + + # Show warnings (should indicate rewrite) + cursor.execute("SHOW WARNINGS;") + warnings = cursor.fetchall() + print("\nWarnings (should indicate rewrite):") + for w in warnings: + print(w) + +# Cleanup +cursor.close() +conn.close() diff --git a/src/main/java/org/qed/Generated/script-proxysql.sh b/src/main/java/org/qed/Generated/script-proxysql.sh new file mode 100644 index 0000000..6ab1db8 --- /dev/null +++ b/src/main/java/org/qed/Generated/script-proxysql.sh @@ -0,0 +1,58 @@ +#!/bin/bash + +PROXYSQL_USER="admin" +PROXYSQL_PASS="admin" +PROXYSQL_HOST="127.0.0.1" +PROXYSQL_PORT="6032" + +MYSQL_USER="root" +MYSQL_PASS="wkaiz" +MYSQL_HOST="127.0.0.1" +MYSQL_PORT="6033" + +run_proxysql() { + local sql="$1" + docker exec -i proxysql mysql -u "$PROXYSQL_USER" -p"$PROXYSQL_PASS" -h "$PROXYSQL_HOST" -P"$PROXYSQL_PORT" -e "$sql" +} + +run_mysql() { + local sql="$1" + echo -e "\n➡️ Running MySQL command:\n$sql\n" + mysql -u "$MYSQL_USER" -p"$MYSQL_PASS" -h "$MYSQL_HOST" -P"$MYSQL_PORT" -e "$sql" + echo -e "\n----------------------------------------\n" +} + +for rule_file in proxysql/*.sql; do + base_name=$(basename "$rule_file" .sql) + test_file="Tests-ProxySQL/${base_name}Test.sql" + + echo -e "\n==============================" + echo "📄 Processing rule file: $rule_file" + echo "Corresponding test file: $test_file" + echo "==============================\n" + + sql_content=$(cat <(echo "USE main;") "$rule_file") + echo -e "➡️ Loading ProxySQL rule:\n$sql_content\n" + run_proxysql "$sql_content" + + run_proxysql "LOAD MYSQL QUERY RULES TO RUNTIME;" + run_proxysql "SAVE MYSQL QUERY RULES TO DISK;" + + echo -e "\n📊 ProxySQL stats after loading rule:" + run_proxysql "SELECT * FROM stats.stats_mysql_query_rules ORDER BY hits DESC;" + echo -e "\n----------------------------------------\n" + + test_sql=$(<"$test_file") + run_mysql "$test_sql" + + sleep 2 + echo -e "\n📊 ProxySQL stats after running test:" + run_proxysql "SELECT * FROM stats.stats_mysql_query_rules ORDER BY hits DESC;" + echo -e "\n----------------------------------------\n" + + echo "🧹 Cleaning up ProxySQL rules..." + run_proxysql "DELETE FROM mysql_query_rules;" + run_proxysql "LOAD MYSQL QUERY RULES TO RUNTIME;" + run_proxysql "SAVE MYSQL QUERY RULES TO DISK;" + echo -e "\n========================================\n" +done