| 
									
										
										
										
											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 | 
					
						
							|  |  |  | --- | 
					
						
							|  |  |  | 
 | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  | <head> | 
					
						
							|  |  |  |   <script src="/alasql/alasql.js"></script> | 
					
						
							|  |  |  | </head> | 
					
						
							|  |  |  | 
 | 
					
						
							| 
									
										
										
										
											2023-02-24 07:46:48 +00:00
										 |  |  | 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. | 
					
						
							|  |  |  | 
 | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  | :::note | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | This demo was tested in the following environments: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | | Environment         | AlaSQL |    Date    | | 
					
						
							|  |  |  | |:--------------------|:-------|:----------:| | 
					
						
							|  |  |  | | NodeJS              | 3.1.0  | 2023-02-23 | | 
					
						
							|  |  |  | | Standalone (Chrome) | 3.0.0  | 2023-04-09 | | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ::: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ## Live Demo
 | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | This demo fetches <https://sheetjs.com/pres.numbers>, performs a `SELECT` query | 
					
						
							|  |  |  | using the built-in AlaSQL + SheetJS integration, then displays the result. Using | 
					
						
							|  |  |  | the result as a data source, the demo will write to a new spreadsheet. | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | <details><summary><b>Demo AlaSQL Queries</b> (click to show)</summary> | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```sql title="AlaSQL Query for reading data from a workbook" | 
					
						
							|  |  |  | SELECT `Index`,          -- "Index" field is the "Index" column of the sheet | 
					
						
							|  |  |  |   UPPER(`Name`) AS `Nom` -- "Nom" field will be uppercase of "Name" column | 
					
						
							|  |  |  | FROM XLSX(?, {           -- Parse the workbook bytes passed to alasql.promise | 
					
						
							|  |  |  |   autoExt: false         -- This option is required in the browser | 
					
						
							|  |  |  | }) | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```sql title="AlaSQL Query for writing data to a workbook" | 
					
						
							|  |  |  | SELECT *                 -- use every field from every row in dataset | 
					
						
							|  |  |  | INTO XLSX(               -- export data to file | 
					
						
							|  |  |  |   "SheetJSAlaSQL.xlsx"   -- filename for export | 
					
						
							|  |  |  | ) FROM ? | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | </details> | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | :::caution | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | If the live demo shows a message | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | alasql undefined | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | please refresh the page.  This is a known bug in the documentation generator. | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ::: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```jsx live | 
					
						
							|  |  |  | function SheetJSAlaSQL() { | 
					
						
							|  |  |  |   const q1 = "SELECT `Index`, UPPER(`Name`) AS `Nom` FROM XLSX(?,{autoExt:false})"; | 
					
						
							|  |  |  |   const q2 = `SELECT * INTO XLSX("SheetJSAlaSQL.xlsx") FROM ?`; | 
					
						
							|  |  |  |   const url = "https://sheetjs.com/pres.numbers"; | 
					
						
							|  |  |  |   const [rows, setRows] = React.useState([]); | 
					
						
							|  |  |  |   const loadURL = React.useCallback(async() => { | 
					
						
							|  |  |  |     if(typeof alasql=="undefined") return setRows([{Nom:"alasql undefined"}]); | 
					
						
							|  |  |  |     const blob = await (await fetch(url)).blob(); | 
					
						
							|  |  |  |     const data = URL.createObjectURL(blob); | 
					
						
							| 
									
										
										
										
											2023-04-18 20:26:59 +00:00
										 |  |  |     const res = await alasql.promise(q1,[data]); | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  |     setRows(res); | 
					
						
							|  |  |  |     await alasql.promise(q2, [res]); | 
					
						
							|  |  |  |   }, []); | 
					
						
							|  |  |  |   return ( <> | 
					
						
							|  |  |  |     <pre><b>URL: </b>{url}<br/><b>Import: </b>{q1}<br/><b>Export: </b>{q2}</pre> | 
					
						
							|  |  |  |     <table><tr><th>Index</th><th>Nom</th></tr> | 
					
						
							|  |  |  |       {rows.map(({Nom, Index}) => <tr><td>{Index}</td><td>{Nom}</td></tr>)} | 
					
						
							|  |  |  |     </table> | 
					
						
							|  |  |  |     <button onClick={loadURL}>Click to start</button> | 
					
						
							|  |  |  |   </> ); | 
					
						
							|  |  |  | } | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ## Browser
 | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | #### Standalone Scripts
 | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | The [Standalone scripts](/docs/getting-started/installation/standalone) should | 
					
						
							|  |  |  | be loaded before the `alasql` script: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```html | 
					
						
							|  |  |  | <script src="https://cdn.sheetjs.com/xlsx-latest/package/dist/shim.min.js"></script> | 
					
						
							|  |  |  | <script src="https://cdn.sheetjs.com/xlsx-latest/package/dist/xlsx.full.min.js"></script> | 
					
						
							|  |  |  | <script src="https://cdn.jsdelivr.net/npm/alasql"></script> | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | #### Frameworks and Bundlers
 | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | `alasql` uses an older version of the library.  It can be overridden through a | 
					
						
							|  |  |  | `package.json` override. The lines should be added *before* installing `alasql`: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | <pre><code parentName="pre" {...{"className": "language-json"}}>{`\ | 
					
						
							|  |  |  | { | 
					
						
							|  |  |  |   /* add this part before "name" */ | 
					
						
							|  |  |  |   /* highlight-start */ | 
					
						
							|  |  |  |   "overrides": { | 
					
						
							|  |  |  |     "xlsx": "https://cdn.sheetjs.com/xlsx-${current}/xlsx-${current}.tgz" | 
					
						
							|  |  |  |   }, | 
					
						
							|  |  |  |   /* highlight-end */ | 
					
						
							|  |  |  |   "name": "my-project", | 
					
						
							|  |  |  |   /* ... more fields ... */ | 
					
						
							|  |  |  | `} | 
					
						
							|  |  |  | </code></pre> | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | After adding the override, AlaSQL can be installed through `npm`: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```bash | 
					
						
							|  |  |  | npm install --save alasql | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | In imports, the SheetJS library must be passed to AlaSQL as shown below: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```js | 
					
						
							|  |  |  | import * as alasql from 'alasql'; | 
					
						
							|  |  |  | import * as XLSX from 'xlsx'; | 
					
						
							|  |  |  | alasql.utils.isBrowserify = false; | 
					
						
							|  |  |  | alasql.utils.global.XLSX = XLSX; | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ### Reading Files
 | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | The `XLSX` "from" target expects a filename. In the browser, AlaSQL uses object | 
					
						
							|  |  |  | URLs which can be created from `Blob` or `File` objects. | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | The following snippet fetches data and passes to AlaSQL: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```js | 
					
						
							|  |  |  | const blob = await (await fetch("https://sheetjs.com/pres.numbers")).blob(); | 
					
						
							| 
									
										
										
										
											2023-04-19 20:03:23 +00:00
										 |  |  | const data = URL.createObjectURL(blob); | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  | const res = await alasql.promise("SELECT * FROM XLSX(?, {autoExt: false}", [data]); | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | By default, the `XLSX` "from" target automatically adds a `.xlsx` extension.  To | 
					
						
							|  |  |  | read URLs, the `autoExt: false` option should be passed as the second argument: | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ```sql | 
					
						
							|  |  |  | SELECT `Name`, `Index` FROM XLSX( | 
					
						
							|  |  |  |   ? --<< this will be the URL passed into `alasql.promise` | 
					
						
							|  |  |  | // 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 | 
					
						
							|  |  |  | (async() => { | 
					
						
							|  |  |  |   const blob = await (await fetch("https://sheetjs.com/pres.numbers")).blob(); | 
					
						
							| 
									
										
										
										
											2023-04-19 20:03:23 +00:00
										 |  |  |   const data = URL.createObjectURL(blob); | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  |   const aoo = await alasql.promise("SELECT * FROM XLSX(?, {autoExt: false}", [data]); | 
					
						
							|  |  |  |   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.xlsx") FROM ?`, [data]); | 
					
						
							|  |  |  |   /* PresMod5.xlsx will be created */ | 
					
						
							|  |  |  | })(); | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ## NodeJS
 | 
					
						
							| 
									
										
										
										
											2023-02-24 07:46:48 +00:00
										 |  |  | 
 | 
					
						
							|  |  |  | :::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> | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ::: | 
					
						
							|  |  |  | 
 | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  | ### Reading Files
 | 
					
						
							| 
									
										
										
										
											2023-02-24 07:46:48 +00:00
										 |  |  | 
 | 
					
						
							|  |  |  | 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() => { | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  |   const aoo = await alasql(`SELECT * from XLSX("pres.xlsx", {autoExt: false})`); | 
					
						
							| 
									
										
										
										
											2023-02-24 07:46:48 +00:00
										 |  |  |   console.log(aoo); // [ { Name: "Bill Clinton", Index: 42 }, ...] | 
					
						
							|  |  |  | })(); | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  | ### Writing Files
 | 
					
						
							| 
									
										
										
										
											2023-02-24 07:46:48 +00:00
										 |  |  | 
 | 
					
						
							|  |  |  | 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 } | 
					
						
							|  |  |  |   ]; | 
					
						
							| 
									
										
										
										
											2023-04-09 21:13:24 +00:00
										 |  |  |   await alasql(`SELECT * INTO XLSX("PresMod5.xlsx") FROM ?`, [data]); | 
					
						
							|  |  |  |   /* PresMod5.xlsx will be created */ | 
					
						
							| 
									
										
										
										
											2023-02-24 07:46:48 +00:00
										 |  |  | })(); | 
					
						
							|  |  |  | ``` | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | ### NodeJS Example
 | 
					
						
							|  |  |  | 
 | 
					
						
							|  |  |  | 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 | 
					
						
							|  |  |  | ``` |