├── .gitignore ├── prettier.config.js ├── jest.config.js ├── tsconfig.json ├── package.json ├── dist ├── index.d.ts ├── index.js.map └── index.js ├── README.md ├── src └── index.ts └── __tests__ └── sheetquery.test.ts /.gitignore: -------------------------------------------------------------------------------- 1 | .DS_Store 2 | node_modules/ 3 | -------------------------------------------------------------------------------- /prettier.config.js: -------------------------------------------------------------------------------- 1 | module.exports = { 2 | printWidth: 100, 3 | trailingComma: 'es5', 4 | tabWidth: 2, 5 | semi: true, 6 | singleQuote: true, 7 | }; 8 | -------------------------------------------------------------------------------- /jest.config.js: -------------------------------------------------------------------------------- 1 | module.exports = { 2 | "roots": [ 3 | "", 4 | ], 5 | "testMatch": [ 6 | "**/__tests__/**/*.test.ts", 7 | ], 8 | "transform": { 9 | "^.+\\.ts$": "ts-jest", 10 | }, 11 | }; 12 | 13 | -------------------------------------------------------------------------------- /tsconfig.json: -------------------------------------------------------------------------------- 1 | { 2 | "compileOnSave": true, 3 | "compilerOptions": { 4 | "rootDir": "src", 5 | "outDir": "dist", 6 | "target": "es2019", 7 | "lib": [ 8 | "es2019", 9 | "dom" 10 | ], 11 | "module": "commonjs", 12 | "esModuleInterop": true, 13 | "strict": true, 14 | "declaration": true, 15 | "sourceMap": true 16 | }, 17 | "exclude": [ 18 | "node_modules", 19 | "__tests__" 20 | ] 21 | } 22 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "sheetquery", 3 | "version": "1.5.2", 4 | "description": "Query Builder/ORM for Google Sheets", 5 | "main": "dist/index.js", 6 | "types": "dist/index.d.ts", 7 | "scripts": { 8 | "build": "tsc", 9 | "clean": "rm -rf dist", 10 | "test": "jest", 11 | "prepack": "npm run clean && npm run build" 12 | }, 13 | "keywords": [ 14 | "gas", 15 | "google", 16 | "apps", 17 | "script", 18 | "google", 19 | "google sheets", 20 | "google apps script", 21 | "spreadsheet", 22 | "query builder", 23 | "orm" 24 | ], 25 | "author": "Vance Lucas ", 26 | "license": "BSD-3-Clause", 27 | "homepage": "https://github.com/vlucas/sheetquery", 28 | "devDependencies": { 29 | "@types/jest": "^26.0.19", 30 | "gasmask": "^1.3.8", 31 | "jest": "^27.5.1", 32 | "ts-jest": "^27.1.3", 33 | "typescript": "^4.5.5" 34 | } 35 | } 36 | -------------------------------------------------------------------------------- /dist/index.d.ts: -------------------------------------------------------------------------------- 1 | export type { Spreadsheet, Sheet } from 'gasmask/src/SpreadsheetApp'; 2 | /** 3 | * Run new sheet query 4 | * 5 | * @param {Spreadsheet} activeSpreadsheet Specific spreadsheet to use, or will use SpreadsheetApp.getActiveSpreadsheet() if undefined\ 6 | * @return {SheetQueryBuilder} 7 | */ 8 | export declare function sheetQuery(activeSpreadsheet?: any): SheetQueryBuilder; 9 | export declare type DictObject = { 10 | [key: string]: any; 11 | }; 12 | export declare type RowObject = { 13 | [key: string]: any; 14 | __meta: { 15 | row: number; 16 | cols: number; 17 | }; 18 | }; 19 | export declare type WhereFn = (row: RowObject) => boolean; 20 | export declare type UpdateFn = (row: RowObject) => RowObject; 21 | /** 22 | * SheetQueryBuilder class - Kind of an ORM for Google Sheets 23 | */ 24 | export declare class SheetQueryBuilder { 25 | activeSpreadsheet: any; 26 | columnNames: string[]; 27 | sheetName: string | undefined; 28 | headingRow: number; 29 | whereFn: WhereFn | undefined; 30 | _sheet: any; 31 | _sheetValues: any; 32 | _sheetHeadings: string[]; 33 | constructor(activeSpreadsheet?: any); 34 | select(columnNames: string | string[]): SheetQueryBuilder; 35 | /** 36 | * Name of spreadsheet to perform operations on 37 | * 38 | * @param {string} sheetName 39 | * @param {number} headingRow 40 | * @return {SheetQueryBuilder} 41 | */ 42 | from(sheetName: string, headingRow?: number): SheetQueryBuilder; 43 | /** 44 | * Apply a filtering function on rows in a spreadsheet before performing an operation on them 45 | * 46 | * @param {Function} fn 47 | * @return {SheetQueryBuilder} 48 | */ 49 | where(fn: WhereFn): SheetQueryBuilder; 50 | /** 51 | * Get Sheet object that is referenced by the current query from() method 52 | * 53 | * @return {Sheet} 54 | */ 55 | getSheet(): any; 56 | /** 57 | * Get values in sheet from current query + where condition 58 | */ 59 | getValues(): any; 60 | /** 61 | * Return matching rows from sheet query 62 | * 63 | * @return {RowObject[]} 64 | */ 65 | getRows(): RowObject[]; 66 | /** 67 | * Get array of headings in current sheet from() 68 | * 69 | * @return {string[]} 70 | */ 71 | getHeadings(): string[]; 72 | /** 73 | * Get all cells from a query + where condition 74 | * @returns {any[]} 75 | */ 76 | getCells(): any[]; 77 | /** 78 | * Get cells in sheet from current query + where condition and from specific header 79 | * @param {string} key name of the column 80 | * @param {Array} [keys] optionnal names of columns use to select more columns than one 81 | * @returns {any[]} all the colum cells from the query's rows 82 | */ 83 | getCellsWithHeadings(key: string, headings: Array): any[]; 84 | /** 85 | * Insert new rows into the spreadsheet 86 | * Arrays of objects like { Heading: Value } 87 | * 88 | * @param {DictObject[]} newRows - Array of row objects to insert 89 | * @return {SheetQueryBuilder} 90 | */ 91 | insertRows(newRows: DictObject[]): SheetQueryBuilder; 92 | /** 93 | * Delete matched rows from spreadsheet 94 | * 95 | * @return {SheetQueryBuilder} 96 | */ 97 | deleteRows(): SheetQueryBuilder; 98 | /** 99 | * Update matched rows in spreadsheet with provided function 100 | * 101 | * @param {UpdateFn} updateFn 102 | * @return {SheetQueryBuilder} 103 | */ 104 | updateRows(updateFn: UpdateFn): SheetQueryBuilder; 105 | /** 106 | * Update single row 107 | */ 108 | updateRow(row: any, updateFn: UpdateFn): SheetQueryBuilder; 109 | /** 110 | * Clear cached values, headings, and flush all operations to sheet 111 | * 112 | * @return {SheetQueryBuilder} 113 | */ 114 | clearCache(): SheetQueryBuilder; 115 | } 116 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SheetQuery 2 | 3 | Query builder/ORM for easily manipulating spreadsheets with Google Apps Script for Google Sheets (SpreadsheetApp). 4 | 5 | This library was created for [BudgetSheet](https://www.budgetsheet.net) and I thought it might be useful for others as 6 | well. 7 | 8 | ## Install as a Google Apps Script Library 9 | 10 | SheetQuery is available as a [Google Apps Script Library](https://developers.google.com/apps-script/guides/libraries). 11 | Script ID: `1pbpOJxDDHVeVr6WQmR5TZKSqTsW4qwdIlcVKIM6UKYvswkivwHpPnHaO` 12 | 13 | This is probably the easiest way to use SheetQuery and ensure you are always using the latest version. 14 | 15 | NOTE: If you use it as a library, you must use the library name first, as all libraries are automatically namespaced: 16 | ``` 17 | SheetQuery.sheetQuery() // Using it as a library 18 | 19 | sheetQuery() // Using it as a local file 20 | ``` 21 | 22 | ## Manual Install Into Your Own Google Apps Script 23 | 24 | If you don't want to use a Library file and need the script to be local within your own project, Create a new file named 25 | `SheetQuery.gs` in your Google Apps Script project. Copy the contents of `dist/index.js` into that file. 26 | 27 | ## Installation for Built Projects via NPM 28 | 29 | To use `sheetquery` via NPM, install it in your project as a dependency: 30 | 31 | ``` 32 | npm i sheetquery 33 | ``` 34 | 35 | Now you are ready to get started using sheetquery in your project via import or require(). 36 | 37 | ## Requirements 38 | 39 | SheetQuery requires a Google Sheet with a heading row (typically the first row where the columns are named). SheetQuery 40 | will use the heading row for all other operations, and for returning row data in key/value objects. 41 | 42 | ## Usage 43 | 44 | SheetQuery operates on a single Sheet at a time. You can start a new query with `sheetQuery().from('SheetName')`. 45 | 46 | ### Query For Data 47 | 48 | Data is queried based on the spreadsheet name and column headings: 49 | 50 | ```javascript 51 | const query = sheetQuery() 52 | .from('Transactions') 53 | .where((row) => row.Category === 'Shops'); 54 | 55 | // query.getRows() => [{ Amount: 95, Category: 'Shops', Business: 'Walmart'}] 56 | ``` 57 | 58 | If your headings are on a different row than the first row, specify it as the second argument to `from`: 59 | 60 | ```javascript 61 | const query = sheetQuery() 62 | .from('Transactions', 2) // For headings on row 2 63 | .where((row) => row.Category === 'Shops'); 64 | 65 | // query.getRows() => [{ Amount: 95, Category: 'Shops', Business: 'Walmart'}] 66 | ``` 67 | 68 | ### Update Rows 69 | 70 | Query for the rows you want to update, and then update them: 71 | 72 | ```javascript 73 | sheetQuery() 74 | .from('Transactions') 75 | .where((row) => row.Business.toLowerCase().includes('starbucks')) 76 | .updateRows((row) => { 77 | row.Category = 'Coffee Shops'; 78 | }); 79 | ``` 80 | 81 | The `updateRows` method can either return nothing, or can return a row object with updated properties that will be saved 82 | back to the spreadsheet row. If the updater function returns nothing/undefined, the row object that was passed in will 83 | be used (along with any changed values that will be updated by reference). 84 | 85 | ### Delete Rows 86 | 87 | Query for the rows you want to delete, and then delete them: 88 | 89 | ```javascript 90 | sheetQuery() 91 | .from('Transactions') 92 | .where((row) => row.Category === 'DELETEME') 93 | .deleteRows(); 94 | ``` 95 | 96 | Note: Be careful with this one, and always make sure to use it with a `where` filter to limit the number of rows that 97 | will be deleted! 98 | 99 | ### Insert Rows 100 | 101 | Rows can be inserted with SheetQuery by column heading name. No more keeping track of array index positions! 102 | 103 | ```javascript 104 | sheetQuery() 105 | .from('Transactions') 106 | .insertRows([ 107 | { 108 | Amount: -554.23, 109 | Name: 'BigBox, inc.', 110 | }, 111 | { 112 | Amount: -29.74, 113 | Name: 'Fast-n-greasy Food Spot', 114 | }, 115 | ]); 116 | ``` 117 | 118 | This can be a great way to insert rows into specific column headings without worrying about whether or not a user has 119 | edited the spreadsheet to add their own columns, etc. that would otherwise cause inserting new rows to be painful. 120 | 121 | SheetQuery will lookup the column headings, match them with the object keys provided, and insert a new row with an array 122 | of values mapped to the correct index positions of the spreadsheet headings. Any heading/column values not provided will 123 | be left blank. 124 | -------------------------------------------------------------------------------- /dist/index.js.map: -------------------------------------------------------------------------------- 1 | {"version":3,"file":"index.js","sourceRoot":"","sources":["../src/index.ts"],"names":[],"mappings":";;;AAEA;;;;;GAKG;AACH,SAAgB,UAAU,CAAC,iBAAuB;IAChD,OAAO,IAAI,iBAAiB,CAAC,iBAAiB,CAAC,CAAC;AAClD,CAAC;AAFD,gCAEC;AAaD;;GAEG;AACH,MAAa,iBAAiB;IAW5B,YAAY,iBAAuB;QATnC,gBAAW,GAAa,EAAE,CAAC;QAE3B,eAAU,GAAW,CAAC,CAAC;QAKvB,mBAAc,GAAa,EAAE,CAAC;QAG5B,IAAI,CAAC,iBAAiB,GAAG,iBAAiB,IAAI,cAAc,CAAC,oBAAoB,EAAE,CAAC;IACtF,CAAC;IAED,MAAM,CAAC,WAA8B;QACnC,IAAI,CAAC,WAAW,GAAG,KAAK,CAAC,OAAO,CAAC,WAAW,CAAC,CAAC,CAAC,CAAC,WAAW,CAAC,CAAC,CAAC,CAAC,WAAW,CAAC,CAAC;QAE5E,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;;;;;OAMG;IACH,IAAI,CAAC,SAAiB,EAAE,aAAqB,CAAC;QAC5C,IAAI,CAAC,SAAS,GAAG,SAAS,CAAC;QAC3B,IAAI,CAAC,UAAU,GAAG,UAAU,CAAC;QAE7B,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;;;;OAKG;IACH,KAAK,CAAC,EAAW;QACf,IAAI,CAAC,OAAO,GAAG,EAAE,CAAC;QAElB,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;;;OAIG;IACH,QAAQ;QACN,IAAI,CAAC,IAAI,CAAC,SAAS,EAAE;YACnB,MAAM,IAAI,KAAK,CAAC,0EAA0E,CAAC,CAAC;SAC7F;QAED,IAAI,CAAC,IAAI,CAAC,MAAM,EAAE;YAChB,IAAI,CAAC,MAAM,GAAG,IAAI,CAAC,iBAAiB,CAAC,cAAc,CAAC,IAAI,CAAC,SAAS,CAAC,CAAC;SACrE;QAED,OAAO,IAAI,CAAC,MAAM,CAAC;IACrB,CAAC;IAED;;OAEG;IACH,SAAS;QACP,IAAI,CAAC,IAAI,CAAC,YAAY,EAAE;YACtB,MAAM,EAAE,GAAG,IAAI,CAAC,UAAU,GAAG,CAAC,CAAC;YAC/B,MAAM,KAAK,GAAG,IAAI,CAAC,QAAQ,EAAE,CAAC;YAE9B,IAAI,CAAC,KAAK,EAAE;gBACV,OAAO,EAAE,CAAC;aACX;YAED,MAAM,SAAS,GAAG,EAAE,CAAC;YACrB,MAAM,WAAW,GAAG,KAAK,CAAC,YAAY,EAAE,CAAC,SAAS,EAAE,CAAC;YACrD,MAAM,OAAO,GAAG,WAAW,CAAC,CAAC,CAAC,CAAC,CAAC,CAAC,WAAW,CAAC,CAAC,CAAC,CAAC,MAAM,CAAC,CAAC,CAAC,CAAC,CAAC;YAC3D,MAAM,OAAO,GAAG,WAAW,CAAC,MAAM,CAAC;YACnC,MAAM,QAAQ,GAAG,CAAC,IAAI,CAAC,cAAc,GAAG,WAAW,CAAC,EAAE,CAAC,IAAI,EAAE,CAAC,CAAC;YAE/D,KAAK,IAAI,CAAC,GAAG,CAAC,EAAE,CAAC,GAAG,OAAO,EAAE,CAAC,EAAE,EAAE;gBAChC,MAAM,GAAG,GAAG,EAAE,MAAM,EAAE,EAAE,GAAG,EAAE,CAAC,GAAG,CAAC,EAAE,IAAI,EAAE,OAAO,EAAE,EAAE,CAAC;gBAEtD,KAAK,IAAI,CAAC,GAAG,CAAC,EAAE,CAAC,GAAG,OAAO,EAAE,CAAC,EAAE,EAAE;oBAChC,2FAA2F;oBAC3F,GAAG,CAAC,QAAQ,CAAC,CAAC,CAAC,CAAC,GAAG,WAAW,CAAC,CAAC,CAAC,CAAC,CAAC,CAAC,CAAC,CAAC,aAAa;iBACpD;gBAED,SAAS,CAAC,IAAI,CAAC,GAAG,CAAC,CAAC;aACrB;YAED,IAAI,CAAC,YAAY,GAAG,SAAS,CAAC;SAC/B;QAED,OAAO,IAAI,CAAC,YAAY,CAAC;IAC3B,CAAC;IAED;;;;OAIG;IACH,OAAO;QACL,MAAM,WAAW,GAAG,IAAI,CAAC,SAAS,EAAE,CAAC;QAErC,OAAO,IAAI,CAAC,OAAO,CAAC,CAAC,CAAC,WAAW,CAAC,MAAM,CAAC,IAAI,CAAC,OAAO,CAAC,CAAC,CAAC,CAAC,WAAW,CAAC;IACvE,CAAC;IAED;;;;OAIG;IACH,WAAW;QACT,IAAI,CAAC,IAAI,CAAC,cAAc,IAAI,CAAC,IAAI,CAAC,cAAc,CAAC,MAAM,EAAE;YACvD,MAAM,EAAE,GAAG,IAAI,CAAC,UAAU,GAAG,CAAC,CAAC;YAC/B,MAAM,KAAK,GAAG,IAAI,CAAC,QAAQ,EAAE,CAAC;YAC9B,MAAM,OAAO,GAAG,KAAK,CAAC,aAAa,EAAE,CAAC;YAEtC,IAAI,CAAC,cAAc,GAAG,KAAK,CAAC,cAAc,CAAC,CAAC,EAAE,CAAC,EAAE,IAAI,CAAC,UAAU,EAAE,OAAO,CAAC,CAAC,EAAE,CAAC,IAAI,EAAE,CAAC;YACrF,IAAI,CAAC,cAAc,GAAG,IAAI,CAAC,cAAc;iBACtC,GAAG,CAAC,CAAC,CAAC,EAAE,EAAE,CAAC,CAAC,OAAO,CAAC,KAAK,QAAQ,CAAC,CAAC,CAAC,CAAC,CAAC,IAAI,EAAE,CAAC,CAAC,CAAC,EAAE,CAAC,CAAC;iBACnD,MAAM,CAAC,OAAO,CAAC,CAAC;SACpB;QAED,OAAO,IAAI,CAAC,cAAc,IAAI,EAAE,CAAC;IACnC,CAAC;IAED;;;OAGG;IACH,QAAQ;QACN,MAAM,IAAI,GAAG,IAAI,CAAC,OAAO,EAAE,CAAC;QAC5B,MAAM,SAAS,GAAe,EAAE,CAAC;QACjC,IAAI,CAAC,OAAO,CAAC,CAAC,GAAG,EAAE,EAAE;YACnB,SAAS,CAAC,IAAI,CAAC,IAAI,CAAC,MAAM,CAAC,QAAQ,CAAC,GAAG,CAAC,MAAM,CAAC,GAAG,EAAE,CAAC,EAAE,CAAC,EAAE,GAAG,CAAC,MAAM,CAAC,IAAI,CAAC,CAAC,CAAC;QAC9E,CAAC,CAAC,CAAC;QAEH,OAAO,SAAS,CAAC;IACnB,CAAC;IAED;;;;;OAKG;IACH,oBAAoB,CAAC,GAAW,EAAE,QAAuB;QACvD,IAAI,IAAI,GAAG,IAAI,CAAC,OAAO,EAAE,CAAC;QAC1B,IAAI,WAAW,GAAG,CAAC,CAAC;QACpB,MAAM,UAAU,GAAe,EAAE,CAAC;QAClC,KAAK,MAAM,IAAI,IAAI,IAAI,CAAC,cAAc,EAAE;YACtC,IAAI,IAAI,IAAI,GAAG;gBAAE,MAAM;YACvB,WAAW,EAAE,CAAC;SACf;QACD,IAAI,CAAC,OAAO,CAAC,CAAC,GAAG,EAAE,EAAE;YACnB,UAAU,CAAC,IAAI,CAAC,IAAI,CAAC,MAAM,CAAC,QAAQ,CAAC,GAAG,CAAC,MAAM,CAAC,GAAG,EAAE,WAAW,CAAC,CAAC,CAAC;QACrE,CAAC,CAAC,CAAC;QAEH,gCAAgC;QAChC,QAAQ,CAAC,OAAO,CAAC,CAAC,GAAG,EAAE,EAAE;YACvB,IAAI,WAAW,GAAG,CAAC,CAAC;YACpB,KAAK,MAAM,IAAI,IAAI,IAAI,CAAC,cAAc,EAAE;gBACtC,IAAI,IAAI,IAAI,GAAG;oBAAE,MAAM;gBACvB,WAAW,EAAE,CAAC;aACf;YACD,IAAI,CAAC,OAAO,CAAC,CAAC,GAAG,EAAE,EAAE;gBACnB,UAAU,CAAC,IAAI,CAAC,IAAI,CAAC,MAAM,CAAC,QAAQ,CAAC,GAAG,CAAC,MAAM,CAAC,GAAG,EAAE,WAAW,CAAC,CAAC,CAAC;YACrE,CAAC,CAAC,CAAC;QACL,CAAC,CAAC,CAAC;QACH,OAAO,UAAU,CAAC;IACpB,CAAC;IAED;;;;;;OAMG;IACH,UAAU,CAAC,OAAqB;QAC9B,MAAM,KAAK,GAAG,IAAI,CAAC,QAAQ,EAAE,CAAC;QAC9B,MAAM,QAAQ,GAAG,IAAI,CAAC,WAAW,EAAE,CAAC;QAEpC,OAAO,CAAC,OAAO,CAAC,CAAC,GAAG,EAAE,EAAE;YACtB,IAAI,CAAC,GAAG,EAAE;gBACR,OAAO;aACR;YAED,MAAM,SAAS,GAAG,QAAQ,CAAC,GAAG,CAAC,CAAC,OAAO,EAAE,EAAE;gBACzC,MAAM,GAAG,GAAG,GAAG,CAAC,OAAO,CAAC,CAAC;gBACzB,OAAO,GAAG,KAAK,SAAS,IAAI,GAAG,KAAK,IAAI,IAAI,GAAG,KAAK,KAAK,CAAC,CAAC,CAAC,EAAE,CAAC,CAAC,CAAC,GAAG,CAAC;YACvE,CAAC,CAAC,CAAC;YAEH,wEAAwE;YACxE,IAAI,SAAS,IAAI,SAAS,CAAC,MAAM,KAAK,CAAC,EAAE;gBACvC,KAAK,CAAC,SAAS,CAAC,SAAS,CAAC,CAAC;aAC5B;QACH,CAAC,CAAC,CAAC;QAEH,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;;;OAIG;IACH,UAAU;QACR,MAAM,IAAI,GAAG,IAAI,CAAC,OAAO,EAAE,CAAC;QAC5B,IAAI,CAAC,GAAG,CAAC,CAAC;QAEV,IAAI,CAAC,OAAO,CAAC,CAAC,GAAc,EAAE,EAAE;YAC9B,MAAM,cAAc,GAAG,IAAI,CAAC,MAAM,CAAC,QAAQ,CAAC,GAAG,CAAC,MAAM,CAAC,GAAG,GAAG,CAAC,EAAE,CAAC,EAAE,CAAC,EAAE,GAAG,CAAC,MAAM,CAAC,IAAI,CAAC,CAAC;YAEvF,cAAc,CAAC,WAAW,CAAC,cAAc,CAAC,SAAS,CAAC,IAAI,CAAC,CAAC;YAC1D,CAAC,EAAE,CAAC;QACN,CAAC,CAAC,CAAC;QAEH,IAAI,CAAC,UAAU,EAAE,CAAC;QAClB,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;;;;OAKG;IACH,UAAU,CAAC,QAAkB;QAC3B,MAAM,IAAI,GAAG,IAAI,CAAC,OAAO,EAAE,CAAC;QAE5B,KAAK,IAAI,CAAC,GAAG,CAAC,EAAE,CAAC,GAAG,IAAI,CAAC,MAAM,EAAE,CAAC,EAAE,EAAE;YACpC,IAAI,CAAC,SAAS,CAAC,IAAI,CAAC,CAAC,CAAC,EAAE,QAAQ,CAAC,CAAC;SACnC;QAED,IAAI,CAAC,UAAU,EAAE,CAAC;QAClB,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;OAEG;IACH,SAAS,CAAC,GAAQ,EAAE,QAAkB;QACpC,MAAM,UAAU,GAAQ,QAAQ,CAAC,GAAG,CAAC,IAAI,GAAG,CAAC;QAC7C,MAAM,OAAO,GAAG,UAAU,CAAC,MAAM,CAAC;QAClC,MAAM,QAAQ,GAAG,IAAI,CAAC,WAAW,EAAE,CAAC;QAEpC,OAAO,UAAU,CAAC,MAAM,CAAC;QAEzB,mDAAmD;QACnD,MAAM,WAAW,GAAG,QAAQ,CAAC,GAAG,CAAC,CAAC,OAAO,EAAE,EAAE;YAC3C,MAAM,GAAG,GAAG,UAAU,CAAC,OAAO,CAAC,CAAC;YAChC,OAAO,GAAG,KAAK,SAAS,IAAI,GAAG,KAAK,IAAI,IAAI,GAAG,KAAK,KAAK,CAAC,CAAC,CAAC,EAAE,CAAC,CAAC,CAAC,GAAG,CAAC;QACvE,CAAC,CAAC,CAAC;QACH,MAAM,OAAO,GAAG,IAAI,CAAC,GAAG,CAAC,OAAO,CAAC,IAAI,EAAE,WAAW,CAAC,MAAM,CAAC,CAAC;QAC3D,MAAM,cAAc,GAAG,IAAI,CAAC,QAAQ,EAAE,CAAC,QAAQ,CAAC,OAAO,CAAC,GAAG,EAAE,CAAC,EAAE,CAAC,EAAE,OAAO,CAAC,CAAC;QAC5E,MAAM,SAAS,GAAG,cAAc,CAAC,SAAS,EAAE,CAAC,CAAC,CAAC,IAAI,EAAE,CAAC;QAEtD,4FAA4F;QAC5F,MAAM,SAAS,GAAG,SAAS,CAAC,GAAG,CAAC,CAAC,KAAa,EAAE,KAAa,EAAE,EAAE;YAC/D,MAAM,GAAG,GAAG,WAAW,CAAC,KAAK,CAAC,CAAC;YAC/B,OAAO,GAAG,KAAK,SAAS,IAAI,GAAG,KAAK,IAAI,IAAI,GAAG,KAAK,KAAK,CAAC,CAAC,CAAC,EAAE,CAAC,CAAC,CAAC,GAAG,CAAC;QACvE,CAAC,CAAC,CAAC;QAEH,cAAc,CAAC,SAAS,CAAC,CAAC,SAAS,CAAC,CAAC,CAAC;QACtC,OAAO,IAAI,CAAC;IACd,CAAC;IAED;;;;OAIG;IACH,UAAU;QACR,IAAI,CAAC,YAAY,GAAG,IAAI,CAAC;QACzB,IAAI,CAAC,cAAc,GAAG,EAAE,CAAC;QAEzB,cAAc,CAAC,KAAK,EAAE,CAAC;QAEvB,OAAO,IAAI,CAAC;IACd,CAAC;CACF;AA7RD,8CA6RC"} -------------------------------------------------------------------------------- /dist/index.js: -------------------------------------------------------------------------------- 1 | /** 2 | * Run new sheet query 3 | * 4 | * @param {Spreadsheet} activeSpreadsheet Specific spreadsheet to use, or will use SpreadsheetApp.getActiveSpreadsheet() if undefined\ 5 | * @return {SheetQueryBuilder} 6 | */ 7 | function sheetQuery(activeSpreadsheet) { 8 | return new SheetQueryBuilder(activeSpreadsheet); 9 | } 10 | 11 | /** 12 | * SheetQueryBuilder class - Kind of an ORM for Google Sheets 13 | */ 14 | class SheetQueryBuilder { 15 | constructor(activeSpreadsheet) { 16 | this.columnNames = []; 17 | this.headingRow = 1; 18 | this._sheetHeadings = []; 19 | this.activeSpreadsheet = activeSpreadsheet || SpreadsheetApp.getActiveSpreadsheet(); 20 | } 21 | select(columnNames) { 22 | this.columnNames = Array.isArray(columnNames) ? columnNames : [columnNames]; 23 | return this; 24 | } 25 | /** 26 | * Name of spreadsheet to perform operations on 27 | * 28 | * @param {string} sheetName 29 | * @param {number} headingRow 30 | * @return {SheetQueryBuilder} 31 | */ 32 | from(sheetName, headingRow = 1) { 33 | this.sheetName = sheetName; 34 | this.headingRow = headingRow; 35 | return this; 36 | } 37 | /** 38 | * Apply a filtering function on rows in a spreadsheet before performing an operation on them 39 | * 40 | * @param {Function} fn 41 | * @return {SheetQueryBuilder} 42 | */ 43 | where(fn) { 44 | this.whereFn = fn; 45 | return this; 46 | } 47 | /** 48 | * Get Sheet object that is referenced by the current query from() method 49 | * 50 | * @return {Sheet} 51 | */ 52 | getSheet() { 53 | if (!this.sheetName) { 54 | throw new Error('SheetQuery: No sheet selected. Select sheet with .from(sheetName) method'); 55 | } 56 | if (!this._sheet) { 57 | this._sheet = this.activeSpreadsheet.getSheetByName(this.sheetName); 58 | } 59 | return this._sheet; 60 | } 61 | /** 62 | * Get values in sheet from current query + where condition 63 | */ 64 | getValues() { 65 | if (!this._sheetValues) { 66 | const zh = this.headingRow - 1; 67 | const sheet = this.getSheet(); 68 | if (!sheet) { 69 | return []; 70 | } 71 | const rowValues = []; 72 | const sheetValues = sheet.getDataRange().getValues(); 73 | const numCols = sheetValues[0] ? sheetValues[0].length : 0; 74 | const numRows = sheetValues.length; 75 | const headings = (this._sheetHeadings = sheetValues[zh] || []); 76 | for (let r = 0; r < numRows; r++) { 77 | const obj = { __meta: { row: r + 1, cols: numCols } }; 78 | for (let c = 0; c < numCols; c++) { 79 | // @ts-expect-error: Headings are set already above, so possibility of an error here is nil 80 | obj[headings[c]] = sheetValues[r][c]; // @ts-ignore 81 | } 82 | rowValues.push(obj); 83 | } 84 | this._sheetValues = rowValues; 85 | } 86 | return this._sheetValues; 87 | } 88 | /** 89 | * Return matching rows from sheet query 90 | * 91 | * @return {RowObject[]} 92 | */ 93 | getRows() { 94 | const sheetValues = this.getValues(); 95 | return this.whereFn ? sheetValues.filter(this.whereFn) : sheetValues; 96 | } 97 | /** 98 | * Get array of headings in current sheet from() 99 | * 100 | * @return {string[]} 101 | */ 102 | getHeadings() { 103 | if (!this._sheetHeadings || !this._sheetHeadings.length) { 104 | const zh = this.headingRow - 1; 105 | const sheet = this.getSheet(); 106 | const numCols = sheet.getLastColumn(); 107 | this._sheetHeadings = sheet.getSheetValues(1, 1, this.headingRow, numCols)[zh] || []; 108 | this._sheetHeadings = this._sheetHeadings 109 | .map((s) => (typeof s === 'string' ? s.trim() : '')) 110 | .filter(Boolean); 111 | } 112 | return this._sheetHeadings || []; 113 | } 114 | /** 115 | * Get all cells from a query + where condition 116 | * @returns {any[]} 117 | */ 118 | getCells() { 119 | const rows = this.getRows(); 120 | const cellArray = []; 121 | rows.forEach((row) => { 122 | cellArray.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols)); 123 | }); 124 | return cellArray; 125 | } 126 | /** 127 | * Get cells in sheet from current query + where condition and from specific header 128 | * @param {string} key name of the column 129 | * @param {Array} [keys] optionnal names of columns use to select more columns than one 130 | * @returns {any[]} all the colum cells from the query's rows 131 | */ 132 | getCellsWithHeadings(key, headings) { 133 | let rows = this.getRows(); 134 | let indexColumn = 1; 135 | const arrayCells = []; 136 | for (const elem of this._sheetHeadings) { 137 | if (elem == key) break; 138 | indexColumn++; 139 | } 140 | rows.forEach((row) => { 141 | arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); 142 | }); 143 | //If we got more thant one param 144 | headings.forEach((col) => { 145 | let indexColumn = 1; 146 | for (const elem of this._sheetHeadings) { 147 | if (elem == col) break; 148 | indexColumn++; 149 | } 150 | rows.forEach((row) => { 151 | arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); 152 | }); 153 | }); 154 | return arrayCells; 155 | } 156 | /** 157 | * Insert new rows into the spreadsheet 158 | * Arrays of objects like { Heading: Value } 159 | * 160 | * @param {DictObject[]} newRows - Array of row objects to insert 161 | * @return {SheetQueryBuilder} 162 | */ 163 | insertRows(newRows) { 164 | const sheet = this.getSheet(); 165 | const headings = this.getHeadings(); 166 | newRows.forEach((row) => { 167 | if (!row) { 168 | return; 169 | } 170 | const rowValues = headings.map((heading) => { 171 | const val = row[heading]; 172 | return val === undefined || val === null || val === false ? '' : val; 173 | }); 174 | // appendRow() will throw if array is empty, so we check to prevent that 175 | if (rowValues && rowValues.length !== 0) { 176 | sheet.appendRow(rowValues); 177 | } 178 | }); 179 | return this; 180 | } 181 | /** 182 | * Delete matched rows from spreadsheet 183 | * 184 | * @return {SheetQueryBuilder} 185 | */ 186 | deleteRows() { 187 | const rows = this.getRows(); 188 | let i = 0; 189 | rows.forEach((row) => { 190 | const deleteRowRange = this._sheet.getRange(row.__meta.row - i, 1, 1, row.__meta.cols); 191 | deleteRowRange.deleteCells(SpreadsheetApp.Dimension.ROWS); 192 | i++; 193 | }); 194 | this.clearCache(); 195 | return this; 196 | } 197 | /** 198 | * Update matched rows in spreadsheet with provided function 199 | * 200 | * @param {UpdateFn} updateFn 201 | * @return {SheetQueryBuilder} 202 | */ 203 | updateRows(updateFn) { 204 | const rows = this.getRows(); 205 | for (let i = 0; i < rows.length; i++) { 206 | this.updateRow(rows[i], updateFn); 207 | } 208 | this.clearCache(); 209 | return this; 210 | } 211 | /** 212 | * Update single row 213 | */ 214 | updateRow(row, updateFn) { 215 | const updatedRow = updateFn(row) || row; 216 | const rowMeta = updatedRow.__meta; 217 | const headings = this.getHeadings(); 218 | delete updatedRow.__meta; 219 | // Put new array data in order of headings in sheet 220 | const arrayValues = headings.map((heading) => { 221 | const val = updatedRow[heading]; 222 | return val === undefined || val === null || val === false ? '' : val; 223 | }); 224 | const maxCols = Math.max(rowMeta.cols, arrayValues.length); 225 | const updateRowRange = this.getSheet().getRange(rowMeta.row, 1, 1, maxCols); 226 | const rangeData = updateRowRange.getValues()[0] || []; 227 | // Map over old data in same index order to update it and ensure array length always matches 228 | const newValues = rangeData.map((value, index) => { 229 | const val = arrayValues[index]; 230 | return val === undefined || val === null || val === false ? '' : val; 231 | }); 232 | updateRowRange.setValues([newValues]); 233 | return this; 234 | } 235 | /** 236 | * Clear cached values, headings, and flush all operations to sheet 237 | * 238 | * @return {SheetQueryBuilder} 239 | */ 240 | clearCache() { 241 | this._sheetValues = null; 242 | this._sheetHeadings = []; 243 | SpreadsheetApp.flush(); 244 | return this; 245 | } 246 | } 247 | 248 | -------------------------------------------------------------------------------- /src/index.ts: -------------------------------------------------------------------------------- 1 | export type { Spreadsheet, Sheet } from 'gasmask/src/SpreadsheetApp'; 2 | 3 | /** 4 | * Run new sheet query 5 | * 6 | * @param {Spreadsheet} activeSpreadsheet Specific spreadsheet to use, or will use SpreadsheetApp.getActiveSpreadsheet() if undefined\ 7 | * @return {SheetQueryBuilder} 8 | */ 9 | export function sheetQuery(activeSpreadsheet?: any) { 10 | return new SheetQueryBuilder(activeSpreadsheet); 11 | } 12 | 13 | export type DictObject = { [key: string]: any }; 14 | export type RowObject = { 15 | [key: string]: any; 16 | __meta: { row: number; cols: number }; 17 | }; 18 | export type WhereFn = (row: RowObject) => boolean; 19 | export type UpdateFn = (row: RowObject) => RowObject; 20 | 21 | // SpreadsheetApp comes from Google Apps Script 22 | declare var SpreadsheetApp: any; 23 | 24 | /** 25 | * SheetQueryBuilder class - Kind of an ORM for Google Sheets 26 | */ 27 | export class SheetQueryBuilder { 28 | activeSpreadsheet: any; 29 | columnNames: string[] = []; 30 | sheetName: string | undefined; 31 | headingRow: number = 1; 32 | whereFn: WhereFn | undefined; 33 | 34 | _sheet: any; 35 | _sheetValues: any; 36 | _sheetHeadings: string[] = []; 37 | 38 | constructor(activeSpreadsheet?: any) { 39 | this.activeSpreadsheet = activeSpreadsheet || SpreadsheetApp.getActiveSpreadsheet(); 40 | } 41 | 42 | select(columnNames: string | string[]): SheetQueryBuilder { 43 | this.columnNames = Array.isArray(columnNames) ? columnNames : [columnNames]; 44 | 45 | return this; 46 | } 47 | 48 | /** 49 | * Name of spreadsheet to perform operations on 50 | * 51 | * @param {string} sheetName 52 | * @param {number} headingRow 53 | * @return {SheetQueryBuilder} 54 | */ 55 | from(sheetName: string, headingRow: number = 1): SheetQueryBuilder { 56 | this.sheetName = sheetName; 57 | this.headingRow = headingRow; 58 | 59 | return this; 60 | } 61 | 62 | /** 63 | * Apply a filtering function on rows in a spreadsheet before performing an operation on them 64 | * 65 | * @param {Function} fn 66 | * @return {SheetQueryBuilder} 67 | */ 68 | where(fn: WhereFn): SheetQueryBuilder { 69 | this.whereFn = fn; 70 | 71 | return this; 72 | } 73 | 74 | /** 75 | * Get Sheet object that is referenced by the current query from() method 76 | * 77 | * @return {Sheet} 78 | */ 79 | getSheet() { 80 | if (!this.sheetName) { 81 | throw new Error('SheetQuery: No sheet selected. Select sheet with .from(sheetName) method'); 82 | } 83 | 84 | if (!this._sheet) { 85 | this._sheet = this.activeSpreadsheet.getSheetByName(this.sheetName); 86 | } 87 | 88 | return this._sheet; 89 | } 90 | 91 | /** 92 | * Get values in sheet from current query + where condition 93 | */ 94 | getValues() { 95 | if (!this._sheetValues) { 96 | const zh = this.headingRow - 1; 97 | const sheet = this.getSheet(); 98 | 99 | if (!sheet) { 100 | return []; 101 | } 102 | 103 | const rowValues = []; 104 | const sheetValues = sheet.getDataRange().getValues(); 105 | const numCols = sheetValues[0] ? sheetValues[0].length : 0; 106 | const numRows = sheetValues.length; 107 | const headings = (this._sheetHeadings = sheetValues[zh] || []); 108 | 109 | for (let r = 0; r < numRows; r++) { 110 | const obj = { __meta: { row: r + 1, cols: numCols } }; 111 | 112 | for (let c = 0; c < numCols; c++) { 113 | // @ts-expect-error: Headings are set already above, so possibility of an error here is nil 114 | obj[headings[c]] = sheetValues[r][c]; // @ts-ignore 115 | } 116 | 117 | rowValues.push(obj); 118 | } 119 | 120 | this._sheetValues = rowValues; 121 | } 122 | 123 | return this._sheetValues; 124 | } 125 | 126 | /** 127 | * Return matching rows from sheet query 128 | * 129 | * @return {RowObject[]} 130 | */ 131 | getRows(): RowObject[] { 132 | const sheetValues = this.getValues(); 133 | 134 | return this.whereFn ? sheetValues.filter(this.whereFn) : sheetValues; 135 | } 136 | 137 | /** 138 | * Get array of headings in current sheet from() 139 | * 140 | * @return {string[]} 141 | */ 142 | getHeadings(): string[] { 143 | if (!this._sheetHeadings || !this._sheetHeadings.length) { 144 | const zh = this.headingRow - 1; 145 | const sheet = this.getSheet(); 146 | const numCols = sheet.getLastColumn(); 147 | 148 | this._sheetHeadings = sheet.getSheetValues(1, 1, this.headingRow, numCols)[zh] || []; 149 | this._sheetHeadings = this._sheetHeadings 150 | .map((s) => (typeof s === 'string' ? s.trim() : '')) 151 | .filter(Boolean); 152 | } 153 | 154 | return this._sheetHeadings || []; 155 | } 156 | 157 | /** 158 | * Get all cells from a query + where condition 159 | * @returns {any[]} 160 | */ 161 | getCells(): any[] { 162 | const rows = this.getRows(); 163 | const cellArray: Array = []; 164 | rows.forEach((row) => { 165 | cellArray.push(this._sheet.getRange(row.__meta.row, 1, 1, row.__meta.cols)); 166 | }); 167 | 168 | return cellArray; 169 | } 170 | 171 | /** 172 | * Get cells in sheet from current query + where condition and from specific header 173 | * @param {string} key name of the column 174 | * @param {Array} [keys] optionnal names of columns use to select more columns than one 175 | * @returns {any[]} all the colum cells from the query's rows 176 | */ 177 | getCellsWithHeadings(key: string, headings: Array): any[] { 178 | let rows = this.getRows(); 179 | let indexColumn = 1; 180 | const arrayCells: Array = []; 181 | for (const elem of this._sheetHeadings) { 182 | if (elem == key) break; 183 | indexColumn++; 184 | } 185 | rows.forEach((row) => { 186 | arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); 187 | }); 188 | 189 | //If we got more thant one param 190 | headings.forEach((col) => { 191 | let indexColumn = 1; 192 | for (const elem of this._sheetHeadings) { 193 | if (elem == col) break; 194 | indexColumn++; 195 | } 196 | rows.forEach((row) => { 197 | arrayCells.push(this._sheet.getRange(row.__meta.row, indexColumn)); 198 | }); 199 | }); 200 | return arrayCells; 201 | } 202 | 203 | /** 204 | * Insert new rows into the spreadsheet 205 | * Arrays of objects like { Heading: Value } 206 | * 207 | * @param {DictObject[]} newRows - Array of row objects to insert 208 | * @return {SheetQueryBuilder} 209 | */ 210 | insertRows(newRows: DictObject[]): SheetQueryBuilder { 211 | const sheet = this.getSheet(); 212 | const headings = this.getHeadings(); 213 | 214 | newRows.forEach((row) => { 215 | if (!row) { 216 | return; 217 | } 218 | 219 | const rowValues = headings.map((heading) => { 220 | const val = row[heading]; 221 | return val === undefined || val === null || val === false ? '' : val; 222 | }); 223 | 224 | // appendRow() will throw if array is empty, so we check to prevent that 225 | if (rowValues && rowValues.length !== 0) { 226 | sheet.appendRow(rowValues); 227 | } 228 | }); 229 | 230 | return this; 231 | } 232 | 233 | /** 234 | * Delete matched rows from spreadsheet 235 | * 236 | * @return {SheetQueryBuilder} 237 | */ 238 | deleteRows(): SheetQueryBuilder { 239 | const rows = this.getRows(); 240 | let i = 0; 241 | 242 | rows.forEach((row: RowObject) => { 243 | const deleteRowRange = this._sheet.getRange(row.__meta.row - i, 1, 1, row.__meta.cols); 244 | 245 | deleteRowRange.deleteCells(SpreadsheetApp.Dimension.ROWS); 246 | i++; 247 | }); 248 | 249 | this.clearCache(); 250 | return this; 251 | } 252 | 253 | /** 254 | * Update matched rows in spreadsheet with provided function 255 | * 256 | * @param {UpdateFn} updateFn 257 | * @return {SheetQueryBuilder} 258 | */ 259 | updateRows(updateFn: UpdateFn): SheetQueryBuilder { 260 | const rows = this.getRows(); 261 | 262 | for (let i = 0; i < rows.length; i++) { 263 | this.updateRow(rows[i], updateFn); 264 | } 265 | 266 | this.clearCache(); 267 | return this; 268 | } 269 | 270 | /** 271 | * Update single row 272 | */ 273 | updateRow(row: any, updateFn: UpdateFn): SheetQueryBuilder { 274 | const updatedRow: any = updateFn(row) || row; 275 | const rowMeta = updatedRow.__meta; 276 | const headings = this.getHeadings(); 277 | 278 | delete updatedRow.__meta; 279 | 280 | // Put new array data in order of headings in sheet 281 | const arrayValues = headings.map((heading) => { 282 | const val = updatedRow[heading]; 283 | return val === undefined || val === null || val === false ? '' : val; 284 | }); 285 | const maxCols = Math.max(rowMeta.cols, arrayValues.length); 286 | const updateRowRange = this.getSheet().getRange(rowMeta.row, 1, 1, maxCols); 287 | const rangeData = updateRowRange.getValues()[0] || []; 288 | 289 | // Map over old data in same index order to update it and ensure array length always matches 290 | const newValues = rangeData.map((value: string, index: number) => { 291 | const val = arrayValues[index]; 292 | return val === undefined || val === null || val === false ? '' : val; 293 | }); 294 | 295 | updateRowRange.setValues([newValues]); 296 | return this; 297 | } 298 | 299 | /** 300 | * Clear cached values, headings, and flush all operations to sheet 301 | * 302 | * @return {SheetQueryBuilder} 303 | */ 304 | clearCache(): SheetQueryBuilder { 305 | this._sheetValues = null; 306 | this._sheetHeadings = []; 307 | 308 | SpreadsheetApp.flush(); 309 | 310 | return this; 311 | } 312 | } 313 | -------------------------------------------------------------------------------- /__tests__/sheetquery.test.ts: -------------------------------------------------------------------------------- 1 | import { sheetQuery } from '../src/index'; 2 | import type { DictObject } from '../src/index'; 3 | import { SpreadsheetApp, Spreadsheet, Sheet } from 'gasmask/dist/SpreadsheetApp'; 4 | 5 | // @ts-ignore 6 | global.SpreadsheetApp = SpreadsheetApp; 7 | 8 | const SHEET_NAME = 'TestSheet'; 9 | let ss = new Spreadsheet(); 10 | 11 | let sheet = new Sheet(SHEET_NAME); 12 | const defaultSheetData = [ 13 | ['Date', 'Amount', 'Name', 'Category'], 14 | ['2021-01-01', 5.32, 'Kwickiemart', 'Shops'], 15 | ['2021-01-02', 72.48, 'Shopmart', 'Shops'], 16 | ['2021-01-03', 1.97, 'Kwickiemart', 'Shops'], 17 | ['2021-01-03', 43.87, 'Gasmart', 'Gas'], 18 | ['2021-01-04', 824.93, 'Wholepaycheck', 'Groceries'], 19 | ]; 20 | 21 | function setupSpreadsheet(sheetData: any[]) { 22 | if (sheet) { 23 | ss.deleteSheet(sheet); 24 | } 25 | 26 | ss.insertSheet(SHEET_NAME); 27 | 28 | sheet = ss.getSheetByName(SHEET_NAME); 29 | sheetData.forEach((row) => sheet.appendRow(row)); 30 | } 31 | 32 | describe('SheetQuery', () => { 33 | describe('from', () => { 34 | it('should allow user to specify heading column number as second argument', () => { 35 | const customSheetData = [['Nope', 'Nope2', 'Nope3', 'Nope4'], ...defaultSheetData]; 36 | 37 | setupSpreadsheet(customSheetData); 38 | 39 | const query = sheetQuery(ss).from(SHEET_NAME, 2); 40 | const rows = query.getRows(); 41 | 42 | expect(Object.keys(rows[0])).toEqual(['__meta', 'Date', 'Amount', 'Name', 'Category']); 43 | expect(rows.length).toBe(customSheetData.length); 44 | expect(rows).toContainEqual({ 45 | Amount: 72.48, 46 | Category: 'Shops', 47 | Date: '2021-01-02', 48 | Name: 'Shopmart', 49 | __meta: { cols: 4, row: 4 }, 50 | }); 51 | }); 52 | }); 53 | 54 | describe('getRows', () => { 55 | it('should return correct __meta row positions', () => { 56 | setupSpreadsheet(defaultSheetData); 57 | 58 | const query = sheetQuery(ss).from(SHEET_NAME); 59 | const rows = query.getRows(); 60 | 61 | expect(Object.keys(rows[0])).toEqual(['__meta', 'Date', 'Amount', 'Name', 'Category']); 62 | expect(rows.length).toBe(defaultSheetData.length); 63 | expect(rows).toContainEqual({ 64 | Amount: 'Amount', 65 | Category: 'Category', 66 | Date: 'Date', 67 | Name: 'Name', 68 | __meta: { cols: 4, row: 1 }, 69 | }); 70 | }); 71 | }); 72 | 73 | describe('getHeadings', () => { 74 | it('should return first heading row by default', () => { 75 | setupSpreadsheet(defaultSheetData); 76 | 77 | const query = sheetQuery(ss).from(SHEET_NAME); 78 | const headings = query.getHeadings(); 79 | 80 | expect(headings).toEqual(['Date', 'Amount', 'Name', 'Category']); 81 | }); 82 | 83 | it('should return custom heading row when specified', () => { 84 | const customSheetData = [['Nope', 'Nope2', 'Nope3', 'Nope4'], ...defaultSheetData]; 85 | 86 | setupSpreadsheet(customSheetData); 87 | 88 | const query = sheetQuery(ss).from(SHEET_NAME, 2); 89 | const headings = query.getHeadings(); 90 | 91 | expect(headings).toEqual(['Date', 'Amount', 'Name', 'Category']); 92 | }); 93 | 94 | it('should remove empty columns and trim extra spaces', () => { 95 | const sheetData = [ 96 | ['Date', 'Amount', 'Name', 'Category', ' ', ' Extra ', ''], 97 | ['2021-01-01', 5.32, 'Kwickiemart', 'Shops', '', ''], 98 | ]; 99 | setupSpreadsheet(sheetData); 100 | 101 | const query = sheetQuery(ss).from(SHEET_NAME).clearCache(); 102 | const headings = query.getHeadings(); 103 | 104 | expect(headings).toEqual(['Date', 'Amount', 'Name', 'Category', 'Extra']); 105 | }); 106 | }); 107 | 108 | describe('getRows', () => { 109 | it('should return first row with 1-index', () => { 110 | setupSpreadsheet(defaultSheetData); 111 | 112 | const query = sheetQuery(ss).from(SHEET_NAME); 113 | const rows = query.getRows(); 114 | 115 | expect(rows.length).toBe(defaultSheetData.length); 116 | expect(rows[0].__meta).toEqual({ 117 | cols: 4, 118 | row: 1, 119 | }); 120 | }); 121 | 122 | it('should return all rows for spreadsheet', () => { 123 | setupSpreadsheet(defaultSheetData); 124 | 125 | const query = sheetQuery(ss).from(SHEET_NAME); 126 | const rows = query.getRows(); 127 | 128 | expect(rows.length).toBe(defaultSheetData.length); 129 | expect(rows).toContainEqual({ 130 | Amount: 72.48, 131 | Category: 'Shops', 132 | Date: '2021-01-02', 133 | Name: 'Shopmart', 134 | __meta: { cols: 4, row: 3 }, 135 | }); 136 | }); 137 | 138 | it('should only return rows that match Category = Shops', () => { 139 | setupSpreadsheet(defaultSheetData); 140 | 141 | const query = sheetQuery(ss) 142 | .from(SHEET_NAME) 143 | .where((row) => row.Category === 'Shops'); 144 | const rows = query.getRows(); 145 | 146 | expect(rows.length).toBe(3); 147 | expect(rows.every((row) => row.Category === 'Shops')).toBeTruthy(); 148 | }); 149 | }); 150 | 151 | describe('insertRows', () => { 152 | it('Should insert rows in the correct places matching column headings', () => { 153 | setupSpreadsheet(defaultSheetData); 154 | 155 | const newRows = [ 156 | { 157 | Amount: -554.23, 158 | Name: 'BigBox, inc. __INSERT_TEST__', 159 | }, 160 | { 161 | Amount: -29.74, 162 | Name: 'Fast-n-greasy Food, Inc. __INSERT_TEST__', 163 | }, 164 | ]; 165 | 166 | // Insert rows 167 | sheetQuery(ss).from(SHEET_NAME).insertRows(newRows); 168 | 169 | const query = sheetQuery(ss).from(SHEET_NAME); 170 | const rows = query.getRows(); 171 | 172 | const testRows = rows.filter((row) => row.Name.includes('__INSERT_TEST__')); 173 | 174 | expect(testRows[0].Name).toEqual(newRows[0].Name); 175 | expect(testRows[0].Date).toEqual(''); 176 | expect(testRows[1].Name).toEqual(newRows[1].Name); 177 | expect(testRows[1].Date).toEqual(''); 178 | }); 179 | 180 | it('Should insert rows with 0 numberic values', () => { 181 | setupSpreadsheet(defaultSheetData); 182 | 183 | const newRows = [ 184 | { 185 | Amount: 0, 186 | Name: 'BigBox, inc. __INSERT_TEST_Z__', 187 | Date: '2023-07-28', 188 | }, 189 | { 190 | Amount: 0, 191 | Name: 'Fast-n-greasy Food, Inc. __INSERT_TEST_Z__', 192 | Date: '2023-07-28', 193 | }, 194 | ]; 195 | 196 | // Insert rows 197 | sheetQuery(ss).from(SHEET_NAME).insertRows(newRows); 198 | 199 | const query = sheetQuery(ss).from(SHEET_NAME); 200 | const rows = query.getRows(); 201 | 202 | const testRows = rows.filter((row) => row.Name.includes('__INSERT_TEST_Z__')); 203 | 204 | expect(testRows[0].Name).toEqual(newRows[0].Name); 205 | expect(testRows[0].Amount).toEqual(newRows[0].Amount); 206 | expect(testRows[1].Name).toEqual(newRows[1].Name); 207 | expect(testRows[1].Amount).toEqual(newRows[1].Amount); 208 | }); 209 | 210 | it('should ignore extra columns not present in spreadsheet during insert', () => { 211 | setupSpreadsheet(defaultSheetData); 212 | 213 | const newRows = [ 214 | { 215 | Date: '2021-01-02', 216 | Amount: -554.23, 217 | Name: 'BigBox, inc. __INSERT_TEST__', 218 | XtraCol: 'whatever', 219 | }, 220 | { 221 | Date: '2021-01-02', 222 | Amount: -29.74, 223 | Name: 'Fast-n-greasy Food, Inc. __INSERT_TEST__', 224 | XtraCol: 'nope', 225 | }, 226 | ]; 227 | 228 | // Insert rows 229 | sheetQuery(ss).from(SHEET_NAME).insertRows(newRows); 230 | 231 | const query = sheetQuery(ss).from(SHEET_NAME); 232 | const rows = query.getRows(); 233 | 234 | const testRows = rows.filter((row) => row.Name.includes('__INSERT_TEST__')); 235 | 236 | expect(Object.keys(testRows[0])).not.toContain('XtraCol'); 237 | expect(Object.keys(testRows[1])).not.toContain('XtraCol'); 238 | }); 239 | 240 | it('should not error with empty spreadsheet or headings', () => { 241 | setupSpreadsheet([]); 242 | 243 | const newRows = [ 244 | { 245 | Date: '2021-01-02', 246 | Amount: -554.23, 247 | Name: 'BigBox, inc. __INSERT_TEST__', 248 | XtraCol: 'whatever', 249 | }, 250 | { 251 | Date: '2021-01-02', 252 | Amount: -29.74, 253 | Name: 'Fast-n-greasy Food, Inc. __INSERT_TEST__', 254 | XtraCol: 'nope', 255 | }, 256 | ]; 257 | 258 | // Insert rows 259 | sheetQuery(ss).from(SHEET_NAME).insertRows(newRows); 260 | 261 | const query = sheetQuery(ss).from(SHEET_NAME); 262 | const rows = query.getRows(); 263 | 264 | expect(rows.length).toEqual(0); 265 | }); 266 | 267 | it('should not error with no rows', () => { 268 | setupSpreadsheet(defaultSheetData); 269 | 270 | const newRows: DictObject[] = []; 271 | 272 | // Insert rows 273 | sheetQuery(ss).from(SHEET_NAME).insertRows(newRows); 274 | 275 | const query = sheetQuery(ss).from(SHEET_NAME); 276 | const rows = query.getRows(); 277 | 278 | expect(rows.length).toEqual(defaultSheetData.length); 279 | }); 280 | 281 | it('should not error with rows with no data in them', () => { 282 | setupSpreadsheet(defaultSheetData); 283 | 284 | // @ts-ignore - Obvious type error, but with runtime data... who knows? 285 | const newRows: DictObject[] = [null]; 286 | 287 | // Insert rows 288 | sheetQuery(ss).from(SHEET_NAME).insertRows(newRows); 289 | 290 | const query = sheetQuery(ss).from(SHEET_NAME); 291 | const rows = query.getRows(); 292 | 293 | expect(rows.length).toEqual(defaultSheetData.length); 294 | }); 295 | }); 296 | 297 | describe('updateRows', () => { 298 | it('should return first heading row by default', () => { 299 | setupSpreadsheet(defaultSheetData); 300 | 301 | const catName = 'TEST_CUSTOM_CATEGORY'; 302 | const query = sheetQuery(ss).from(SHEET_NAME); 303 | 304 | // Update rows 305 | query.updateRows((row) => Object.assign(row, { Category: catName })); 306 | 307 | const rows = query.clearCache().getRows(); 308 | const allNewCategory = rows.some((row) => row.Category === catName); 309 | 310 | expect(allNewCategory).toEqual(true); 311 | }); 312 | }); 313 | 314 | describe('updateRow', () => { 315 | it('should update single row using __meta info', () => { 316 | setupSpreadsheet(defaultSheetData); 317 | 318 | const query = sheetQuery(ss).from(SHEET_NAME); 319 | const rows = query.getRows(); 320 | 321 | const someRow = rows.find((row) => row.Name === 'Gasmart'); 322 | 323 | expect(someRow).not.toBeUndefined(); 324 | 325 | // Update row 326 | query.updateRow(someRow, (row) => Object.assign(row, { Name: 'Gasmart Ultra' })); 327 | 328 | const newRows = query.clearCache().getRows(); 329 | const someNewRow = rows.find((row) => row.Name === 'Gasmart Ultra'); 330 | 331 | expect(someNewRow).not.toBeUndefined(); 332 | }); 333 | 334 | it('should update single row with numeric 0 value', () => { 335 | setupSpreadsheet(defaultSheetData); 336 | 337 | const query = sheetQuery(ss).from(SHEET_NAME); 338 | const rows = query.getRows(); 339 | 340 | const someRow = rows.find((row) => row.Name === 'Gasmart'); 341 | 342 | expect(someRow).not.toBeUndefined(); 343 | 344 | // Update row 345 | query.updateRow(someRow, (row) => Object.assign(row, { Name: 'Gasmart Ultra', Amount: 0 })); 346 | 347 | const newRows = query.clearCache().getRows(); 348 | const someNewRow = rows.find((row) => row.Name === 'Gasmart Ultra'); 349 | 350 | expect(someNewRow).not.toBeUndefined(); 351 | expect(someNewRow?.Amount).toEqual(0); 352 | }); 353 | 354 | it('should update without error even with mismatching column counts', () => { 355 | const customSheetData = [ 356 | ['Date', 'Amount', 'Name', 'Category'], 357 | ['2021-01-01', 5.32, 'Kwickiemart', 'Shops'], 358 | ['2021-01-02', 72.48, 'Shopmart', 'Shops'], 359 | ['2021-01-03', 1.97, 'Kwickiemart', 'Shops'], 360 | ['2021-01-03', 43.87, 'Gasmart', 'Gas', '', '', 'something here'], 361 | ['2021-01-04', 824.93, 'Wholepaycheck', 'Groceries'], 362 | ]; 363 | setupSpreadsheet(customSheetData); 364 | 365 | const query = sheetQuery(ss).from(SHEET_NAME); 366 | const rows = query.getRows(); 367 | 368 | const someRow = rows.find((row) => row.Name === 'Gasmart'); 369 | 370 | expect(someRow).not.toBeUndefined(); 371 | 372 | // Update row 373 | query.updateRow(someRow, (row) => Object.assign(row, { Name: 'Gasmart Ultra' })); 374 | 375 | const newRows = query.clearCache().getRows(); 376 | const someNewRow = rows.find((row) => row.Name === 'Gasmart Ultra'); 377 | 378 | expect(someNewRow).not.toBeUndefined(); 379 | }); 380 | }); 381 | }); 382 | --------------------------------------------------------------------------------