├── tests ├── output │ └── .gitignore ├── complex.sql ├── basic.sql └── expected │ ├── complex.sql │ └── basic.sql ├── .github ├── FUNDING.yml └── workflows │ └── test.yml ├── .gitignore ├── Dockerfile ├── Makefile ├── LICENSE ├── litejq.c └── README.md /tests/output/.gitignore: -------------------------------------------------------------------------------- 1 | *.sql -------------------------------------------------------------------------------- /.github/FUNDING.yml: -------------------------------------------------------------------------------- 1 | github: [Florents-Tselai] 2 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .idea 2 | *.so 3 | *.out.sql 4 | litejq -------------------------------------------------------------------------------- /Dockerfile: -------------------------------------------------------------------------------- 1 | FROM ubuntu:noble 2 | RUN apt-get update 3 | RUN apt-get install -y build-essential pkg-config sqlite3 libsqlite3-dev libjq-dev git 4 | 5 | WORKDIR /litejq 6 | COPY . /litejq 7 | 8 | RUN make && make test 9 | -------------------------------------------------------------------------------- /tests/complex.sql: -------------------------------------------------------------------------------- 1 | .load ./litejq 2 | .echo on 3 | 4 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.'); 5 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.a'); 6 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.c'); 7 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.c[2]'); 8 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.c[2].f'); -------------------------------------------------------------------------------- /tests/basic.sql: -------------------------------------------------------------------------------- 1 | .load ./litejq 2 | .echo on 3 | 4 | select jq('{"a": "xyz"}', '.a') = 'xyz'; 5 | select jq('{"a": 100}', '.a') = 100; 6 | select jq('{"a": 100.0001}', '.a') = 100.0001; 7 | select jq('{"a": "sdfgdfg"}', '.b') ISNULL; 8 | select jq('{"a": 1}', '.a') = 1; 9 | select jq('{"a": true}', '.a') = 1; 10 | select jq('{"a": false}', '.a') = 0; -------------------------------------------------------------------------------- /tests/expected/complex.sql: -------------------------------------------------------------------------------- 1 | 2 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.'); 3 | {"a":2,"c":[4,5,{"f":7}]} 4 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.a'); 5 | 2 6 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.c'); 7 | [4,5,{"f":7}] 8 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.c[2]'); 9 | {"f":7} 10 | select jq('{"a":2,"c":[4,5,{"f":7}]}', '.c[2].f'); 11 | 7 12 | -------------------------------------------------------------------------------- /tests/expected/basic.sql: -------------------------------------------------------------------------------- 1 | 2 | select jq('{"a": "xyz"}', '.a') = 'xyz'; 3 | 1 4 | select jq('{"a": 100}', '.a') = 100; 5 | 1 6 | select jq('{"a": 100.0001}', '.a') = 100.0001; 7 | 1 8 | select jq('{"a": "sdfgdfg"}', '.b') ISNULL; 9 | 1 10 | select jq('{"a": 1}', '.a') = 1; 11 | 1 12 | select jq('{"a": true}', '.a') = 1; 13 | 1 14 | select jq('{"a": false}', '.a') = 0; 15 | 1 16 | -------------------------------------------------------------------------------- /.github/workflows/test.yml: -------------------------------------------------------------------------------- 1 | name: Test 2 | 3 | on: [ push, pull_request ] 4 | 5 | permissions: 6 | contents: read 7 | 8 | jobs: 9 | test: 10 | runs-on: ubuntu-latest 11 | steps: 12 | - name: 'Check Out' 13 | uses: actions/checkout@v3 14 | 15 | - name: Install dependencies 16 | run: | 17 | sudo apt update 18 | sudo apt install -y build-essential \ 19 | pkg-config \ 20 | autoconf \ 21 | libtool \ 22 | wget \ 23 | sqlite3 libsqlite3-dev libjq-dev 24 | 25 | - name: Build extension 26 | run: | 27 | make all 28 | 29 | - name: Run tests 30 | run: | 31 | make test 32 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | CC=gcc 2 | CFLAGS=-shared -fPIC 3 | SRC=litejq.c 4 | OUT=litejq 5 | PKG_CONFIG ?= pkg-config 6 | 7 | ifeq (no,$(shell $(PKG_CONFIG) jq || echo no)) 8 | $(warning "libjq not registed with pkg-config, build might fail. If it does, try setting JQ_PREFIX manually and run with `JQ_PREFIX=/path/to/dir make all`") 9 | LIBJQ_LIBS=-I$(JQ_PREFIX)/include -L$(JQ_PREFIX)/lib -ljq 10 | else 11 | LIBJQ_LIBS=$(shell $(PKG_CONFIG) --cflags --libs libjq) 12 | endif 13 | 14 | SQLITE3_LIBS=$(shell $(PKG_CONFIG) --cflags --libs sqlite3) 15 | 16 | all: $(OUT) 17 | 18 | $(OUT): $(SRC) 19 | $(CC) $(CFLAGS) -o $(OUT) $(SRC) $(SQLITE3_LIBS) $(LIBJQ_LIBS) 20 | 21 | .PHONY: run-test-% 22 | run-test-%: 23 | echo "running test: tests/$*.sql" 24 | sqlite3 :memory: tests/output/$*.sql 25 | diff tests/output/$*.sql tests/expected/$*.sql 26 | 27 | test: run-test-basic run-test-complex 28 | 29 | clean: 30 | -rm -f $(OUT) 31 | -rm tests/output/*.sql 32 | 33 | dev: clean all test 34 | 35 | .PHONY: dev 36 | .default: all 37 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2024 Florents Tselai 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. -------------------------------------------------------------------------------- /litejq.c: -------------------------------------------------------------------------------- 1 | #include 2 | 3 | SQLITE_EXTENSION_INIT1 4 | 5 | #include 6 | #include 7 | #include 8 | 9 | 10 | /* Forward declarations for the SQLite jq function */ 11 | static void jq_text_text(sqlite3_context *context, int argc, sqlite3_value **argv); 12 | 13 | /* Initialization function for the SQLite extension */ 14 | int sqlite3_litejq_init(sqlite3 *db, char **pzErrMsg, const sqlite3_api_routines *pApi) { 15 | SQLITE_EXTENSION_INIT2(pApi) 16 | // Register the jq function 17 | int rc = sqlite3_create_function(db, "jq", 2, SQLITE_UTF8, NULL, jq_text_text, NULL, NULL); 18 | if (rc != SQLITE_OK) { 19 | *pzErrMsg = sqlite3_mprintf("Failed to register function jq: %d", rc); 20 | return rc; 21 | } 22 | return SQLITE_OK; 23 | } 24 | 25 | 26 | /* Implementation of the jq(text, text) function */ 27 | static void jq_text_text(sqlite3_context *context, int argc, sqlite3_value **argv) { 28 | const char *input_json; 29 | const char *jq_program; 30 | jq_state *jq; 31 | jv input; 32 | jv result; 33 | 34 | if (argc != 2 || sqlite3_value_type(argv[0]) != SQLITE_TEXT || sqlite3_value_type(argv[1]) != SQLITE_TEXT) { 35 | sqlite3_result_error(context, "jq function requires exactly two TEXT arguments", -1); 36 | return; 37 | } 38 | 39 | input_json = (const char *) sqlite3_value_text(argv[0]); 40 | jq_program = (const char *) sqlite3_value_text(argv[1]); 41 | 42 | input = jv_parse(input_json); 43 | if (!jv_is_valid(input)) { 44 | sqlite3_result_error(context, "Invalid JSON input", -1); 45 | jv_free(input); 46 | return; 47 | } 48 | 49 | jq = jq_init(); 50 | if (jq_compile(jq, jq_program)) { 51 | jq_start(jq, input, 0); 52 | 53 | while (jv_is_valid(result = jq_next(jq))) { 54 | switch (jv_get_kind(result)) { 55 | case JV_KIND_NULL: 56 | sqlite3_result_null(context); 57 | break; 58 | case JV_KIND_FALSE: 59 | sqlite3_result_int(context, 0); 60 | break; 61 | case JV_KIND_TRUE: 62 | sqlite3_result_int(context, 1); 63 | break; 64 | case JV_KIND_NUMBER: 65 | if (jv_is_integer(result)) 66 | sqlite3_result_int(context, jv_number_value(result)); 67 | else 68 | sqlite3_result_double(context, jv_number_value(result)); 69 | break; 70 | case JV_KIND_STRING: { 71 | sqlite3_result_text(context, jv_string_value(result), -1, SQLITE_TRANSIENT); 72 | break; 73 | } 74 | /* SQLite doesn't have a dedicated JSON type, 75 | * thus we don't have to recurse into arrays and objects. 76 | * Instead we just dump a json-serialized version of the result. 77 | * */ 78 | case JV_KIND_ARRAY: 79 | case JV_KIND_OBJECT: { 80 | jv dumped = jv_dump_string(result, 0); 81 | sqlite3_result_text(context, jv_string_value(dumped), -1, SQLITE_TRANSIENT); 82 | jv_free(dumped); 83 | break; 84 | } 85 | default: 86 | sqlite3_result_error(context, "Unsupported JSON type", -1); 87 | break; 88 | } 89 | 90 | } // end while loop 91 | jv_free(result); 92 | 93 | } else { 94 | sqlite3_result_error(context, "Failed to compile jq program", -1); 95 | } 96 | jq_teardown(&jq); 97 | } 98 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # liteJQ: jq support in SQLite 2 | 3 | 4 | GitHub Repo stars 5 | Release 6 | 7 | 8 | 9 | 10 | 11 | **liteJQ** is an SQLite extension, written in C, that brings `jq` support to SQLite. 12 | It uses vanilla `libjq`. 13 | 14 | *Note*: If you like the idea, but you're more into Postgres, check out: [pgJQ: jq extension for Postgres](https://github.com/Florents-Tselai/pgJQ) 15 | 16 | ## Motivation 17 | 18 | SQLite has been supporting JSON for years. 19 | Complex queries, however, involving JSON can be more cumbersome to write and understand, 20 | especially when compared to more complex systems like PostgreSQL. 21 | **liteJQ** attempts to alleviate that by bringing the expressive power of jq into SQLite. 22 | 23 | ## Installation 24 | 25 | ```sh 26 | make 27 | ``` 28 | 29 | This produces a `litejq` binary object, which should be loaded in SQLite at runtime. 30 | 31 | Verify the installation. 32 | 33 | ```sh 34 | sqlite3 :memory: < 1980'); 99 | ``` 100 | The above query is equivalent to this one 101 | ```sql 102 | select jq(d, '{title: .title, year: .year}') 103 | from movies 104 | where jq(d, '.year') > 1980; 105 | ``` 106 | 107 | **Extract Movies with Specific Keywords in Extract** 108 | 109 | ```sql 110 | select jq(d, '.extract') 111 | from movies 112 | where jq(d, '.extract | contains("silent")'); 113 | ``` 114 | 115 | **Filter movies by a specific genre (e.g., Drama)** 116 | 117 | ```sql 118 | select jq(d, '{title: .title, year: .year, genres: .genres}') 119 | from movies 120 | where jq(d, '.genres[] == "Drama"'); 121 | ``` 122 | 123 | **Filter movies where "Joan Lorring" and "John Dall" played together** 124 | 125 | ```sql 126 | select jq(d, '{title: .title, year: .year, cast: .cast}') 127 | from movies 128 | where jq(d, '.cast | contains(["Joan Lorring", "John Dall"])'); 129 | ``` 130 | 131 | **Group by movies by release year** 132 | 133 | ```sql 134 | select jq(d, '.year'), count(*) 135 | from movies 136 | group by jq(d, '.year') 137 | ``` 138 | 139 | ## Notes On Installation 140 | 141 | For this to work, you'll need development files for both SQLite and jq. 142 | 143 | ### MacOS 144 | 145 | ```sh 146 | brew install jq sqlite3 147 | make all 148 | ``` 149 | 150 | I've found that `brew` installs header files auomatically for you, 151 | so there's nothing else you have to do 152 | 153 | Verify installation 154 | 155 | ```sh 156 | sqlite3 :memory: <