2023-02-24 07:46:48 +00:00
|
|
|
---
|
|
|
|
title: AlaSQL
|
2023-02-28 11:40:44 +00:00
|
|
|
pagination_prev: demos/desktop/index
|
|
|
|
pagination_next: demos/local/index
|
2023-02-24 07:46:48 +00:00
|
|
|
sidebar_custom_props:
|
|
|
|
sql: true
|
|
|
|
---
|
|
|
|
|
|
|
|
import current from '/version.js';
|
|
|
|
|
|
|
|
AlaSQL is a pure JavaScript in-memory SQL database. It has built-in support for
|
|
|
|
SheetJS through the `XLSX` target operator.
|
|
|
|
|
|
|
|
This demo covers basic concepts pertaining to data import and export. The
|
|
|
|
official documentation includes advanced examples and deployment tips as well as
|
|
|
|
strategies for general data processing in AlaSQL expressions.
|
|
|
|
|
|
|
|
## NodeJS Usage
|
|
|
|
|
|
|
|
:::caution
|
|
|
|
|
|
|
|
`alasql` uses an older version of the library. It can be overridden through a
|
|
|
|
`package.json` override in the latest versions of NodeJS:
|
|
|
|
|
|
|
|
<pre><code parentName="pre" {...{"className": "language-json"}}>{`\
|
|
|
|
{
|
|
|
|
"overrides": {
|
|
|
|
"xlsx": "https://cdn.sheetjs.com/xlsx-${current}/xlsx-${current}.tgz"
|
|
|
|
}
|
|
|
|
}`}
|
|
|
|
</code></pre>
|
|
|
|
|
|
|
|
:::
|
|
|
|
|
|
|
|
#### Reading Files
|
|
|
|
|
|
|
|
By default, the `XLSX` "from" target automatically adds a `.xlsx` extension. To
|
|
|
|
read files with an arbitrary filename, the `autoExt: false` option should be
|
|
|
|
passed as the second argument:
|
|
|
|
|
|
|
|
```sql
|
|
|
|
SELECT `Name`, `Index` FROM XLSX(
|
|
|
|
"pres.numbers" --<< filename is "pres.numbers"
|
|
|
|
// highlight-start
|
|
|
|
, { --<< options are supplied as the second argument to XLSX operator
|
|
|
|
autoExt: false --<< do not automatically add ".xlsx" extension!
|
|
|
|
}
|
|
|
|
// highlight-end
|
|
|
|
) WHERE `Index` < 45
|
|
|
|
```
|
|
|
|
|
|
|
|
By default the workbook is parsed and `sheet_to_json` is used to pull data:
|
|
|
|
|
|
|
|
```js
|
|
|
|
const { promise: alasql } = require("alasql");
|
|
|
|
|
|
|
|
(async() => {
|
|
|
|
const aoo = await alasql(`SELECT * from XLSX("pres.xlsb", {autoExt: false})`);
|
|
|
|
console.log(aoo); // [ { Name: "Bill Clinton", Index: 42 }, ...]
|
|
|
|
})();
|
|
|
|
```
|
|
|
|
|
|
|
|
#### Writing Files
|
|
|
|
|
|
|
|
The `XLSX` "into" target calls `XLSX.writeFile` under the hood:
|
|
|
|
|
|
|
|
```js
|
|
|
|
const { promise: alasql } = require("alasql");
|
|
|
|
|
|
|
|
(async() => {
|
|
|
|
const data = [
|
|
|
|
{ Name: "Bill Clinton", Index: 42 },
|
|
|
|
{ Name: "Someone Else", Index: 47 }
|
|
|
|
];
|
|
|
|
await alasql(`SELECT * INTO XLSX("PresMod5.xlsb") FROM ?`, [data]);
|
|
|
|
/* PresMod5.xlsb will be created */
|
|
|
|
})();
|
|
|
|
```
|
|
|
|
|
|
|
|
### NodeJS Example
|
|
|
|
|
|
|
|
:::note
|
|
|
|
|
|
|
|
This demo was tested on 2023 February 23 against AlaSQL 3.1.0
|
|
|
|
|
|
|
|
:::
|
|
|
|
|
|
|
|
1) Create an empty folder for the project:
|
|
|
|
|
|
|
|
```bash
|
|
|
|
mkdir alasql
|
|
|
|
cd alasql
|
|
|
|
```
|
|
|
|
|
|
|
|
2) In the folder, create a stub `package.json` with the `xlsx` override:
|
|
|
|
|
|
|
|
```json title="package.json"
|
|
|
|
{
|
|
|
|
"overrides": {
|
|
|
|
"xlsx": "https://cdn.sheetjs.com/xlsx-latest/xlsx-latest.tgz"
|
|
|
|
}
|
|
|
|
}
|
|
|
|
```
|
|
|
|
|
|
|
|
3) Install SheetJS and AlaSQL:
|
|
|
|
|
|
|
|
```bash
|
|
|
|
npm i --save alasql@3.1.0 https://cdn.sheetjs.com/xlsx-latest/xlsx-latest.tgz
|
|
|
|
```
|
|
|
|
|
|
|
|
4) Download the test file <https://sheetjs.com/pres.numbers> :
|
|
|
|
|
|
|
|
```bash
|
|
|
|
curl -LO https://sheetjs.com/pres.numbers
|
|
|
|
```
|
|
|
|
|
|
|
|
5) Save the following test script to `SheetJSAlaSQL.js`:
|
|
|
|
|
|
|
|
```js title="SheetJSAlaSQL.js"
|
|
|
|
const { promise: alasql } = require("alasql");
|
|
|
|
|
|
|
|
(async() => {
|
|
|
|
/* read data from spreadsheet to JS */
|
|
|
|
const data = await alasql(`
|
|
|
|
SELECT \`Name\`, \`Index\`
|
|
|
|
FROM XLSX("pres.numbers", {autoExt:false})
|
|
|
|
WHERE \`Index\` < 45
|
|
|
|
`);
|
|
|
|
console.log(data);
|
|
|
|
|
|
|
|
/* write data from JS to spreadsheet */
|
|
|
|
data.push({Name: "Someone Else", Index: 47});
|
|
|
|
await alasql(`SELECT * INTO XLSX("SheetJSAlaSQL1.xlsx") FROM ?`, [data]);
|
|
|
|
})();
|
|
|
|
```
|
|
|
|
|
|
|
|
6) Run the test script
|
|
|
|
|
|
|
|
```bash
|
|
|
|
node SheetJSAlaSQL.js
|
|
|
|
```
|
|
|
|
|
|
|
|
The output should display:
|
|
|
|
|
|
|
|
```
|
|
|
|
[
|
|
|
|
{ Name: 'Bill Clinton', Index: 42 },
|
|
|
|
{ Name: 'GeorgeW Bush', Index: 43 },
|
|
|
|
{ Name: 'Barack Obama', Index: 44 }
|
|
|
|
]
|
|
|
|
```
|
|
|
|
|
|
|
|
The script should generate `SheetJSAlaSQL1.xlsx` with the additional row:
|
|
|
|
|
|
|
|
```csv
|
|
|
|
Name,Index
|
|
|
|
Bill Clinton,42
|
|
|
|
GeorgeW Bush,43
|
|
|
|
Barack Obama,44
|
|
|
|
Someone Else,47
|
|
|
|
```
|