From e4a23b86e0fa6d297961c6bef236b71c47b5a456 Mon Sep 17 00:00:00 2001 From: Scott Gress Date: Mon, 1 Dec 2025 22:04:25 -0600 Subject: [PATCH 1/2] update reserved words list, add alias rules --- pegjs/sqlite.pegjs | 181 +++++++++++++++++++++++++++----------------- test/sqlite.spec.js | 16 ++++ 2 files changed, 129 insertions(+), 68 deletions(-) diff --git a/pegjs/sqlite.pegjs b/pegjs/sqlite.pegjs index ba96572b..7d90f917 100644 --- a/pegjs/sqlite.pegjs +++ b/pegjs/sqlite.pegjs @@ -1,103 +1,136 @@ { const reservedMap = { - 'ALTER': true, - 'ALL': true, 'ADD': true, + 'ALL': true, + 'ALTER': true, 'AND': true, 'AS': true, - 'ASC': true, - + 'AUTOINCREMENT': true, 'BETWEEN': true, - 'BY': true, - - 'CALL': true, 'CASE': true, + 'CHECK': true, + 'COLLATE': true, + 'COMMIT': true, + 'CONSTRAINT': true, 'CREATE': true, - 'CONTAINS': true, - 'COUNT': true, - 'CURRENT_DATE': true, - 'CURRENT_TIME': true, - 'CURRENT_TIMESTAMP': true, - 'CURRENT_USER': true, - + 'DEFAULT': true, + 'DEFERRABLE': true, 'DELETE': true, - 'DESC': true, 'DISTINCT': true, 'DROP': true, - 'ELSE': true, - 'END': true, + 'ESCAPE': true, + 'EXCEPT': true, 'EXISTS': true, - 'EXPLAIN': true, - - 'FALSE': true, + 'FOREIGN': true, 'FROM': true, - 'FULL': true, - - 'GENERATED': true, 'GROUP': true, - 'HAVING': true, - 'IN': true, - 'INNER': true, + 'INDEX': true, 'INSERT': true, + 'INTERSECT': true, 'INTO': true, 'IS': true, - + 'ISNULL': true, 'JOIN': true, - // 'JSON': true, - - // 'KEY': true, - - 'LEFT': true, - 'LIKE': true, 'LIMIT': true, - 'LOW_PRIORITY': true, // for lock table - 'NOT': true, + 'NOTHING': true, + 'NOTNULL': true, 'NULL': true, - 'ON': true, 'OR': true, 'ORDER': true, - 'OUTER': true, - - 'RECURSIVE': true, - 'RENAME': true, - 'READ': true, // for lock table - 'RIGHT': true, - + 'PRIMARY': true, + 'REFERENCES': true, + 'RETURNING': true, 'SELECT': true, - 'SESSION_USER': true, 'SET': true, - 'SHOW': true, - 'SYSTEM_USER': true, - 'TABLE': true, 'THEN': true, - 'TRUE': true, - 'TRUNCATE': true, - // 'TYPE': true, // reserved (MySQL) - + 'TO': true, + 'TRANSACTION': true, 'UNION': true, + 'UNIQUE': true, 'UPDATE': true, 'USING': true, - 'VALUES': true, - - 'WITH': true, 'WHEN': true, 'WHERE': true, - 'WRITE': true, // for lock table - - 'GLOBAL': true, - 'SESSION': true, - 'LOCAL': true, - 'PERSIST': true, - 'PERSIST_ONLY': true, }; + const invalidImplicitAliasMap = { + 'INDEXED': true, + 'INDEX': true, + 'ESCAPE': true, + 'CHECK': true, + 'FOREIGN': true, + 'REGEXP': true, + 'ADD': true, + 'AS': true, + 'SELECT': true, + 'TABLE': true, + 'LEFT': true, + 'THEN': true, + 'DEFERRABLE': true, + 'ELSE': true, + 'DELETE': true, + 'OR': true, + 'INTERSECT': true, + 'NOT': true, + 'NULL': true, + 'LIKE': true, + 'EXCEPT': true, + 'TRANSACTION': true, + 'ON': true, + 'NATURAL': true, + 'ALTER': true, + 'EXISTS': true, + 'CONSTRAINT': true, + 'INTO': true, + 'SET': true, + 'HAVING': true, + 'GLOB': true, + 'INNER': true, + 'REFERENCES': true, + 'UNIQUE': true, + 'OUTER': true, + 'BETWEEN': true, + 'NOTHING': true, + 'GROUP': true, + 'DEFAULT': true, + 'CASE': true, + 'COLLATE': true, + 'CREATE': true, + 'JOIN': true, + 'INSERT': true, + 'MATCH': true, + 'DISTINCT': true, + 'IS': true, + 'UPDATE': true, + 'VALUES': true, + 'WHEN': true, + 'WHERE': true, + 'AND': true, + 'DROP': true, + 'AUTOINCREMENT': true, + 'TO': true, + 'IN': true, + 'COMMIT': true, + 'CROSS': true, + 'FROM': true, + 'FULL': true, + 'LIMIT': true, + 'ORDER': true, + 'RETURNING': true, + 'RIGHT': true, + 'UNION': true, + 'USING': true, + 'ALL': true, + 'PRIMARY': true + } + function getLocationObject() { return options.includeLocations ? {loc: location()} : {} } @@ -777,15 +810,15 @@ use_stmt alter_table_stmt = KW_ALTER __ KW_TABLE __ - t:table_ref_list __ + t:table_name __ e:alter_action_list { - if (t && t.length > 0) t.forEach(table => tableList.add(`alter::${table.db}::${table.table}`)); + tableList.add(`alter::${t.db}::${t.table}`) return { tableList: Array.from(tableList), columnList: columnListTableAlias(columnList), ast: { type: 'alter', - table: t, + table: [t], expr: e } }; @@ -1514,8 +1547,8 @@ column_list_item } alias_clause - = KW_AS ___ i:alias_ident { return i; } - / KW_AS? __ i:ident { return i; } + = KW_AS __ i:alias_ident_explicit { return i; } + / i:alias_ident_implicit { return i; } from_clause = KW_FROM __ l:table_ref_list { return l; } @@ -2332,16 +2365,28 @@ ident return name; } -alias_ident +alias_ident_explicit = name:ident_name !{ if (reservedMap[name.toUpperCase()] === true) throw new Error("Error: "+ JSON.stringify(name)+" is a reserved word, can not as alias clause"); return false } { return name; } - / name:quoted_ident { + / name:quoted_ident { return name; } + +alias_ident_implicit + = name:ident_name !{ + // reject reserved words + if (reservedMap[name.toUpperCase()] === true) return true; + + // reject invalid implicit alias words + if (invalidImplicitAliasMap[name.toUpperCase()] === true) return true; + + return false; + } { return name; } + / name:quoted_ident { return name; } quoted_ident_type = double_quoted_ident / single_quoted_ident / backticks_quoted_ident diff --git a/test/sqlite.spec.js b/test/sqlite.spec.js index fa2d9344..eaf85ea6 100644 --- a/test/sqlite.spec.js +++ b/test/sqlite.spec.js @@ -300,4 +300,20 @@ describe('sqlite', () => { expect(getParsedSql(sql)).to.be.equal(sql) }); }); + it('should allow column names that are keywords, but not reserved words, without quotes', () => { + const sql = `SELECT partition FROM some_table` + expect(getParsedSql(sql)).to.be.equal('SELECT "partition" FROM "some_table"') + }) + it('should allow column names that are reserved words with quotes', () => { + const sql = `SELECT "from" FROM some_table` + expect(getParsedSql(sql)).to.be.equal('SELECT "from" FROM "some_table"') + }) + it('should allow table names that are keywords, but not reserved words, without quotes', () => { + const sql = `CREATE TABLE partition (foo integer)` + expect(getParsedSql(sql)).to.be.equal('CREATE TABLE "partition" ("foo" INTEGER)') + }) + it('should allow explict aliases that would be invalid as implicit aliases', () => { + const sql = `SELECT * FROM foo as left where left.bar=1` + expect(getParsedSql(sql)).to.be.equal('SELECT * FROM "foo" AS "left" WHERE "left"."bar" = 1') + }) }) From 61ab23f9c3aff61bf48cb05418ce62ebbf2b159c Mon Sep 17 00:00:00 2001 From: Scott Gress Date: Mon, 1 Dec 2025 23:01:59 -0600 Subject: [PATCH 2/2] reorder, update joins --- pegjs/sqlite.pegjs | 115 +++++++++++++++++++++++--------------------- test/sqlite.spec.js | 27 +++++++++++ 2 files changed, 88 insertions(+), 54 deletions(-) diff --git a/pegjs/sqlite.pegjs b/pegjs/sqlite.pegjs index 7d90f917..4d2a26c2 100644 --- a/pegjs/sqlite.pegjs +++ b/pegjs/sqlite.pegjs @@ -61,74 +61,74 @@ }; const invalidImplicitAliasMap = { - 'INDEXED': true, - 'INDEX': true, - 'ESCAPE': true, - 'CHECK': true, - 'FOREIGN': true, - 'REGEXP': true, 'ADD': true, - 'AS': true, - 'SELECT': true, - 'TABLE': true, - 'LEFT': true, - 'THEN': true, - 'DEFERRABLE': true, - 'ELSE': true, - 'DELETE': true, - 'OR': true, - 'INTERSECT': true, - 'NOT': true, - 'NULL': true, - 'LIKE': true, - 'EXCEPT': true, - 'TRANSACTION': true, - 'ON': true, - 'NATURAL': true, + 'ALL': true, 'ALTER': true, - 'EXISTS': true, - 'CONSTRAINT': true, - 'INTO': true, - 'SET': true, - 'HAVING': true, - 'GLOB': true, - 'INNER': true, - 'REFERENCES': true, - 'UNIQUE': true, - 'OUTER': true, + 'AND': true, + 'AS': true, + 'AUTOINCREMENT': true, 'BETWEEN': true, - 'NOTHING': true, - 'GROUP': true, - 'DEFAULT': true, 'CASE': true, + 'CHECK': true, 'COLLATE': true, + 'COMMIT': true, + 'CONSTRAINT': true, 'CREATE': true, - 'JOIN': true, - 'INSERT': true, - 'MATCH': true, + 'CROSS': true, + 'DEFAULT': true, + 'DEFERRABLE': true, + 'DELETE': true, 'DISTINCT': true, - 'IS': true, - 'UPDATE': true, - 'VALUES': true, - 'WHEN': true, - 'WHERE': true, - 'AND': true, 'DROP': true, - 'AUTOINCREMENT': true, - 'TO': true, - 'IN': true, - 'COMMIT': true, - 'CROSS': true, + 'ELSE': true, + 'ESCAPE': true, + 'EXCEPT': true, + 'EXISTS': true, + 'FOREIGN': true, 'FROM': true, 'FULL': true, + 'GLOB': true, + 'GROUP': true, + 'HAVING': true, + 'IN': true, + 'INDEX': true, + 'INDEXED': true, + 'INNER': true, + 'INSERT': true, + 'INTERSECT': true, + 'INTO': true, + 'IS': true, + 'JOIN': true, + 'LEFT': true, + 'LIKE': true, 'LIMIT': true, + 'MATCH': true, + 'NATURAL': true, + 'NOT': true, + 'NOTHING': true, + 'NULL': true, + 'ON': true, + 'OR': true, 'ORDER': true, + 'OUTER': true, + 'PRIMARY': true, + 'REFERENCES': true, + 'REGEXP': true, 'RETURNING': true, 'RIGHT': true, + 'SELECT': true, + 'SET': true, + 'TABLE': true, + 'THEN': true, + 'TO': true, + 'TRANSACTION': true, 'UNION': true, + 'UNIQUE': true, + 'UPDATE': true, 'USING': true, - 'ALL': true, - 'PRIMARY': true + 'VALUES': true, + 'WHEN': true, + 'WHERE': true, } function getLocationObject() { @@ -1681,8 +1681,11 @@ table_base } join_op - = KW_LEFT __ KW_OUTER? __ KW_JOIN { return 'LEFT JOIN'; } - / (KW_INNER __)? KW_JOIN { return 'INNER JOIN'; } + = natural:(KW_NATURAL __)? KW_LEFT __ KW_OUTER? __ KW_JOIN { return natural ? 'NATURAL LEFT JOIN' : 'LEFT JOIN'; } + / natural:(KW_NATURAL __)? KW_RIGHT __ KW_OUTER? __ KW_JOIN { return natural ? 'NATURAL RIGHT JOIN' : 'RIGHT JOIN'; } + / natural:(KW_NATURAL __)? KW_FULL __ KW_OUTER? __ KW_JOIN { return natural ? 'NATURAL FULL JOIN' : 'FULL JOIN'; } + / natural:(KW_NATURAL __)? (KW_INNER __)? KW_JOIN { return natural ? 'NATURAL INNER JOIN' : 'INNER JOIN'; } + / KW_CROSS __ KW_JOIN { return 'CROSS JOIN'; } table_name = dt:ident tail:(__ DOT __ ident)? { @@ -2817,7 +2820,11 @@ KW_COLLATE = "COLLATE"i !ident_start { return 'COLLATE'; } KW_ON = "ON"i !ident_start KW_LEFT = "LEFT"i !ident_start +KW_RIGHT = "RIGHT"i !ident_start +KW_CROSS = "CROSS"i !ident_start +KW_FULL = "FULL"i !ident_start KW_INNER = "INNER"i !ident_start +KW_NATURAL = "NATURAL"i !ident_start KW_JOIN = "JOIN"i !ident_start KW_OUTER = "OUTER"i !ident_start KW_OVER = "OVER"i !ident_start diff --git a/test/sqlite.spec.js b/test/sqlite.spec.js index eaf85ea6..41082425 100644 --- a/test/sqlite.spec.js +++ b/test/sqlite.spec.js @@ -316,4 +316,31 @@ describe('sqlite', () => { const sql = `SELECT * FROM foo as left where left.bar=1` expect(getParsedSql(sql)).to.be.equal('SELECT * FROM "foo" AS "left" WHERE "left"."bar" = 1') }) + + describe('joins', () => { + const joinTypes = { + 'LEFT JOIN': 'LEFT JOIN', + 'LEFT OUTER JOIN': 'LEFT JOIN', + 'RIGHT JOIN': 'RIGHT JOIN', + 'RIGHT OUTER JOIN': 'RIGHT JOIN', + 'FULL JOIN': 'FULL JOIN', + 'FULL OUTER JOIN': 'FULL JOIN', + 'INNER JOIN': 'INNER JOIN', + 'NATURAL LEFT JOIN': 'NATURAL LEFT JOIN', + 'NATURAL RIGHT JOIN': 'NATURAL RIGHT JOIN', + 'NATURAL FULL JOIN': 'NATURAL FULL JOIN', + 'NATURAL INNER JOIN': 'NATURAL INNER JOIN', + 'NATURAL LEFT OUTER JOIN': 'NATURAL LEFT JOIN', + 'NATURAL RIGHT OUTER JOIN': 'NATURAL RIGHT JOIN', + 'NATURAL FULL OUTER JOIN': 'NATURAL FULL JOIN', + 'CROSS JOIN': 'CROSS JOIN', + 'JOIN': 'INNER JOIN', + } + Object.keys(joinTypes).forEach(joinType => { + it(`should support ${joinType}`, () => { + const sql = `SELECT * FROM table1 ${joinType} table2 ON table1.id = table2.t1_id` + expect(getParsedSql(sql)).to.be.equal(`SELECT * FROM "table1" ${joinTypes[joinType]} "table2" ON "table1"."id" = "table2"."t1_id"`) + }) + }) + }) })