forked from sheetjs/docs.sheetjs.com
171 lines
4.6 KiB
Markdown
171 lines
4.6 KiB
Markdown
|
---
|
||
|
title: Knex SQL Builder
|
||
|
pagination_prev: demos/desktop/index
|
||
|
pagination_next: demos/local/index
|
||
|
sidebar_custom_props:
|
||
|
sql: true
|
||
|
---
|
||
|
|
||
|
:::note
|
||
|
|
||
|
This demo was last tested on 2023 April 19 with Knex 2.4.2 and `better-sqlite`.
|
||
|
|
||
|
:::
|
||
|
|
||
|
## Integration Details
|
||
|
|
||
|
#### Importing Data
|
||
|
|
||
|
`sheet_to_json` generates an array of objects. An `INSERT` statement can be
|
||
|
generated from each row object using `knex.insert`:
|
||
|
|
||
|
```js
|
||
|
const aoo = XLSX.utils.sheet_to_json(ws);
|
||
|
for(let i = 0; i < aoo.length; ++i) await knex.insert(aoo[i]).into(table_name);
|
||
|
```
|
||
|
|
||
|
#### Exporting Data
|
||
|
|
||
|
The result of a `SELECT` statement is an array of objects:
|
||
|
|
||
|
```js
|
||
|
const aoo = await knex.select("*").from(table_name);
|
||
|
const worksheet = XLSX.utils.json_to_sheet(aoo);
|
||
|
```
|
||
|
|
||
|
## Complete Example
|
||
|
|
||
|
1) Install dependencies:
|
||
|
|
||
|
```bash
|
||
|
npm i --save https://cdn.sheetjs.com/xlsx-latest/xlsx-latest.tgz knex better-sqlite3
|
||
|
```
|
||
|
|
||
|
2) Download the [test file](https://sheetjs.com/pres.numbers)
|
||
|
|
||
|
```bash
|
||
|
curl -LO https://sheetjs.com/pres.numbers
|
||
|
```
|
||
|
|
||
|
3) Save the following utility script to `sheetjsknex.js`:
|
||
|
|
||
|
```js title="sheetjsknex.js"
|
||
|
const XLSX = require("xlsx");
|
||
|
|
||
|
// define mapping between determined types and Knex types
|
||
|
const PG = { "n": "float", "s": "text", "b": "boolean" };
|
||
|
|
||
|
async function ws_to_knex(knex, ws, table_name) {
|
||
|
|
||
|
// generate an array of objects from the data
|
||
|
const aoo = XLSX.utils.sheet_to_json(ws);
|
||
|
|
||
|
// types will map column headers to types, while hdr holds headers in order
|
||
|
const types = {}, hdr = [];
|
||
|
|
||
|
// loop across each row object
|
||
|
aoo.forEach(row =>
|
||
|
// Object.entries returns a row of [key, value] pairs. Loop across those
|
||
|
Object.entries(row).forEach(([k,v]) => {
|
||
|
|
||
|
// If this is first time seeing key, mark unknown and append header array
|
||
|
if(!types[k]) { types[k] = "?"; hdr.push(k); }
|
||
|
|
||
|
// skip null and undefined
|
||
|
if(v == null) return;
|
||
|
|
||
|
// check and resolve type
|
||
|
switch(typeof v) {
|
||
|
case "string": // strings are the broadest type
|
||
|
types[k] = "s"; break;
|
||
|
case "number": // if column is not string, number is the broadest type
|
||
|
if(types[k] != "s") types[k] = "n"; break;
|
||
|
case "boolean": // only mark boolean if column is unknown or boolean
|
||
|
if("?b".includes(types[k])) types[k] = "b"; break;
|
||
|
default: types[k] = "s"; break; // default to string type
|
||
|
}
|
||
|
})
|
||
|
);
|
||
|
|
||
|
await knex.schema.dropTableIfExists(table_name);
|
||
|
|
||
|
// use column type info to create table
|
||
|
await knex.schema.createTable(table_name, (table) => { hdr.forEach(h => { table[PG[types[h]] || "text"](h); }); });
|
||
|
|
||
|
// insert each non-empty row object
|
||
|
for(let i = 0; i < aoo.length; ++i) {
|
||
|
if(!aoo[i] || !Object.keys(aoo[i]).length) continue;
|
||
|
try { await knex.insert(aoo[i]).into(table_name); } catch(e) {}
|
||
|
}
|
||
|
return knex;
|
||
|
}
|
||
|
|
||
|
async function knex_to_ws(knex, table_name) {
|
||
|
const aoo = await knex.select("*").from(table_name);
|
||
|
return XLSX.utils.json_to_sheet(aoo);
|
||
|
}
|
||
|
|
||
|
module.exports = { ws_to_knex, knex_to_ws };
|
||
|
```
|
||
|
|
||
|
4) Save the following to `SheetJSKnexTest.js`:
|
||
|
|
||
|
```js title="SheetJSKnexTest.js"
|
||
|
const { ws_to_knex, knex_to_ws } = require("./sheetjsknex");
|
||
|
const Knex = require('knex');
|
||
|
|
||
|
/* read file and get first worksheet */
|
||
|
const XLSX = require("xlsx");
|
||
|
const oldwb = XLSX.readFile("pres.numbers");
|
||
|
const wsname = oldwb.SheetNames[0];
|
||
|
const oldws = oldwb.Sheets[wsname];
|
||
|
|
||
|
(async() => {
|
||
|
/* open connection to SheetJSKnex.db */
|
||
|
let knex = Knex({ client: 'better-sqlite3', connection: { filename: "SheetJSKnex.db" } });
|
||
|
try {
|
||
|
/* load data into database and close connection */
|
||
|
await ws_to_knex(knex, oldws, "Test_Table");
|
||
|
} finally { knex.destroy(); }
|
||
|
|
||
|
/* reconnect to SheetJSKnex.db */
|
||
|
knex = Knex({ client: 'better-sqlite3', connection: { filename: "SheetJSKnex.db" } });
|
||
|
try {
|
||
|
/* get data from db */
|
||
|
const aoo = await knex.select("*").from("Test_Table");
|
||
|
|
||
|
/* export to file */
|
||
|
const newws = await knex_to_ws(knex, "Test_Table");
|
||
|
const newwb = XLSX.utils.book_new();
|
||
|
XLSX.utils.book_append_sheet(newwb, newws, "Export");
|
||
|
XLSX.writeFile(newwb, "SheetJSKnex.xlsx");
|
||
|
} finally { knex.destroy(); }
|
||
|
})();
|
||
|
```
|
||
|
|
||
|
This script will read `pres.numbers` and load data into a table `Test_Table`.
|
||
|
The SQLite database will be saved to `SheetJSKnex.db`.
|
||
|
|
||
|
After closing the connection, the script will make a new connection and export
|
||
|
data to `SheetJSKnex.xlsx`.
|
||
|
|
||
|
5) Run the script:
|
||
|
|
||
|
```bash
|
||
|
node SheetJSKnexTest.js
|
||
|
```
|
||
|
|
||
|
The script will generate two artifacts:
|
||
|
|
||
|
`SheetJSKnex.xlsx` can be opened in a spreadsheet app or tested in the terminal:
|
||
|
|
||
|
```bash
|
||
|
npx xlsx-cli SheetJSKnex.xlsx
|
||
|
```
|
||
|
|
||
|
`SheetJSKnex.db` can be verified with the `sqlite3` command line tool:
|
||
|
|
||
|
```bash
|
||
|
sqlite3 SheetJSKnex.db 'select * from Test_Table'
|
||
|
```
|