diff --git a/lib/sql-js/README.md b/lib/sql-js/README.md index f2e3870..bc9a023 100644 --- a/lib/sql-js/README.md +++ b/lib/sql-js/README.md @@ -13,6 +13,21 @@ SQLite [amalgamation][2] extensions included: 1. [FTS5][4] -- virtual table module that provides full-text search functionality +2. [FTS3/FTS4][15] -- older virtual table modules for full-text search +3. [JSON1][16] -- scalar, aggregate and table-valued functions for managing JSON data + +SQLite [contribution extensions][17]: + +1. [extension-functions][18] -- mathematical and string extension functions for SQL queries. + + Math: `acos`, `asin`, `atan`, `atn2`, `atan2`, `acosh`, `asinh`, `atanh`, `difference`, + `degrees`, `radians`, `cos`, `sin`, `tan`, `cot`, `cosh`, `sinh`, `tanh`, `coth`, + `exp`, `log`, `log10`, `power`, `sign`, `sqrt`, `square`, `ceil`, `floor`, `pi`. + + String: `replicate`, `charindex`, `leftstr`, `rightstr`, `ltrim`, `rtrim`, `trim`, + `replace`, `reverse`, `proper`, `padl`, `padr`, `padc`, `strfilter`. + + Aggregate: `stdev`, `variance`, `mode`, `median`, `lower_quartile`, `upper_quartile`. SQLite [miscellaneous extensions][3] included: @@ -21,6 +36,9 @@ SQLite [miscellaneous extensions][3] included: [Querying Tree Structures in SQLite][11] ([closure.c][8]) 3. `uuid`, `uuid_str` and `uuid_blob` RFC-4122 UUID functions ([uuid.c][9]) 4. `regexp` (hence `REGEXP` operator) and `regexpi` functions ([regexp.c][10]) +5. `percentile` function ([percentile.c][13]) +6. `decimal`, `decimal_cmp`, `decimal_add`, `decimal_sub` and `decimal_mul` functions + ([decimal.c][14]) SQLite 3rd party extensions included: @@ -29,6 +47,9 @@ SQLite 3rd party extensions included: To ease the step to have working clone locally, the build is committed into the repository. +Examples of queries involving these extensions can be found in the test suite in +[sqliteExtensions.spec.js][19]. + ## Build method Basically it's extended amalgamation and `SQLITE_EXTRA_INIT` concisely @@ -71,3 +92,10 @@ described in [this message from SQLite Forum][12]: [10]: https://sqlite.org/src/file/ext/misc/regexp.c [11]: https://charlesleifer.com/blog/querying-tree-structures-in-sqlite-using-python-and-the-transitive-closure-extension/ [12]: https://sqlite.org/forum/forumpost/6ad7d4f4bebe5e06?raw +[13]: https://sqlite.org/src/file/ext/misc/percentile.c +[14]: https://sqlite.org/src/file/ext/misc/decimal.c +[15]: https://sqlite.org/fts3.html +[16]: https://sqlite.org/json1.html +[17]: https://sqlite.org/contrib/ +[18]: https://sqlite.org/contrib//download/extension-functions.c?get=25 +[19]: https://github.com/lana-k/sqliteviz/blob/master/tests/lib/database/sqliteExtensions.spec.js diff --git a/lib/sql-js/configure.py b/lib/sql-js/configure.py index 16c965b..ae8be3e 100644 --- a/lib/sql-js/configure.py +++ b/lib/sql-js/configure.py @@ -24,6 +24,8 @@ extension_urls = ( ('https://sqlite.org/src/raw/dbfd8543?at=closure.c', 'sqlite3_closure_init'), ('https://sqlite.org/src/raw/5bb2264c?at=uuid.c', 'sqlite3_uuid_init'), ('https://sqlite.org/src/raw/5853b0e5?at=regexp.c', 'sqlite3_regexp_init'), + ('https://sqlite.org/src/raw/b9086e22?at=percentile.c', 'sqlite3_percentile_init'), + ('https://sqlite.org/src/raw/09f967dc?at=decimal.c', 'sqlite3_decimal_init'), # Third-party extension # ===================== ('https://github.com/jakethaw/pivot_vtab/raw/08ab0797/pivot_vtab.c', 'sqlite3_pivotvtab_init'), diff --git a/lib/sql-js/dist/sql-wasm.wasm b/lib/sql-js/dist/sql-wasm.wasm index 3ceb678..62858d6 100755 Binary files a/lib/sql-js/dist/sql-wasm.wasm and b/lib/sql-js/dist/sql-wasm.wasm differ diff --git a/tests/lib/database/sqliteExtensions.spec.js b/tests/lib/database/sqliteExtensions.spec.js index 32004f0..2961378 100644 --- a/tests/lib/database/sqliteExtensions.spec.js +++ b/tests/lib/database/sqliteExtensions.spec.js @@ -269,6 +269,48 @@ describe('SQLite extensions', function () { }) }) + it('supports percentile', async function () { + const actual = await db.execute(` + CREATE TABLE s(x INTEGER); + INSERT INTO s VALUES (15), (20), (35), (40), (50); + + SELECT + percentile(x, 5) p5, + percentile(x, 30) p30, + percentile(x, 40) p40, + percentile(x, 50) p50, + percentile(x, 100) p100 + FROM s; + `) + expect(actual.values).to.eql({ + p5: [16], + p30: [23], + p40: [29], + p50: [35], + p100: [50] + }) + }) + + it('supports decimal', async function () { + const actual = await db.execute(` + select + decimal_add(decimal('0.1'), decimal('0.2')) "add", + decimal_sub(0.2, 0.1) sub, + decimal_mul(power(2, 69), 2) mul, + decimal_cmp(decimal('0.1'), 0.1) cmp_e, + decimal_cmp(decimal('0.1'), decimal('0.099999')) cmp_g, + decimal_cmp(decimal('0.199999'), decimal('0.2')) cmp_l + `) + expect(actual.values).to.eql({ + add: ['0.3'], + sub: ['0.1'], + mul: ['1180591620717412000000'], + cmp_e: [0], + cmp_g: [1], + cmp_l: [-1] + }) + }) + it('supports FTS5', async function () { const actual = await db.execute(` CREATE VIRTUAL TABLE email USING fts5(sender, title, body, tokenize = 'porter ascii'); @@ -296,4 +338,96 @@ describe('SQLite extensions', function () { sender: ['bar@localhost'] }) }) + + it('supports FTS3', async function () { + const actual = await db.execute(` + CREATE VIRTUAL TABLE email USING fts3(sender, title, body, tokenize = 'porter'); + + INSERT INTO email VALUES + ( + 'foo@localhost', + 'fts3/4', + 'FTS3 and FTS4 are SQLite virtual table modules that allows users to perform ' + || 'full-text searches on a set of documents.' + ), + ( + 'bar@localhost', + 'fts4', + 'FTS5 is an SQLite virtual table module that provides full-text search ' + || 'functionality to database applications.' + ); + + SELECT sender + FROM email + WHERE body MATCH '("full-text" NOT document AND (functionality OR table))'; + `) + expect(actual.values).to.eql({ + sender: ['bar@localhost'] + }) + }) + + it('supports FTS4', async function () { + const actual = await db.execute(` + CREATE VIRTUAL TABLE email USING fts4( + sender, title, body, notindexed=sender, tokenize='simple' + ); + + INSERT INTO email VALUES + ( + 'foo@localhost', + 'fts3/4', + 'FTS3 and FTS4 are SQLite virtual table modules that allows users to perform ' + || 'full-text searches on a set of documents.' + ), + ( + 'bar@localhost', + 'fts4', + 'FTS5 is an SQLite virtual table module that provides full-text search ' + || 'functionality to database applications.' + ); + + SELECT sender + FROM email + WHERE body MATCH '("full-text" NOT document AND (functionality OR table NOT modules))'; + `) + expect(actual.values).to.eql({ + sender: ['bar@localhost'] + }) + }) + + it('supports JSON1', async function () { + const actual = await db.execute(` + WITH input(filename) AS ( + VALUES + ('/etc/redis/redis.conf'), + ('/run/redis/redis-server.pid'), + ('/var/log/redis-server.log') + ), tmp AS ( + SELECT + filename, + '["' || replace(filename, '/', '", "') || '"]' as filename_array + FROM input + ) + SELECT ( + SELECT group_concat(ip.value, '/') + FROM json_each(filename_array) ip + WHERE ip.id <= p.id + ) AS path + FROM tmp, json_each(filename_array) AS p + WHERE p.id > 1 -- because the filenames start with the separator + `) + expect(actual.values).to.eql({ + path: [ + '/etc', + '/etc/redis', + '/etc/redis/redis.conf', + '/run', + '/run/redis', + '/run/redis/redis-server.pid', + '/var', + '/var/log', + '/var/log/redis-server.log' + ] + }) + }) })