--- title: Sheets with SQLite sidebar_label: SQLite pagination_prev: demos/cli/index pagination_next: demos/local/index sidebar_custom_props: sql: true ---
import current from '/version.js'; import CodeBlock from '@theme/CodeBlock'; [SQLite](https://sqlite.org/) is a lightweight embeddable SQL database engine. There are connector libraries for many popular JavaScript server-side platforms. [SheetJS](https://sheetjs.com) is a JavaScript library for reading and writing data from spreadsheets. This demo uses SQLite and SheetJS to exchange data between spreadsheets and SQL servers. We'll explore how to use save tables from a database to spreadsheets and how to add data from spreadsheets into a database. :::info pass This demo covers SQLite `.db` file processing. The [WebSQL demo](/docs/demos/local/websql) covers the Web SQL Database API, a SQLite-compatible database built into Chromium and Google Chrome. ::: :::note Tested Deployments This demo was tested in the following environments: | Platform | Connector Library | Date | |:-----------------|:---------------------------|:-----------| | Chromium 119 | `sql.js` (`1.8.0`) | 2023-12-04 | | NodeJS `20.10.0` | `better-sqlite3` (`9.2.0`) | 2023-12-04 | | BunJS `1.0.15` | (built-in) | 2023-12-04 | | Deno `1.38.4` | `sqlite` (`3.8`) | 2023-12-04 | ::: ## Demo The following examples show how to query for each table in an SQLite database, query for the data for each table, add each non-empty table to a workbook, and export as XLSX. #### Sample Database The Chinook database is a MIT-licensed sample database. The original source code repository `http://chinookdatabase.codeplex.com` is no longer available, so the [raw SQL queries are mirrored here](pathname:///sqlite/chinook.sql). ### Exporting Data Connector libraries typically provide a way to generate an array of objects from the result of a `SELECT` query. For example, using `better-sqlite3` in NodeJS: ```js import Database from "better-sqlite3"; /* open database */ var db = Database("chinook.db"); /* get data from the `Invoice` table */ var aoo = db.prepare("SELECT * FROM 'Invoice' LIMIT 100000").all(); ``` The SheetJS `json_to_sheet` method[^1] can take the result and generate a worksheet object[^2]. The `book_new` and `book_append_sheet` methods[^3] help build a workbook object[^4]. The `writeFile` method[^5] generates a file: ```js import * as XLSX from "xlsx"; /* Create Worksheet from the row objects */ var ws = XLSX.utils.json_to_sheet(aoo, {dense: true}); /* Add to Workbook */ XLSX.utils.book_append_sheet(wb, ws, "Sheet1"); /* Write File */ XLSX.writeFile(wb, "SheetJSQLiteNode.xlsx"); ``` ### Importing Data The ["Generating Tables"](/docs/demos/data/sql#generating-tables) section includes a code snippet for generating SQLite-compatible SQL queries from a SheetJS worksheet object. Each query can be run sequentially. ## Browser `sql.js`[^6] is a compiled version of SQLite into WebAssembly, making it usable in web browsers. SQLite database files can be `fetch`ed and loaded: ```js /* Load sql.js library */ const SQL = await initSqlJs(config); /* fetch sqlite database */ const ab = await (await fetch("/sqlite/chinook.db")).arrayBuffer(); /* connect to DB */ const db = new SQL.Database(new Uint8Array(ab)); ``` The `sql.js` connector library uses an iterator-like interface. After preparing a statement, `Statement#step` loops over the result and `Statement#getAsObject` pulls each row as a row object: ```js /* perform query and get iterator */ const sql = db.prepare("SELECT * FROM 'Invoice' LIMIT 100000").all(); /* create worksheet from the row objects */ let ws; while(sql.step()) { const row = sql.getAsObject(); if(!ws) ws = XLSX.utils.json_to_sheet([row], {dense: true, header}); else XLSX.utils.sheet_add_json(ws, [row], { header, origin: -1, skipHeader: true}); } ``` ### Demo This demo fetches [`chinook.db`](pathname:///sqlite/chinook.db), loads into the SQLite engine and performs a series of queries to extract the data. Worksheets are created from the data. A workbook is created from the worksheets and exported to a XLSX file. ```jsx live function SheetJSQLJS() { return () } ``` ## Server-Side Platforms ### NodeJS The `better-sqlite3`[^7] native module embeds the SQLite C library. `Statement#all` runs a prepared statement and returns an array of objects: ```js import Database from "better-sqlite3"; import * as XLSX from "xlsx"; /* open database */ var db = Database("chinook.db"); /* get data from the `Invoice` table */ var aoo = db.prepare("SELECT * FROM 'Invoice' LIMIT 100000").all(); /* create worksheet from the row objects */ var ws = XLSX.utils.json_to_sheet(aoo, {dense: true}); ``` #### NodeJS Demo 0) Build `chinook.db` from [the SQL statements](pathname:///sqlite/chinook.sql): ```bash curl -LO https://docs.sheetjs.com/sqlite/chinook.sql sqlite3 chinook.db ".read chinook.sql" ``` 1) Install the dependencies: