forked from sheetjs/docs.sheetjs.com
idb
This commit is contained in:
parent
dbe0554b9b
commit
def028682c
@ -16,15 +16,19 @@ The public demo <https://sheetjs.com/sql> generates a database from workbook.
|
||||
## WebSQL Details
|
||||
|
||||
Importing data from spreadsheets is straightforward using the `generate_sql`
|
||||
helper function from ["Generating Tables"](/docs/demos/data/sql#generating-tables):
|
||||
helper function from ["Generating Tables"](/docs/demos/data/sql#generating-tables).
|
||||
|
||||
The Web SQL Database API is callback-based. The following snippet wraps
|
||||
transactions in Promise objects:
|
||||
|
||||
```js
|
||||
const db = openDatabase('sheetql', '1.0', 'SheetJS WebSQL Test', 2097152);
|
||||
const stmts = generate_sql(ws, wsname);
|
||||
|
||||
// NOTE: tx.executeSql and db.transaction use callbacks. This wraps in Promises
|
||||
for(var i = 0; i < stmts.length; ++i) await new Promise((res, rej) => {
|
||||
for(var stmt of stmts) await new Promise((res, rej) => {
|
||||
db.transaction(tx =>
|
||||
tx.executeSql(stmts[i], [],
|
||||
tx.executeSql(stmt, [],
|
||||
(tx, data) => res(data), // if the query is successful, return the data
|
||||
(tx, err) => rej(err) // if the query fails, reject with the error
|
||||
));
|
||||
@ -33,23 +37,29 @@ for(var i = 0; i < stmts.length; ++i) await new Promise((res, rej) => {
|
||||
|
||||
The result of a SQL SELECT statement is a `SQLResultSet`. The `rows` property
|
||||
is a `SQLResultSetRowList`. It is an "array-like" structure that has `length`
|
||||
and properties like `0`, `1`, etc. However, this is not a real Array object.
|
||||
and properties like `0`, `1`, etc. However, this is not a real Array object!
|
||||
|
||||
A real Array can be created using `Array.from`:
|
||||
|
||||
```js
|
||||
const db = openDatabase('sheetql', '1.0', 'SheetJS WebSQL Test', 2097152);
|
||||
db.readTransaction(tx =>
|
||||
tx.executeSQL("SELECT * FROM DatabaseTable", [], (tx, data) => {
|
||||
// data.rows is "array-like", so `Array.from` can make it a real array
|
||||
const aoo = Array.from(data.rows);
|
||||
const ws = XLSX.utils.json_to_sheet(aoo);
|
||||
// ... it is recommended to perform an export here OR wrap in a Promise
|
||||
// ... perform an export here OR wrap in a Promise
|
||||
})
|
||||
);
|
||||
```
|
||||
|
||||
### Live Demo
|
||||
|
||||
:::note
|
||||
|
||||
This demo was last tested on 2023 February 26
|
||||
|
||||
:::
|
||||
|
||||
The following demo generates a database with 5 fixed SQL statements. Queries
|
||||
can be changed in the Live Editor. The WebSQL database can be inspected in the
|
||||
"WebSQL" section of the "Application" Tab of Developer Tools:
|
||||
@ -67,16 +77,16 @@ function SheetQL() {
|
||||
'INSERT INTO Presidents (Name, Idx) VALUES ("Joseph Biden", 46)'
|
||||
];
|
||||
const xport = React.useCallback(async() => {
|
||||
// prep database
|
||||
/* prep database */
|
||||
const db = openDatabase('sheetql', '1.0', 'SheetJS WebSQL Test', 2097152);
|
||||
|
||||
for(var i = 0; i < queries.length; ++i) await new Promise((res, rej) => {
|
||||
for(var q of queries) await new Promise((res, rej) => {
|
||||
db.transaction((tx) => {
|
||||
tx.executeSql(queries[i], [], (tx, data) => res(data), (tx, err) => rej(err));
|
||||
tx.executeSql(q, [], (tx, data) => res(data), (tx, err) => rej(err));
|
||||
});
|
||||
});
|
||||
|
||||
// pull data and generate rows
|
||||
/* pull data and generate rows */
|
||||
db.readTransaction(tx => {
|
||||
tx.executeSql("SELECT * FROM Presidents", [], (tx, data) => {
|
||||
const aoo = Array.from(data.rows);
|
||||
@ -102,16 +112,24 @@ export as XLSX.
|
||||
|
||||
[The Northwind database is available in SQLite form](https://raw.githubusercontent.com/jpwhite3/northwind-SQLite3/master/dist/northwind.db).
|
||||
|
||||
:::note
|
||||
|
||||
This demo was last tested on 2023 February 26
|
||||
|
||||
:::
|
||||
|
||||
### NodeJS
|
||||
|
||||
The **`better-sqlite3`** module provides a very simple API for working with
|
||||
SQLite databases. `Statement#all` runs a prepared statement and returns an array
|
||||
of JS objects.
|
||||
|
||||
0) [Download `northwind.db`](https://raw.githubusercontent.com/jpwhite3/northwind-SQLite3/master/dist/northwind.db).
|
||||
|
||||
1) Install the dependencies:
|
||||
|
||||
```bash
|
||||
npm i --save https://cdn.sheetjs.com/xlsx-latest/xlsx-latest.tgz better-sqlite3
|
||||
npm i --save https://cdn.sheetjs.com/xlsx-latest/xlsx-latest.tgz better-sqlite3@8.1.0
|
||||
```
|
||||
|
||||
2) Save the following to `node.mjs`:
|
||||
@ -157,6 +175,8 @@ XLSX.writeFile(wb, "node.xlsx");
|
||||
|
||||
Bun ships with a built-in high-performance module `bun:sqlite`.
|
||||
|
||||
0) [Download `northwind.db`](https://raw.githubusercontent.com/jpwhite3/northwind-SQLite3/master/dist/northwind.db).
|
||||
|
||||
1) Install the dependencies:
|
||||
|
||||
```bash
|
||||
@ -206,6 +226,8 @@ XLSX.writeFile(wb, "bun.xlsx");
|
||||
|
||||
Deno `sqlite` library returns raw arrays of arrays.
|
||||
|
||||
0) [Download `northwind.db`](https://raw.githubusercontent.com/jpwhite3/northwind-SQLite3/master/dist/northwind.db).
|
||||
|
||||
1) Save the following to `deno.ts`:
|
||||
|
||||
```ts title="deno.ts"
|
||||
@ -244,4 +266,4 @@ result.forEach(function(row) {
|
||||
XLSX.writeFile(wb, "deno.xlsx");
|
||||
```
|
||||
|
||||
3) Run `deno run --allow-read --allow-write deno.ts` and open `deno.xlsx`
|
||||
2) Run `deno run --allow-read --allow-write deno.ts` and open `deno.xlsx`
|
||||
|
@ -6,26 +6,228 @@ sidebar_custom_props:
|
||||
type: web
|
||||
---
|
||||
|
||||
<head>
|
||||
<script type="text/javascript" src="https://unpkg.com/localforage@1.10.0/dist/localforage.min.js"></script>
|
||||
<script type="text/javascript" src="https://unpkg.com/dexie@3.2.3/dist/dexie.js"></script>
|
||||
</head>
|
||||
|
||||
:::warning
|
||||
|
||||
IndexedDB is a very low-level API. It is strongly recommended to use a wrapper
|
||||
library or [WebSQL](/docs/demos/data/websql) in production applications.
|
||||
IndexedDB is a very low-level API.
|
||||
|
||||
Browser vendors recommend using libraries or [WebSQL](/docs/demos/data/websql)
|
||||
in production applications.
|
||||
|
||||
:::
|
||||
|
||||
## Wrapper Libraries
|
||||
|
||||
A number of popular wrapper libraries seek to simplify IndexedDB operations.
|
||||
|
||||
:::note
|
||||
|
||||
The wrapper libraries in this section have been used by SheetJS users in
|
||||
production sites.
|
||||
|
||||
:::
|
||||
|
||||
### localForage
|
||||
|
||||
:::note
|
||||
|
||||
This demo was last tested on 2023 February 26 with `localForage` 1.10.0
|
||||
|
||||
:::
|
||||
|
||||
`localForage` is a IndexedDB wrapper that presents an async Storage interface.
|
||||
|
||||
Arrays of objects can be stored using `JSON.stringify` using row index as key:
|
||||
Arrays of objects can be stored using `setItem` using row index as key:
|
||||
|
||||
```js
|
||||
const aoo = XLSX.utils.sheet_to_json(ws);
|
||||
for(var i = 0; i < aoo.length; ++i) await localForage.setItem(i, JSON.stringify(aoo[i]));
|
||||
for(var i = 0; i < aoo.length; ++i) await localForage.setItem(i, aoo[i]);
|
||||
```
|
||||
|
||||
Recovering the array of objects is possible by using `JSON.parse`:
|
||||
Recovering the array of objects involves an iteration over the storage:
|
||||
|
||||
```js
|
||||
const aoo = [];
|
||||
for(var i = 0; i < localForage.length; ++i) aoo.push(JSON.parse(await localForage.getItem(i)));
|
||||
const wb = XLSX.utils.json_to_sheet(aoo);
|
||||
await localforage.iterate((v, k) => { aoa[+k] = v; });
|
||||
const ws = XLSX.utils.json_to_sheet(aoo);
|
||||
```
|
||||
|
||||
#### Demo
|
||||
|
||||
This demo prepares a small IndexedDB database with some sample data.
|
||||
|
||||
After saving the exported file, the IndexedDB database can be inspected in the
|
||||
"IndexedDB" section of the "Application" Tab of Developer Tools:
|
||||
|
||||
![IndexedDB view in Developer Tools](pathname:///storageapi/lforage.png)
|
||||
|
||||
```jsx live
|
||||
function SheetJSLocalForage() {
|
||||
const data = [
|
||||
{ Name: "Barack Obama", Index: 44 },
|
||||
{ Name: "Donald Trump", Index: 45 },
|
||||
{ Name: "Joseph Biden", Index: 46 }
|
||||
];
|
||||
const xport = React.useCallback(async() => {
|
||||
/* force use of IndexedDB and connect to DB */
|
||||
localforage.config({
|
||||
driver: [ localforage.INDEXEDDB ],
|
||||
name: "SheetQL",
|
||||
size: 2097152
|
||||
});
|
||||
|
||||
/* create sample data */
|
||||
await localforage.clear();
|
||||
for(var i = 0; i < data.length; ++i) await localforage.setItem(i, data[i]);
|
||||
|
||||
/* pull data and generate aoa */
|
||||
const aoo = [];
|
||||
await localforage.iterate((v, k) => { aoo[+k] = v; });
|
||||
|
||||
/* export */
|
||||
const ws = XLSX.utils.json_to_sheet(aoo);
|
||||
const wb = XLSX.utils.book_new();
|
||||
XLSX.utils.book_append_sheet(wb, ws, "Presidents");
|
||||
XLSX.writeFile(wb, "SheetJSLocalForage.xlsx");
|
||||
});
|
||||
return ( <pre><button onClick={xport}><b>Do it!</b></button></pre> );
|
||||
}
|
||||
```
|
||||
|
||||
### DexieJS
|
||||
|
||||
:::note
|
||||
|
||||
This demo was last tested on 2023 February 26 with DexieJS 3.2.3
|
||||
|
||||
:::
|
||||
|
||||
DexieJS is a minimalistic wrapper for IndexedDB. It provides a convenient
|
||||
interface for creating multiple logical tables, well-suited for workbooks.
|
||||
|
||||
#### Importing Data
|
||||
|
||||
When configuring tables, DexieJS needs a schema. The schema definition supports
|
||||
primary keys and other properties, but they are not required:
|
||||
|
||||
```js
|
||||
/* assuming `wb` is a workbook from XLSX.read */
|
||||
var db = new Dexie("SheetJSDexie");
|
||||
db.version(1).stores(Object.fromEntries(wb.SheetNames.map(n => ([n, "++"]))));
|
||||
```
|
||||
|
||||
After the database is configured, `bulkPut` can insert arrays of objects:
|
||||
|
||||
```js
|
||||
/* loop over worksheet names */
|
||||
for(let i = 0; i <= wb.SheetNames.length; ++i) {
|
||||
/* get the worksheet for the specified index */
|
||||
const wsname = wb.SheetNames[i];
|
||||
const ws = wb.Sheets[wsname];
|
||||
if(!ws) continue;
|
||||
/* generate an array of objects */
|
||||
const aoo = XLSX.utils.sheet_to_json(ws);
|
||||
/* push to idb */
|
||||
await db[wsname].bulkPut(aoo);
|
||||
}
|
||||
```
|
||||
|
||||
This demo inserts all data from a selected worksheet into a database, then
|
||||
fetches the data from the first worksheet in reverse:
|
||||
|
||||
```jsx live
|
||||
/* The live editor requires this function wrapper */
|
||||
function SheetJSDexieImport(props) {
|
||||
const [__html, setHTML] = React.useState("Select a spreadsheet");
|
||||
|
||||
return (<>
|
||||
<input type="file" onChange={async(e) => { try {
|
||||
/* get data as an ArrayBuffer */
|
||||
const file = e.target.files[0];
|
||||
const data = await file.arrayBuffer();
|
||||
|
||||
/* parse worksheet */
|
||||
const wb = XLSX.read(data);
|
||||
|
||||
/* load into indexeddb */
|
||||
await Dexie.delete("SheetJSDexie");
|
||||
const db = new Dexie("SheetJSDexie");
|
||||
const wsnames = wb.SheetNames.map(n => ([n, "++"]));
|
||||
db.version(1).stores(Object.fromEntries(wsnames));
|
||||
|
||||
/* loop over worksheet names */
|
||||
for(let i = 0; i <= wb.SheetNames.length; ++i) {
|
||||
/* get the worksheet for the specified index */
|
||||
const wsname = wb.SheetNames[i];
|
||||
const ws = wb.Sheets[wsname];
|
||||
if(!ws) continue;
|
||||
/* generate an array of objects */
|
||||
const aoo = XLSX.utils.sheet_to_json(ws);
|
||||
/* push to idb */
|
||||
await db[wsname].bulkPut(aoo);
|
||||
}
|
||||
|
||||
/* fetch the first table in reverse order */
|
||||
const rev = await db[wb.SheetNames[0]].reverse().toArray();
|
||||
|
||||
setHTML(rev.map(r => JSON.stringify(r)).join("\n"));
|
||||
} catch(e) { setHTML(e && e.message || e); }}}/>
|
||||
<pre dangerouslySetInnerHTML={{ __html }}/>
|
||||
</>);
|
||||
}
|
||||
```
|
||||
|
||||
#### Exporting Data
|
||||
|
||||
`db.tables` is a plain array of table objects. `toArray` fetches data:
|
||||
|
||||
```js
|
||||
/* create blank workbook */
|
||||
const wb = XLSX.utils.book_new();
|
||||
/* loop tables */
|
||||
for(const table of db.tables) {
|
||||
/* get data */
|
||||
const aoo = await table.toArray();
|
||||
/* create worksheet */
|
||||
const ws = XLSX.utils.json_to_sheet(aoo);
|
||||
/* add to workbook */
|
||||
XLSX.utils.book_append_sheet(wb, ws, table.name);
|
||||
}
|
||||
```
|
||||
|
||||
This demo prepares a small database with some sample data.
|
||||
|
||||
```jsx live
|
||||
function SheetJSDexieExport() {
|
||||
const data = [
|
||||
{ Name: "Barack Obama", Index: 44 },
|
||||
{ Name: "Donald Trump", Index: 45 },
|
||||
{ Name: "Joseph Biden", Index: 46 }
|
||||
];
|
||||
const xport = React.useCallback(async() => {
|
||||
/* prepare db */
|
||||
await Dexie.delete("SheetJSDexie");
|
||||
var db = new Dexie("SheetJSDexie");
|
||||
db.version(1).stores({ Presidents: "++" });
|
||||
db.Presidents.bulkPut(data);
|
||||
|
||||
/* pull data and generate workbook */
|
||||
const wb = XLSX.utils.book_new();
|
||||
for(const table of db.tables) {
|
||||
const aoo = await table.toArray();
|
||||
const ws = XLSX.utils.json_to_sheet(aoo);
|
||||
XLSX.utils.book_append_sheet(wb, ws, table.name);
|
||||
}
|
||||
XLSX.writeFile(wb, "SheetJSDexie.xlsx");
|
||||
});
|
||||
return ( <pre><button onClick={xport}><b>Do it!</b></button></pre> );
|
||||
}
|
||||
```
|
||||
|
||||
### AlaSQL
|
||||
|
||||
[AlaSQL](/docs/demos/data/alasql) ships with an IndexedDB backend.
|
BIN
docz/static/storageapi/lforage.png
Normal file
BIN
docz/static/storageapi/lforage.png
Normal file
Binary file not shown.
After Width: | Height: | Size: 72 KiB |
Loading…
Reference in New Issue
Block a user