├── .gitignore ├── LICENSE ├── README.md ├── package.json ├── src ├── aggregate.js ├── createTable.js ├── distinct.js ├── dropTable.js ├── examples │ ├── createTable.js │ ├── distinct.js │ ├── from.js │ ├── groupBy.js │ ├── having.js │ ├── limit.js │ ├── offset.js │ ├── orderBy.js │ ├── pagination.js │ ├── sampleData.js │ ├── select.js │ ├── update.js │ └── where.js ├── from.js ├── groupBy.js ├── having.js ├── index.js ├── insertInto.js ├── join.js ├── limit.js ├── offset.js ├── orderBy.js ├── output.js ├── select.js ├── update.js ├── util.js └── where.js └── yarn-error.log /.gitignore: -------------------------------------------------------------------------------- 1 | .idea/** 2 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2021-2023 Joshua Weinberg 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy 4 | of this software and associated documentation files (the "Software"), to deal 5 | in the Software without restriction, including without limitation the rights 6 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 7 | copies of the Software, and to permit persons to whom the Software is 8 | furnished to do so, subject to the following conditions: 9 | 10 | The above copyright notice and this permission notice shall be included in all 11 | copies or substantial portions of the Software. 12 | 13 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 14 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 15 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 16 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 17 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 18 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 19 | SOFTWARE. 20 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # What is SQLToy? 2 | 3 | SQLToy is an in-memory SQL database written in Javascript. It is under 500 lines of code and has zero dependencies. It supports the following SQL operations: 4 | 5 | - SELECT 6 | - FROM 7 | - CROSS JOIN 8 | - INNER JOIN 9 | - LEFT JOIN 10 | - RIGHT JOIN 11 | - WHERE 12 | - GROUP BY 13 | - Aggregate functions: ARRAY_AGG, MAX, MIN, COUNT 14 | - DISTINCT 15 | - ORDER BY 16 | - OFFSET 17 | - LIMIT 18 | - CREATE TABLE 19 | - INSERT INTO 20 | - UPDATE 21 | 22 | SQLToy is for learning SQL. Instead of doing this from the "outside-in" by learning the query language you do it "inside-out" by going through the implementation of the most common SQL operators. Instead of just learning what the operators do, you also learn how they do it which (hopefully!) gives you a much deeper level of understanding. 23 | 24 | A detailed [Wiki](https://github.com/weinberg/SQLToy/wiki) walks through the code. Please take a look! 25 | 26 | To get the most out of this repository you should have familiarity with Javascript and some ES6 syntax. If you are proficient in another programming language like Python or Java you should still be able to figure things out. This is not a primer on how to write a production grade database. No attempts are made at performance optimization or compatibility with any standard. SQLToy does not support persistence, transactions or even parsing queries. There are many ways you can break it. See below for usage. 27 | 28 | ## [Read the Wiki](https://github.com/weinberg/SQLToy/wiki) 29 | 30 | The heart of this repo is not the code itself but the walkthrough which describes what you need to understand it: 31 | 32 | This can be found here: [SQLToy Wiki](https://github.com/weinberg/SQLToy/wiki) 33 | 34 | If you are a Javascript programmer I suspect you will find it much simpler than you think. Give it a look! 35 | 36 | ## OK, I will read the Wiki. But how do I _use_ this database? 37 | 38 | There are two concepts you should understand in order to use the database. These are described in detail in the wiki section [Key Concepts](https://github.com/weinberg/SQLToy/wiki/Two-Key-Concepts). 39 | 40 | 1. SQL order of operations. You must call the operations in the correct order. A "real" database will do this for you. In this database you must call the operations in the correct order yourself. 41 | 42 | 2. "Tables in, tables out". All operations in this database (and _conceptually_ in a real database) take tables as input and produce tables as output. So you take a table and provide it to an operation, getting a new table back. To apply multiple operations, supply that new table as an argument to the next operation. 43 | 44 | As an example, the following query in both PostgreSQL and SQLToy: 45 | 46 | ##### PostgreSQL 47 | ```SQL 48 | SELECT DISTINCT status, club.name, COUNT(*) AS count FROM employee 49 | JOIN employee_club 50 | ON employee_club.a = employee.id 51 | JOIN club 52 | ON club.id = employee_club.b 53 | WHERE employee.salary > 80000 54 | GROUP BY status, club.name 55 | ORDER BY count DESC; 56 | 57 | +----------+--------------------+---------+ 58 | | status | name | count | 59 | |----------+--------------------+---------| 60 | | active | Cat Lovers | 2 | 61 | | active | Rotary Club | 1 | 62 | | active | BBQ Crew | 1 | 63 | | active | House Builders | 1 | 64 | | inactive | Education for Kids | 1 | 65 | | inactive | Environmentalists | 1 | 66 | +----------+--------------------+---------+ 67 | ``` 68 | 69 | ##### SQLToy 70 | 71 | To make this query in SQLToy we must re-order the operations according to the [SQL Order of Operations](https://github.com/weinberg/SQLToy/wiki/Two-Key-Concepts) and chain them together: 72 | 73 | ```javascript 74 | let employee = FROM('employee'); 75 | let employee_club = FROM('employee_club'); 76 | result = JOIN(employee, employee_club, (c) => c["employee_club.A"] === c["employee.id"]); 77 | result = JOIN(result, club, (c) => c["employee_club.B"] === c["club.id"] ); 78 | result = WHERE(result, (row) => row['employee.salary'] > 150000); 79 | result = GROUP_BY(result, ['employee.status', 'club.name']); 80 | result = COUNT(result, 'club.name'); 81 | result = SELECT(result,['employee.status', 'club.name','COUNT(club.name)'],{'COUNT(club.name)': 'count'}) 82 | result = DISTINCT(result, ['employee.status', 'club.name', 'count']) 83 | result = ORDER_BY(result, (a,b) => a.count < b.count ? 1 : -1); 84 | table(result); 85 | ``` 86 | 87 | The resulting table can be viewed with the `table()` helper and looks like this: 88 | 89 | ``` 90 | ┌─────────────────┬──────────────────────┬───────┐ 91 | │ employee.status │ club.name │ count │ 92 | ├─────────────────┼──────────────────────┼───────┤ 93 | │ active │ Cat Lovers │ 2 │ 94 | │ active │ Environmentalists │ 1 │ 95 | │ active │ Food for the Needy │ 1 │ 96 | │ active │ House Builders │ 1 │ 97 | │ inactive │ Education for Kids │ 1 │ 98 | │ inactive │ Environmentalists │ 1 │ 99 | └─────────────────┴──────────────────────┴───────┘ 100 | ``` 101 | 102 | ## References 103 | 104 | A good primer on SQL operation execution order: 105 | 106 | https://blog.jooq.org/a-beginners-guide-to-the-true-order-of-sql-operations/ 107 | 108 | For a good discussion of set theory as it applies to the relational model: 109 | 110 | https://medium.com/basecs/set-theory-the-method-to-database-madness-5ec4b4f05d79 . 111 | 112 | ## Contributions 113 | 114 | I welcome contributions! The goals of this project are: 115 | 116 | - Teach SQL through a simple Javascript SQL database implementation 117 | - Simplicity and readability over features or compatibility with any standard 118 | - As few dependencies as possible 119 | 120 | If you have ideas to further these goals you are welcome to submit a pull-request. 121 | 122 | ## License 123 | 124 | The code in SQLToy is licensed under [The MIT License](https://github.com/weinberg/SQLToy/blob/main/LICENSE). 125 | 126 | The contents of the Wiki are licensed separately under the [Creative Commons Attribution-NonCommercial-NoDerivatives 4.0 International License](https://github.com/weinberg/SQLToy/wiki/LICENSE). 127 | 128 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "SQLToy", 3 | "version": "1.0.0", 4 | "description": "SQL database implemented in Javascript", 5 | "main": "index.js", 6 | "repository": "git@weinberg.github.com:weinberg/SQLtoy.git", 7 | "author": "Joshua Weinberg", 8 | "license": "MIT", 9 | "private": false, 10 | "type": "module" 11 | } 12 | -------------------------------------------------------------------------------- /src/aggregate.js: -------------------------------------------------------------------------------- 1 | // AGGREGATE FUNCTIONS 2 | 3 | const aggregateHelper = (table, column, aggName, aggFunc) => { 4 | for (const row of table.rows) { 5 | const pick = row._groupRows.map(gr => gr[column]) 6 | row[`${aggName}(${column})`] = aggFunc(pick); 7 | } 8 | return table; 9 | } 10 | 11 | // ARRAY_AGG returns a table with a new aggregate column for the given grouped column 12 | // which just contains the list of the grouped values 13 | const ARRAY_AGG = (table, column) => { 14 | return aggregateHelper(table, column, 'ARRAY_AGG', values => JSON.stringify(values)); 15 | } 16 | 17 | // AVG returns a table with a new aggregate column for the given grouped column 18 | // which contains the average of the grouped values 19 | const AVG = (table, column) => { 20 | return aggregateHelper(table, column, 'AVG', values => { 21 | const total = values.reduce((p, c) => p + c, 0); 22 | return total / values.length; 23 | }); 24 | } 25 | 26 | // MAX aggregate function 27 | const MAX = (table, column) => { 28 | const getMax = (a, b) => Math.max(a, b); 29 | return aggregateHelper(table, column, 'MAX', values => values.reduce(getMax)); 30 | } 31 | 32 | // MIN aggregate function 33 | const MIN = (table, column) => { 34 | const getMin = (a, b) => Math.min(a, b); 35 | return aggregateHelper(table, column, 'MIN', values => values.reduce(getMin)); 36 | } 37 | 38 | // COUNT aggregate function 39 | // todo - only count rows where column is not null. this will break the count('*') hack so we might need to special case that 40 | const COUNT = (table, column) => { 41 | return aggregateHelper(table, column, 'COUNT', values => values.length); 42 | } 43 | 44 | export { 45 | ARRAY_AGG, 46 | AVG, 47 | COUNT, 48 | MAX, 49 | MIN 50 | } 51 | -------------------------------------------------------------------------------- /src/createTable.js: -------------------------------------------------------------------------------- 1 | import { database } from './index.js'; 2 | 3 | /** 4 | * CREATE_TABLE 5 | */ 6 | 7 | function CREATE_TABLE(name) { 8 | database.tables[name] = { 9 | name, 10 | rows: [] 11 | } 12 | 13 | return database.tables[name]; 14 | } 15 | 16 | export { CREATE_TABLE } 17 | -------------------------------------------------------------------------------- /src/distinct.js: -------------------------------------------------------------------------------- 1 | /** 2 | * DISTINCT 3 | */ 4 | 5 | import {US} from "./util.js"; 6 | 7 | // Distinct takes a table and reduces the rows based on unique values in the columns given. 8 | // Only the columns given will be returned in the resulting table. 9 | 10 | const DISTINCT = (table, columns) => { 11 | const _distinct = {} 12 | for (const row of table.rows) { 13 | // make composite key 14 | let key = columns.map(column => row[column]).join(US); 15 | _distinct[key] = row; 16 | } 17 | 18 | const newRows = []; 19 | for (let key in _distinct) { 20 | const newRow = {}; 21 | for (let column of columns) { 22 | newRow[column] = _distinct[key][column]; 23 | } 24 | newRows.push(newRow); 25 | } 26 | 27 | return { 28 | name: table.name, 29 | rows: newRows, 30 | }; 31 | } 32 | 33 | export { DISTINCT } 34 | -------------------------------------------------------------------------------- /src/dropTable.js: -------------------------------------------------------------------------------- 1 | import { database } from './index.js' 2 | 3 | function DROP_TABLE(tableName) { 4 | delete database.tables[tableName]; 5 | } 6 | 7 | export { DROP_TABLE }; 8 | -------------------------------------------------------------------------------- /src/examples/createTable.js: -------------------------------------------------------------------------------- 1 | import {CREATE_TABLE} from "../createTable.js"; 2 | import {INSERT_INTO} from "../insertInto.js"; 3 | import {FROM} from "../from.js"; 4 | import {table} from "../output.js"; 5 | import {initSQLToy} from "../index.js"; 6 | 7 | initSQLToy(); 8 | CREATE_TABLE('stories'); 9 | INSERT_INTO('stories', [ 10 | { id: 1, name: 'The Elliptical Machine that ate Manhattan', author_id: 1 }, 11 | { id: 2, name: 'Queen of the Bats', author_id: 2 }, 12 | { id: 3, name: 'ChocoMan', author_id: 3 }, 13 | ]); 14 | INSERT_INTO('stories', { id: 4, name: 'Something', author_id: 5}); 15 | const stories = FROM('stories'); 16 | table(stories); 17 | console.log(JSON.stringify(stories,null,2)); 18 | -------------------------------------------------------------------------------- /src/examples/distinct.js: -------------------------------------------------------------------------------- 1 | import {table} from "../output.js"; 2 | import {SELECT} from "../select.js"; 3 | import {DISTINCT} from "../distinct.js"; 4 | import {initSQLToy} from "../index.js"; 5 | import {FROM} from "../from.js"; 6 | import {JOIN} from "../join.js"; 7 | import {WHERE} from "../where.js"; 8 | import {GROUP_BY} from "../groupBy.js"; 9 | import {COUNT} from "../aggregate.js"; 10 | import {ORDER_BY} from "../orderBy.js"; 11 | import {CREATE_TABLE} from "../createTable.js"; 12 | import {INSERT_INTO} from "../insertInto.js"; 13 | 14 | // demo distinct 15 | 16 | initSQLToy(); 17 | /* 18 | +------+------------------+----------+ 19 | | id | city | state | 20 | |------+------------------+----------| 21 | | 1 | Denver | Colorado | 22 | | 2 | Colorado Springs | Colorado | 23 | | 3 | South Park | Colorado | 24 | | 4 | Corpus Christi | Texas | 25 | | 5 | Houston | Texas | 26 | | 6 | Denver | Colorado | 27 | | 7 | Corpus Christi | Texas | 28 | +------+------------------+----------+ 29 | */ 30 | 31 | CREATE_TABLE('friends'); 32 | INSERT_INTO('friends',[ 33 | {id:1,city:'Denver',state:'Colorado'}, 34 | {id:2,city:'Colorado Springs',state:'Colorado'}, 35 | {id:3,city:'South Park',state:'Colorado'}, 36 | {id:4,city:'Corpus Christi',state:'Texas'}, 37 | {id:5,city:'Houston',state:'Texas'}, 38 | {id:6,city:'Denver',state:'Colorado'}, 39 | {id:7,city:'Corpus Christi',state:'Texas'}, 40 | ]); 41 | 42 | const friends = FROM('friends'); 43 | const result = DISTINCT(friends, ['city', 'state']); 44 | table(result); 45 | process.exit(); 46 | 47 | /* 48 | CREATE_TABLE('book'); 49 | INSERT_INTO('book', [ 50 | { id: 1, name: 'The C Programming Language', status: 'Checked Out' }, 51 | { id: 2, name: 'SQL Fundamentals', status: 'Checked Out' }, 52 | { id: 3, name: 'The Magic Garden Explained', status: 'Checked Out' }, 53 | { id: 4, name: 'The Art of Computer Programming', status: 'Available' }, 54 | { id: 5, name: 'Design Patterns', status: 'Available' }, 55 | { id: 6, name: 'Compilers, ', status: 'Missing' }, 56 | ]); 57 | 58 | // Distinct on status 59 | const book = FROM('book'); 60 | let result = SELECT(book, ['status']); 61 | result = DISTINCT(result, ['status']); 62 | table(result); 63 | 64 | */ 65 | 66 | // Output: 67 | /* 68 | ┌───────────────┐ 69 | │ status │ 70 | ├───────────────┤ 71 | │ Checked Out │ 72 | │ Available │ 73 | │ Missing │ 74 | └───────────────┘ 75 | */ 76 | 77 | // Distinct can work on multiple columns 78 | 79 | // This query joins on club and then does distinct on status and club.name 80 | // which leads to (active, Cat Lovers) and (inactive, Environmentalists) being condensed to a single row 81 | // 82 | // SELECT distinct status, club.name, COUNT(*) AS count FROM employee 83 | // JOIN employee_club ON employee_club.a = employee.id 84 | // JOIN club ON club.id = employee_club.b 85 | // WHERE employee.salary > 150000 86 | // GROUP BY status, club.name 87 | 88 | /* 89 | Result: 90 | ┌─────────────────┬──────────────────────┬───────┐ 91 | │ employee.status │ club.name │ count │ 92 | ├─────────────────┼──────────────────────┼───────┤ 93 | │ active │ Cat Lovers │ 2 │ 94 | │ inactive │ Environmentalists │ 1 │ 95 | │ inactive │ Education for Kids │ 1 │ 96 | │ active │ House Builders │ 1 │ 97 | │ active │ Food for the Needy │ 1 │ 98 | │ active │ Environmentalists │ 1 │ 99 | └─────────────────┴──────────────────────┴───────┘ 100 | */ 101 | 102 | // First do join via join table 103 | 104 | employee = FROM('employee'); 105 | club = FROM('club'); 106 | employee_club = FROM('employee_club'); 107 | result = JOIN(employee, employee_club, (c) => c["employee_club.A"] === c["employee.id"]); 108 | result = JOIN(result, club, (c) => c["employee_club.B"] === c["club.id"]); 109 | result = WHERE(result, (row) => row['employee.salary'] > 150000); 110 | result = GROUP_BY(result, ['employee.status', 'club.name']); 111 | result = COUNT(result, 'club.name'); 112 | result = SELECT(result, ['employee.status', 'club.name', 'COUNT(club.name)'], {'COUNT(club.name)': 'count'}); 113 | result = DISTINCT(result, ['employee.status', 'club.name', 'count']); 114 | result = ORDER_BY(result, (a, b) => a.count < b.count ? 1 : -1); 115 | 116 | table(result); 117 | -------------------------------------------------------------------------------- /src/examples/from.js: -------------------------------------------------------------------------------- 1 | import {table} from "../output.js"; 2 | import {CROSS_JOIN, INNER_JOIN, LEFT_JOIN, RIGHT_JOIN} from "../join.js"; 3 | import {FROM} from "../from.js"; 4 | import {setupDatabase} from "./sampleData.js"; 5 | import {initSQLToy} from "../index.js"; 6 | import {CREATE_TABLE} from "../createTable.js"; 7 | import {INSERT_INTO} from "../insertInto.js"; 8 | import {SELECT} from "../select.js"; 9 | import {ORDER_BY} from "../orderBy.js"; 10 | 11 | // Demo 12 | initSQLToy(); 13 | setupDatabase(); 14 | let employee; 15 | let department; 16 | let club; 17 | let employee_club; 18 | let result; 19 | 20 | /***********************************/ 21 | 22 | let test1 = CREATE_TABLE('test1'); 23 | let test2 = CREATE_TABLE('test2'); 24 | INSERT_INTO('test1', {c: 'A'}); 25 | INSERT_INTO('test1', {c: 'B'}); 26 | INSERT_INTO('test2', {c: '1'}); 27 | INSERT_INTO('test2', {c: '2'}); 28 | 29 | // manually doing cross join 30 | result = CROSS_JOIN(test1, test2); 31 | result = SELECT(CROSS_JOIN(test1, test2), ['test1.c', 'test2.c']) 32 | table(result); 33 | 34 | // giving multiple tables to FROM 35 | result = FROM(['test1', 'test2']); 36 | table(result); 37 | 38 | let test3 = CREATE_TABLE('test3'); 39 | INSERT_INTO('test3', {c: 'X'}); 40 | INSERT_INTO('test3', {c: 'Y'}); 41 | result = FROM(['test1', 'test2', 'test3']); 42 | table(result); 43 | 44 | /***********************************/ 45 | 46 | console.log("\n-- Inner join employee, department on department id"); 47 | console.log( 48 | "-- Equivalent SQL: SELECT * FROM employee JOIN department ON employee.department_id = department.id;" 49 | ); 50 | employee = FROM('employee'); 51 | department = FROM('department'); 52 | result = INNER_JOIN(employee, department, (c) => c["employee.department_id"] === c["department.id"]); 53 | table(result); 54 | 55 | /***********************************/ 56 | 57 | console.log("\n-- Left join employee, department on department id --"); 58 | console.log( 59 | "-- Equivalent SQL: SELECT * FROM employee LEFT JOIN department ON employee.department_id = department.id;" 60 | ); 61 | employee = FROM('employee'); 62 | department = FROM('department'); 63 | result = LEFT_JOIN(employee, department, (c) => c["employee.department_id"] === c["department.id"]); 64 | table(result); 65 | 66 | /***********************************/ 67 | 68 | console.log("\n-- Right outer join on department id --"); 69 | console.log( 70 | "-- Equivalent SQL: SELECT * FROM employee RIGHT JOIN department ON employee.department_id = department.id;" 71 | ); 72 | employee = FROM('employee'); 73 | department = FROM('department'); 74 | result = RIGHT_JOIN(employee, department, (c) => c["employee.department_id"] === c["department.id"]); 75 | table(result); 76 | 77 | /***********************************/ 78 | 79 | // Join using the join table 80 | 81 | console.log("\n-- Many to many join employee to charity group"); 82 | console.log( 83 | "-- Equivalent SQL: SELECT * FROM employee JOIN employee_club ON employee_club.a = employee.id JOIN club ON club.id = employee_club.b " 84 | ); 85 | employee = FROM('employee'); 86 | club = FROM('club'); 87 | employee_club = FROM('employee_club'); 88 | result = INNER_JOIN(employee, employee_club, (c) => c["employee_club.A"] === c["employee.id"]); 89 | result = INNER_JOIN(result, club, (c) => c["employee_club.B"] === c["club.id"]); 90 | result = SELECT(result, ['employee.name', 'club.name']); 91 | result = ORDER_BY(result, (a, b) => a['employee.name'].localeCompare(b['employee.name'])); 92 | table(result); 93 | -------------------------------------------------------------------------------- /src/examples/groupBy.js: -------------------------------------------------------------------------------- 1 | import {GROUP_BY} from "../groupBy.js"; 2 | import {ARRAY_AGG, AVG, COUNT, MAX, MIN} from "../aggregate.js"; 3 | import {table} from "../output.js"; 4 | import {setupDatabase, setupSimpleDatabase} from "./sampleData.js"; 5 | import {initSQLToy} from "../index.js"; 6 | import {FROM} from "../from.js"; 7 | import {DROP_TABLE} from "../dropTable.js"; 8 | import {CREATE_TABLE} from "../createTable.js"; 9 | import {INSERT_INTO} from "../insertInto.js"; 10 | import {SELECT} from "../select.js"; 11 | 12 | initSQLToy(); 13 | setupSimpleDatabase(); 14 | let employee; 15 | let result; 16 | 17 | /**********************************************/ 18 | 19 | /* 20 | console.log('SELECT department_id, ARRAY_AGG(role) FROM employee GROUP BY department_id'); 21 | 22 | DROP_TABLE('employee'); 23 | CREATE_TABLE('employee'); 24 | INSERT_INTO('employee',[ 25 | {id:1,name:'Josh',department_id:1,role:'Manager'}, 26 | {id:2,name:'Ruth',department_id:2,role:'Worker'}, 27 | {id:3,name:'Jake',department_id:1,role:'Worker'}, 28 | {id:4,name:'John',department_id:2,role:'Worker'}, 29 | {id:5,name:'Alice',department_id:2,role:'Manager'}, 30 | {id:6,name:'Dan',department_id:1,role:'Manager'}, 31 | {id:7,name:'Janet',department_id:1,role:'Manager'}, 32 | ]); 33 | employee = FROM('employee'); 34 | result = GROUP_BY(employee, ['department_id']); 35 | console.log(JSON.stringify(result,null,2)); 36 | result = ARRAY_AGG(result, 'name'); 37 | result = SELECT(result, ['department_id','ARRAY_AGG(name)']); 38 | table(result) 39 | 40 | process.exit(); 41 | */ 42 | 43 | /********************************************** 44 | 45 | console.log('SELECT department_id, role, COUNT(*), ARRAY_AGG(name) FROM employee GROUP BY department_id, role;'); 46 | 47 | DROP_TABLE('employee'); 48 | CREATE_TABLE('employee'); 49 | INSERT_INTO('employee',[ 50 | {id:1,name:'Josh',department_id:1,role:'Manager'}, 51 | {id:2,name:'Ruth',department_id:2,role:'Worker'}, 52 | {id:3,name:'Jake',department_id:1,role:'Worker'}, 53 | {id:4,name:'John',department_id:2,role:'Worker'}, 54 | {id:5,name:'Alice',department_id:2,role:'Manager'}, 55 | {id:6,name:'Dan',department_id:1,role:'Manager'}, 56 | {id:7,name:'Janet',department_id:1,role:'Manager'}, 57 | ]); 58 | employee = FROM('employee'); 59 | result = GROUP_BY(employee, ['department_id','role']); 60 | console.log(JSON.stringify(result,null,2)); 61 | result = COUNT(result, '*'); 62 | result = ARRAY_AGG(result, 'name'); 63 | result = SELECT(result, ['department_id','role','COUNT(*)','ARRAY_AGG(name)']); 64 | table(result) 65 | 66 | process.exit(); 67 | */ 68 | 69 | /********************************************** 70 | 71 | /* 72 | console.log('SELECT department_id, COUNT(*) FROM employee GROUP BY department_id'); 73 | 74 | DROP_TABLE('employee'); 75 | CREATE_TABLE('employee'); 76 | INSERT_INTO('employee',[ 77 | {id:1,name:'Josh',department_id:1,role:'Manager'}, 78 | {id:2,name:'Ruth',department_id:2,role:'Worker'}, 79 | {id:3,name:'Jake',department_id:1,role:'Worker'}, 80 | {id:4,name:'John',department_id:2,role:'Worker'}, 81 | {id:5,name:'Alice',department_id:2,role:'Manager'}, 82 | {id:6,name:'Dan',department_id:1,role:'Manager'}, 83 | {id:7,name:'Janet',department_id:1,role:'Manager'}, 84 | ]); 85 | employee = FROM('employee'); 86 | result = GROUP_BY(employee, ['department_id']); 87 | result = COUNT(result, '*'); 88 | result = SELECT(result, ['department_id','COUNT(*)'], {'COUNT(*)': 'count'}); 89 | table(result) 90 | 91 | process.exit(); 92 | */ 93 | 94 | /**********************************************/ 95 | 96 | CREATE_TABLE('test_scores'); 97 | INSERT_INTO('test_scores',[ 98 | {student_id:1,test_id:1,score:100}, 99 | {student_id:1,test_id:2,score:90}, 100 | {student_id:2,test_id:1,score:85}, 101 | {student_id:2,test_id:2,score:80}, 102 | {student_id:3,test_id:1,score:75}, 103 | {student_id:3,test_id:2,score:99}, 104 | ]); 105 | const testScores = FROM('test_scores'); 106 | result = GROUP_BY(testScores, ['student_id']); 107 | result = ARRAY_AGG(result, 'score'); 108 | console.log(JSON.stringify(result,null,2)); 109 | result = SELECT(result, ['student_id','ARRAY_AGG(score)']); 110 | table(result) 111 | 112 | process.exit(); 113 | 114 | /**********************************************/ 115 | 116 | console.log('SELECT department_id, array_agg(salary) FROM employee GROUP BY department_id'); 117 | 118 | employee = FROM('employee'); 119 | result = GROUP_BY(employee, ['department_id']); 120 | result = ARRAY_AGG(result, 'salary'); 121 | table(result) 122 | 123 | /**********************************************/ 124 | 125 | console.log('SELECT department_id, avg(salary) FROM employee GROUP BY department_id'); 126 | 127 | employee = FROM('employee'); 128 | result = GROUP_BY(employee, ['department_id']); 129 | result = AVG(result, 'salary'); 130 | table(result) 131 | 132 | /**********************************************/ 133 | 134 | console.log('SELECT department_id, avg(salary), array_agg(salary) FROM employee GROUP BY department_id'); 135 | 136 | employee = FROM('employee'); 137 | result = GROUP_BY(employee, ['department_id']); 138 | result = ARRAY_AGG(result, 'salary'); 139 | result = AVG(result, 'salary'); 140 | result = MAX(result, 'salary'); 141 | result = MIN(result, 'salary'); 142 | result = COUNT(result, 'salary'); 143 | table(result) 144 | 145 | /* 146 | SELECT department_id, array_agg(salary) FROM employee GROUP BY department_id 147 | ┌───────────────┬────────────────────────────┐ 148 | │ department_id │ ARRAY_AGG(salary) │ 149 | ├───────────────┼────────────────────────────┤ 150 | │ 1 │ [ 150000, 200000, 180000 ] │ 151 | │ 2 │ [ 160000 ] │ 152 | │ │ [ 120000, 200000 ] │ 153 | └───────────────┴────────────────────────────┘ 154 | 155 | 156 | SELECT department_id, avg(salary) FROM employee GROUP BY department_id 157 | ┌───────────────┬────────────────────┐ 158 | │ department_id │ AVG(salary) │ 159 | ├───────────────┼────────────────────┤ 160 | │ 1 │ 176666.66666666666 │ 161 | │ 2 │ 160000 │ 162 | │ │ 160000 │ 163 | └───────────────┴────────────────────┘ 164 | 165 | 166 | SELECT department_id, avg(salary), array_agg(salary) FROM employee GROUP BY department_id 167 | ┌───────────────┬────────────────────────────┬────────────────────┬─────────────┬─────────────┬───────────────┐ 168 | │ department_id │ ARRAY_AGG(salary) │ AVG(salary) │ MAX(salary) │ MIN(salary) │ COUNT(salary) │ 169 | ├───────────────┼────────────────────────────┼────────────────────┼─────────────┼─────────────┼───────────────┤ 170 | │ 1 │ [ 150000, 200000, 180000 ] │ 176666.66666666666 │ 200000 │ 150000 │ 3 │ 171 | │ 2 │ [ 160000 ] │ 160000 │ 160000 │ 160000 │ 1 │ 172 | │ │ [ 120000, 200000 ] │ 160000 │ 200000 │ 120000 │ 2 │ 173 | └───────────────┴────────────────────────────┴────────────────────┴─────────────┴─────────────┴───────────────┘ 174 | */ 175 | -------------------------------------------------------------------------------- /src/examples/having.js: -------------------------------------------------------------------------------- 1 | import {GROUP_BY} from "../groupBy.js"; 2 | import {COUNT} from "../aggregate.js"; 3 | import {table} from "../output.js"; 4 | import {HAVING} from "../having.js"; 5 | import {initSQLToy} from "../index.js"; 6 | import {setupDatabase} from "./sampleData.js"; 7 | import {FROM} from "../from.js"; 8 | 9 | initSQLToy(); 10 | setupDatabase(); 11 | let employee; 12 | let result; 13 | 14 | employee = FROM('employee'); 15 | result = GROUP_BY(employee, ['department_id']); 16 | result = COUNT(result, 'department_id'); 17 | result = HAVING(result, (row) => row['COUNT(department_id)'] > 2); 18 | table(result); 19 | 20 | /* 21 | ┌───────────────┬──────────────────────┐ 22 | │ department_id │ COUNT(department_id) │ 23 | ├───────────────┼──────────────────────┤ 24 | │ 1 │ 3 │ 25 | └───────────────┴──────────────────────┘ 26 | */ 27 | -------------------------------------------------------------------------------- /src/examples/limit.js: -------------------------------------------------------------------------------- 1 | import {SELECT} from "../select.js"; 2 | import {LIMIT} from "../limit.js"; 3 | import {ORDER_BY} from "../orderBy.js"; 4 | import {table} from "../output.js"; 5 | import {initSQLToy} from "../index.js"; 6 | import {setupDatabase} from "./sampleData.js"; 7 | import {FROM} from "../from.js"; 8 | 9 | initSQLToy(); 10 | setupDatabase(); 11 | let employee; 12 | let result; 13 | 14 | employee = FROM('employee'); 15 | result = SELECT(employee, ['name', 'status', 'salary']); 16 | result = ORDER_BY(result, (a,b) => a.salary - b.salary); 17 | result = LIMIT(result, 4); 18 | table(result); 19 | 20 | /* 21 | ┌───────────┬────────────┬────────┐ 22 | │ name │ status │ salary │ 23 | ├───────────┼────────────┼────────┤ 24 | │ Michael │ active │ 120000 │ 25 | │ Josh │ inactive │ 150000 │ 26 | │ Jane │ active │ 160000 │ 27 | │ Elliot │ active │ 180000 │ 28 | └───────────┴────────────┴────────┘ 29 | 30 | */ 31 | -------------------------------------------------------------------------------- /src/examples/offset.js: -------------------------------------------------------------------------------- 1 | import {SELECT} from "../select.js"; 2 | import {ORDER_BY} from "../orderBy.js"; 3 | import {OFFSET} from "../offset.js"; 4 | import {table} from "../output.js"; 5 | import {initSQLToy} from "../index.js"; 6 | import {setupDatabase} from "./sampleData.js"; 7 | import {FROM} from "../from.js"; 8 | import {CREATE_TABLE} from "../createTable.js"; 9 | import {INSERT_INTO} from "../insertInto.js"; 10 | import {LIMIT} from "../limit.js"; 11 | 12 | initSQLToy(); 13 | setupDatabase(); 14 | let employee; 15 | 16 | CREATE_TABLE('filenames'); 17 | INSERT_INTO('filenames', [ 18 | {filename:'00-INDEX'}, 19 | {filename:'07'}, 20 | {filename:'1040.bin.ihex'}, 21 | {filename:'11d.c'}, 22 | {filename:'11d.h'}, 23 | {filename:'1200.bin.ihex'}, 24 | {filename:'12160.bin.ihex'}, 25 | {filename:'1232ea962bbaf0e909365f4964f6cceb2ba8ce'}, 26 | {filename:'1280.bin.ihex'}, 27 | {filename:'15562512ca6cf14c1b8f08e09d5907118deaf0'}, 28 | {filename:'17'}, 29 | {filename:'1d'}, 30 | {filename:'1.Intro'}, 31 | {filename:'21142.c'}, 32 | {filename:'21285.c'}, 33 | {filename:'2860_main_dev.c'}, 34 | {filename:'2860_rtmp_init.c'}, 35 | {filename:'2870_main_dev.c'}, 36 | {filename:'2870_rtmp_init.c'}, 37 | {filename:'2.Process'}, 38 | {filename:''}, 39 | ]); 40 | const filenames = FROM('filenames'); 41 | let result = OFFSET(filenames, 10); // 0 offset is just for example 42 | result = LIMIT(result, 10); 43 | table(result); 44 | process.exit(); 45 | 46 | /* 47 | employee = FROM('employee'); 48 | result = SELECT(employee, ['name', 'status', 'salary']); 49 | result = ORDER_BY(result, (a,b) => a.salary - b.salary); 50 | result = OFFSET(result, 2); 51 | table(result); 52 | 53 | /* 54 | ┌──────────┬────────────┬────────┐ 55 | │ name │ status │ salary │ 56 | ├──────────┼────────────┼────────┤ 57 | │ Jane │ active │ 160000 │ 58 | │ Elliot │ active │ 180000 │ 59 | │ Ruth │ inactive │ 200000 │ 60 | │ Garth │ active │ 200000 │ 61 | └──────────┴────────────┴────────┘ 62 | */ 63 | -------------------------------------------------------------------------------- /src/examples/orderBy.js: -------------------------------------------------------------------------------- 1 | // order by name 2 | import {SELECT} from "../select.js"; 3 | import {table} from "../output.js"; 4 | import {ORDER_BY} from "../orderBy.js"; 5 | import {FROM} from "../from.js"; 6 | import {initSQLToy} from "../index.js"; 7 | import {setupDatabase} from "./sampleData.js"; 8 | import {INSERT_INTO} from "../insertInto.js"; 9 | import {DROP_TABLE} from "../dropTable.js"; 10 | import {CREATE_TABLE} from "../createTable.js"; 11 | 12 | initSQLToy(); 13 | setupDatabase(); 14 | let employee; 15 | let result; 16 | 17 | DROP_TABLE('employee'); 18 | CREATE_TABLE('employee'); 19 | INSERT_INTO('employee',[ 20 | {id:1,name:'Josh',department_id:1,role:'Worker'}, 21 | {id:2,name:'Ruth',department_id:2,role:'Worker'}, 22 | {id:3,name:'Jake',department_id:1,role:'Worker'}, 23 | {id:4,name:'John',department_id:2,role:'Worker'}, 24 | {id:5,name:'Alice',department_id:2,role:'Manager'}, 25 | {id:6,name:'Dan',department_id:1,role:'Manager'}, 26 | {id:7,name:'Janet',department_id:1,role:'Manager'}, 27 | ]); 28 | employee = FROM('employee'); 29 | result = ORDER_BY(employee, (a, b) => a['name'].localeCompare(b['name'])); 30 | table(result); 31 | process.exit(); 32 | 33 | /* 34 | ┌───────────┬────────────┐ 35 | │ name │ status │ 36 | ├───────────┼────────────┤ 37 | │ Elliot │ active │ 38 | │ Garth │ active │ 39 | │ Jane │ active │ 40 | │ Josh │ inactive │ 41 | │ Michael │ active │ 42 | │ Ruth │ inactive │ 43 | └───────────┴────────────┘ 44 | */ 45 | 46 | // order by status 47 | employee = FROM('employee'); 48 | result = SELECT(employee, ['name', 'status']); 49 | result = ORDER_BY(result, (a,b) => { if (a.status < b.status) { return -1; } else { return 1; } }); 50 | console.log('Order by status:'); 51 | table(result); 52 | 53 | /* 54 | ┌───────────┬────────────┐ 55 | │ name │ status │ 56 | ├───────────┼────────────┤ 57 | │ Jane │ active │ 58 | │ Elliot │ active │ 59 | │ Michael │ active │ 60 | │ Garth │ active │ 61 | │ Josh │ inactive │ 62 | │ Ruth │ inactive │ 63 | └───────────┴────────────┘ 64 | 65 | */ 66 | -------------------------------------------------------------------------------- /src/examples/pagination.js: -------------------------------------------------------------------------------- 1 | import {table} from "../output.js"; 2 | import {SELECT} from "../select.js"; 3 | import {ORDER_BY} from "../orderBy.js"; 4 | import {OFFSET} from "../offset.js"; 5 | import {LIMIT} from "../limit.js"; 6 | import {setupDatabase} from "./sampleData.js"; 7 | import {initSQLToy} from "../index.js"; 8 | import {FROM} from "../from.js"; 9 | 10 | // OFFSET and LIMIT used together paginate data 11 | 12 | initSQLToy(); 13 | setupDatabase(); 14 | let employee; 15 | let result; 16 | 17 | // page 1 18 | employee = FROM('employee'); 19 | result = SELECT(employee, ['name', 'status', 'salary']); 20 | result = ORDER_BY(result, (a,b) => a.salary - b.salary); 21 | result = OFFSET(result, 0); 22 | result = LIMIT(result, 4); 23 | table(result); 24 | 25 | /* 26 | ┌───────────┬────────────┬────────┐ 27 | │ name │ status │ salary │ 28 | ├───────────┼────────────┼────────┤ 29 | │ Michael │ active │ 120000 │ 30 | │ Josh │ inactive │ 150000 │ 31 | │ Jane │ active │ 160000 │ 32 | │ Elliot │ active │ 180000 │ 33 | └───────────┴────────────┴────────┘ 34 | */ 35 | 36 | 37 | // page 2 38 | employee = FROM('employee'); 39 | result = SELECT(employee, ['name', 'status', 'salary']); 40 | result = ORDER_BY(result, (a,b) => a.salary - b.salary); 41 | result = OFFSET(result, 4); 42 | result = LIMIT(result, 4); 43 | table(result); 44 | 45 | /* 46 | ┌─────────┬────────────┬────────┐ 47 | │ name │ status │ salary │ 48 | ├─────────┼────────────┼────────┤ 49 | │ Ruth │ inactive │ 200000 │ 50 | │ Garth │ active │ 200000 │ 51 | └─────────┴────────────┴────────┘ 52 | */ 53 | -------------------------------------------------------------------------------- /src/examples/sampleData.js: -------------------------------------------------------------------------------- 1 | import {CREATE_TABLE} from "../createTable.js"; 2 | import {INSERT_INTO} from "../insertInto.js"; 3 | import {table} from "../output.js"; 4 | import {FROM} from "../from.js"; 5 | import {initSQLToy} from "../index.js"; 6 | 7 | /****************** 8 | * 9 | * Sample data 10 | * 11 | *****************/ 12 | 13 | /* 14 | employee 15 | +------+--------+-----------------+ 16 | | id | name | department_id | 17 | |------+--------+-----------------| 18 | | 1 | Josh | 1 | 19 | | 2 | Ruth | 2 | 20 | | 3 | Greg | 5 | 21 | +------+--------+-----------------+ 22 | 23 | department 24 | +------+-------------+ 25 | | id | name | 26 | |------+-------------| 27 | | 1 | Sales | 28 | | 2 | Marketing | 29 | | 3 | Engineering | 30 | +------+-------------+ 31 | */ 32 | 33 | // simple data 34 | function setupSimpleDatabase() { 35 | CREATE_TABLE('employee'); 36 | INSERT_INTO('employee', {id: 1, name: "Josh", department_id: 1, salary: 50000}); 37 | INSERT_INTO('employee', {id: 2, name: "Ruth", department_id: 2, salary: 60000}); 38 | INSERT_INTO('employee', {id: 3, name: "Greg", department_id: 5, salary: 70000}); 39 | INSERT_INTO('employee', {id: 4, name: "Pat", department_id: 1, salary: 80000}); 40 | 41 | CREATE_TABLE('department'); 42 | INSERT_INTO('department', {id: 1, name: "Sales"}); 43 | INSERT_INTO('department', {id: 2, name: "Marketing"}); 44 | INSERT_INTO('department', {id: 3, name: "Engineering"}); 45 | } 46 | 47 | // more complex data 48 | function setupDatabase() { 49 | CREATE_TABLE('employee'); 50 | INSERT_INTO('employee', {id: 1, name: "Josh"}); 51 | INSERT_INTO('employee', {id: 2, name: "Jane"}); 52 | INSERT_INTO('employee', {id: 3, name: "Ruth"}); 53 | INSERT_INTO('employee', {id: 4, name: "Elliot"}); 54 | INSERT_INTO('employee', {id: 5, name: "Michael"}); 55 | INSERT_INTO('employee', {id: 6, name: "Garth"}); 56 | 57 | CREATE_TABLE('department'); 58 | INSERT_INTO('department', {id: 1, name: "Sales"}); 59 | INSERT_INTO('department', {id: 2, name: "Engineering"}); 60 | INSERT_INTO('department', {id: 3, name: "Management"}); 61 | INSERT_INTO('department', {id: 4, name: "Consultants"}); 62 | 63 | CREATE_TABLE('club'); 64 | INSERT_INTO('club', {id: 1, name: "Cat Lovers"}); 65 | INSERT_INTO('club', {id: 2, name: "House Builders"}); 66 | INSERT_INTO('club', {id: 3, name: "Book Drive"}); 67 | INSERT_INTO('club', {id: 4, name: "Carbon Offset Club"}); 68 | INSERT_INTO('club', {id: 5, name: "Asian Languages"}); 69 | INSERT_INTO('club', {id: 6, name: "Weekly Potluck"}); 70 | 71 | // join table for many-to-many relation between employee and club 72 | // employees can be in zero or more groups 73 | // groups can have zero or more employees 74 | CREATE_TABLE('employee_club'); 75 | INSERT_INTO('employee_club', {A: 1, B: 1},); 76 | INSERT_INTO('employee_club', {A: 1, B: 4},); 77 | INSERT_INTO('employee_club', {A: 2, B: 1},); 78 | INSERT_INTO('employee_club', {A: 3, B: 4},); 79 | INSERT_INTO('employee_club', {A: 3, B: 5},); 80 | INSERT_INTO('employee_club', {A: 4, B: 1},); 81 | INSERT_INTO('employee_club', {A: 4, B: 2},); 82 | INSERT_INTO('employee_club', {A: 4, B: 3},); 83 | INSERT_INTO('employee_club', {A: 4, B: 4},); 84 | 85 | /* 86 | const employee = FROM('employee'); 87 | table(employee); 88 | const club = FROM('club'); 89 | table(club); 90 | const employee_club = FROM('employee_club'); 91 | table(employee_club); 92 | */ 93 | } 94 | 95 | /* 96 | initSQLToy(); 97 | setupDatabase(); 98 | */ 99 | 100 | export {setupSimpleDatabase, setupDatabase} 101 | -------------------------------------------------------------------------------- /src/examples/select.js: -------------------------------------------------------------------------------- 1 | import {SELECT} from "../select.js"; 2 | import {table} from "../output.js"; 3 | import {initSQLToy} from "../index.js"; 4 | import {FROM} from "../from.js"; 5 | import {CREATE_TABLE} from "../createTable.js"; 6 | import {INSERT_INTO} from "../insertInto.js"; 7 | import {JOIN} from "../join.js"; 8 | 9 | 10 | initSQLToy(); 11 | 12 | /*****************************************************/ 13 | /* 14 | +-------------+------------+----------+------------------+ 15 | | player_id | type | result | length_minutes | 16 | |-------------+------------+----------+------------------| 17 | | 1 | Chess | Win | 23.5 | 18 | | 1 | Chess | Loss | 26.5 | 19 | | 2 | Checkers | Loss | 6.5 | 20 | | 2 | Dominos | Loss | 9.1 | 21 | | 1 | Battleship | Win | 27.9 | 22 | +-------------+------------+----------+------------------+ 23 | */ 24 | 25 | /* 26 | CREATE_TABLE('games'); 27 | INSERT_INTO('games', [ 28 | {player_id:1,type:'Chess',result:'Win',length_minutes:23.5}, 29 | {player_id:1,type:'Chess',result:'Loss',length_minutes:26.5}, 30 | {player_id:2,type:'Checkers',result:'Loss',length_minutes:6.5}, 31 | {player_id:2,type:'Dominos',result:'Loss',length_minutes:9.1}, 32 | {player_id:1,type:'Battleshipt',result:'Win',length_minutes:27.9}, 33 | ]); 34 | const games = FROM('games'); 35 | const result = SELECT(games, ['type', 'result']); 36 | table(result); 37 | process.exit(); 38 | */ 39 | 40 | /*****************************************************/ 41 | 42 | /* 43 | +------+--------+ 44 | | id | name | 45 | |------+--------| 46 | | 1 | Josh | 47 | | 2 | Ruth | 48 | | 3 | Carl | 49 | +------+--------+ 50 | */ 51 | CREATE_TABLE('games'); 52 | INSERT_INTO('games', [ 53 | {player_id: 1, type: 'Chess', result: 'Win', length_minutes: 23.5}, 54 | {player_id: 1, type: 'Chess', result: 'Loss', length_minutes: 26.5}, 55 | {player_id: 2, type: 'Checkers', result: 'Loss', length_minutes: 6.5}, 56 | {player_id: 2, type: 'Dominos', result: 'Loss', length_minutes: 9.1}, 57 | {player_id: 1, type: 'Battleshipt', result: 'Win', length_minutes: 27.9}, 58 | ]); 59 | CREATE_TABLE('player'); 60 | INSERT_INTO('player', [ 61 | {id: 1, name: 'Josh'}, 62 | {id: 2, name: 'Ruth'}, 63 | {id: 3, name: 'Carl'}, 64 | ]); 65 | const games = FROM('games'); 66 | const player = FROM('player'); 67 | let result = JOIN(games, player, c => c['games.player_id'] === c['player.id']); 68 | result = SELECT(result, ['games.type', 'player.name', 'games.result'], {'games.type': 'Game Type', 'player.name': 'Player Name', 'games.result': 'Win or Loss'}); 69 | table(result); 70 | process.exit(); 71 | 72 | /***************************************************** 73 | 74 | setupDatabase(); 75 | let employee; 76 | let result; 77 | 78 | employee = FROM('employee'); 79 | result = GROUP_BY(employee, ['department_id', 'status']); 80 | result = ARRAY_AGG(result, 'name'); 81 | result = MAX(result, 'salary'); 82 | result = COUNT(result, 'status'); 83 | result = SELECT(result, ['department_id','status','ARRAY_AGG(name)','MAX(salary)','COUNT(status)']); 84 | table(result); 85 | */ 86 | 87 | /* 88 | ┌───────────────┬────────────┬────────────────────────┬─────────────┬───────────────┐ 89 | │ department_id │ status │ ARRAY_AGG(name) │ MAX(salary) │ COUNT(status) │ 90 | ├───────────────┼────────────┼────────────────────────┼─────────────┼───────────────┤ 91 | │ 1 │ inactive │ [ Josh , Ruth ] │ 200000 │ 2 │ 92 | │ 2 │ active │ [ Jane ] │ 160000 │ 1 │ 93 | │ 1 │ active │ [ Elliot ] │ 180000 │ 1 │ 94 | │ │ active │ [ Michael , Garth ] │ 200000 │ 2 │ 95 | └───────────────┴────────────┴────────────────────────┴─────────────┴───────────────┘ 96 | 97 | */ 98 | -------------------------------------------------------------------------------- /src/examples/update.js: -------------------------------------------------------------------------------- 1 | import {table} from "../output.js"; 2 | import {setupDatabase} from "./sampleData.js"; 3 | import {initSQLToy} from "../index.js"; 4 | import {FROM} from "../from.js"; 5 | import {UPDATE} from "../update.js"; 6 | 7 | 8 | initSQLToy(); 9 | setupDatabase(); 10 | let employee; 11 | let result; 12 | 13 | employee = FROM('employee'); 14 | table(employee); 15 | 16 | result = UPDATE(employee, {name: 'JOSH'}, (row) => row.name === 'Josh'); 17 | 18 | table(result); 19 | -------------------------------------------------------------------------------- /src/examples/where.js: -------------------------------------------------------------------------------- 1 | // SELECT * FROM employee JOIN department ON department.id = employee.id WHERE salary > 150000 2 | // First do an inner join on employee and department 3 | import {INNER_JOIN} from "../join.js"; 4 | import {WHERE} from "../where.js"; 5 | import {table} from "../output.js"; 6 | import {setupDatabase} from "./sampleData.js"; 7 | import {initSQLToy} from "../index.js"; 8 | import {FROM} from "../from.js"; 9 | import {CREATE_TABLE} from "../createTable.js"; 10 | import {INSERT_INTO} from "../insertInto.js"; 11 | 12 | initSQLToy(); 13 | setupDatabase(); 14 | let employee; 15 | let department; 16 | let result; 17 | let employee_club; 18 | let club; 19 | 20 | employee = FROM('employee'); 21 | result = WHERE(employee, (c) => c["department_id"] === 1); 22 | table(result); 23 | 24 | employee = FROM('employee'); 25 | department = FROM('department'); 26 | result = INNER_JOIN(employee, department, (c) => c["employee.department_id"] === c["department.id"]); 27 | result = WHERE(result, (row) => { 28 | return row['employee.salary'] > 150000; 29 | }); 30 | table(result); 31 | 32 | /* 33 | ┌─────────────┬───────────────┬─────────────────┬────────────────────────┬─────────────────┬───────────────┬─────────────────┐ 34 | │ employee.id │ employee.name │ employee.salary │ employee.department_id │ employee.status │ department.id │ department.name │ 35 | ├─────────────┼───────────────┼─────────────────┼────────────────────────┼─────────────────┼───────────────┼─────────────────┤ 36 | │ 2 │ Jane │ 160000 │ 2 │ active │ 2 │ Engineering │ 37 | │ 3 │ Ruth │ 200000 │ 1 │ inactive │ 1 │ Sales │ 38 | │ 4 │ Elliot │ 180000 │ 1 │ active │ 1 │ Sales │ 39 | └─────────────┴───────────────┴─────────────────┴────────────────────────┴─────────────────┴───────────────┴─────────────────┘ 40 | */ 41 | 42 | // SELECT * FROM employee 43 | // JOIN employee_club ON employee_club.a = employee.id 44 | // JOIN club ON club.id = employee_club.b 45 | // WHERE salary > 150000 AND club.name = 'Cat Lovers'; 46 | 47 | employee = FROM('employee'); 48 | department = FROM('department'); 49 | employee_club = FROM('employee_club'); 50 | club = FROM('club'); 51 | result = INNER_JOIN(employee, employee_club, (c) => c["employee_club.A"] === c["employee.id"]); 52 | result = INNER_JOIN(result, club, (c) => c["employee_club.B"] === c["club.id"]); 53 | table(result); 54 | result = WHERE(result, (row) => { 55 | return row['employee.salary'] > 150000 && row['club.name'] === 'Cat Lovers'; 56 | }); 57 | table(result); 58 | 59 | /* 60 | ┌─────────────┬───────────────┬─────────────────┬────────────────────────┬─────────────────┬──────────────────────────┬──────────────────────────┬──────────────────┬────────────────────┐ 61 | │ employee.id │ employee.name │ employee.salary │ employee.department_id │ employee.status │ employee_club.A │ employee_club.B │ club.id │ club.name │ 62 | ├─────────────┼───────────────┼─────────────────┼────────────────────────┼─────────────────┼──────────────────────────┼──────────────────────────┼──────────────────┼────────────────────┤ 63 | │ 2 │ Jane │ 160000 │ 2 │ active │ 2 │ 1 │ 1 │ Cat Lovers │ 64 | │ 4 │ Elliot │ 180000 │ 1 │ active │ 4 │ 1 │ 1 │ Cat Lovers │ 65 | └─────────────┴───────────────┴─────────────────┴────────────────────────┴─────────────────┴──────────────────────────┴──────────────────────────┴──────────────────┴────────────────────┘ 66 | */ 67 | 68 | CREATE_TABLE('test1'); 69 | INSERT_INTO('test1', {id: 1, name: 'Josh', test_2_id: 1}); 70 | CREATE_TABLE('test2'); 71 | INSERT_INTO('test2', {id: 1, name: 'Engineering', test_3_id: 1}); 72 | CREATE_TABLE('test3'); 73 | INSERT_INTO('test3', {id: 1, name: 'First Floor', test_3_id: 1}); 74 | debugger; 75 | let test1 = FROM('test1'); 76 | let test2 = FROM('test2'); 77 | let test3 = FROM('test3'); 78 | result = INNER_JOIN(test1, test2, (c) => c["test1.test_2_id"] === c["test2.id"]); 79 | table(result); 80 | result = INNER_JOIN(result, test3, (c) => c["test2.test_3_id"] === c["test3.id"]); 81 | table(result); 82 | -------------------------------------------------------------------------------- /src/from.js: -------------------------------------------------------------------------------- 1 | import { database } from './index.js'; 2 | import {CROSS_JOIN} from "./join.js"; 3 | 4 | function FROM(tableNames) { 5 | // just a tablename 6 | if (!Array.isArray(tableNames)) { 7 | return database.tables[tableNames]; 8 | } 9 | // array of tablenames 10 | if (tableNames.length === 1) { 11 | return database.tables[tableNames[0]]; 12 | } 13 | // recursively cross join on multiple tables 14 | return CROSS_JOIN(database.tables[tableNames[0]], FROM(tableNames.slice(1))); 15 | } 16 | 17 | export { FROM } 18 | -------------------------------------------------------------------------------- /src/groupBy.js: -------------------------------------------------------------------------------- 1 | /** 2 | * GROUP_BY returns a new table with 1 row for each distinct set of values from the groupBys columns. 3 | * On those rows it also creates a _groupRows property which holds an array of copies of the rows 4 | * which were grouped from the original table. This property is then used in the aggregate functions. 5 | */ 6 | import {US} from "./util.js"; 7 | 8 | const GROUP_BY = (table, groupBys) => { 9 | const groupRows = {}; // hash of composite key to array of rows which are in the group 10 | for (const row of table.rows) { 11 | let key = groupBys.map(groupBy => row[groupBy]).join(US); // make composite key 12 | if (!groupRows[key]) { 13 | groupRows[key] = []; 14 | } 15 | groupRows[key].push({...row}); // push a copy 16 | } 17 | 18 | const resultRows = []; 19 | for (const key in groupRows) { 20 | const resultRow = { 21 | _groupRows: groupRows[key] 22 | }; 23 | for (const column of groupBys) { 24 | resultRow[column] = groupRows[key][0][column]; // take the grouped value from the first entry in keyrows 25 | } 26 | resultRows.push(resultRow); 27 | } 28 | 29 | return { 30 | name: table.name, 31 | rows: resultRows 32 | } 33 | } 34 | 35 | export {GROUP_BY} 36 | -------------------------------------------------------------------------------- /src/having.js: -------------------------------------------------------------------------------- 1 | /** 2 | * HAVING 3 | */ 4 | 5 | // Having takes a column and a predicate - this is just like where but should be run after group by 6 | const HAVING = (table, pred) => { 7 | return { 8 | name: table.name, 9 | rows: table.rows.filter(pred) 10 | } 11 | } 12 | 13 | export { HAVING } 14 | -------------------------------------------------------------------------------- /src/index.js: -------------------------------------------------------------------------------- 1 | /** 2 | * SQLToy 3 | */ 4 | 5 | let database = {} 6 | 7 | function initSQLToy() { 8 | database = { 9 | tables: {} 10 | } 11 | 12 | } 13 | 14 | export { initSQLToy, database } 15 | -------------------------------------------------------------------------------- /src/insertInto.js: -------------------------------------------------------------------------------- 1 | import { database } from './index.js'; 2 | 3 | function INSERT_INTO(tableName, r) { 4 | let rows; 5 | if (Array.isArray(r)) { 6 | rows = r; 7 | } else { 8 | rows = [r]; 9 | } 10 | const table = database.tables[tableName]; 11 | table.rows = [...table.rows, ...rows]; 12 | } 13 | 14 | export { INSERT_INTO } 15 | -------------------------------------------------------------------------------- /src/join.js: -------------------------------------------------------------------------------- 1 | // cross takes two tables and returns a table which includes a cross join of all rows 2 | const CROSS_JOIN = (a, b) => { 3 | const result = { 4 | name: '', 5 | rows: [] 6 | } 7 | for (const x of a.rows) { // loop over rows in table a 8 | for (const y of b.rows) { // loop over rows in table b 9 | const row = {}; 10 | 11 | // for each column in a, create a column in the ouput 12 | for (const k in x) { 13 | const columnName = a.name ? `${a.name}.${k}` : k; 14 | row[columnName] = x[k]; 15 | } 16 | 17 | // for each column in b, create a column in the ouput 18 | for (const k in y) { 19 | const columnName = b.name ? `${b.name}.${k}` : k; 20 | row[columnName] = y[k]; 21 | } 22 | 23 | // Store an array of the two rows used to make up this new row. 24 | // This is used in LEFT_JOIN and RIGHT_JOIN. 25 | row._tableRows = [x, y]; 26 | 27 | result.rows.push(row); 28 | } 29 | } 30 | return result; 31 | }; 32 | 33 | /** 34 | * innerJoin takes two tables and a predicate. Result will be a table which includes the cross join of all rows which satisfy the predicate. 35 | * todo: support aliases where we can pass in a value to use for columnName (in the cross join) 36 | */ 37 | const INNER_JOIN = (a, b, pred) => { 38 | return { 39 | name: '', 40 | rows: CROSS_JOIN(a, b).rows.filter(pred), 41 | } 42 | }; 43 | 44 | /** 45 | * leftJoin takes two tables and a predicate. Result will be a table which includes all rows from the cross join which satisfy the predicate or in the case where no rows in b match for a row in a, a row with the values for b set to null. 46 | */ 47 | const LEFT_JOIN = (a, b, pred) => { 48 | // Start by taking the cross join of a,b and creating a result table. 49 | const cp = CROSS_JOIN(a, b); 50 | let result = { 51 | name: '', 52 | rows: [], 53 | } 54 | 55 | // for each row in a either return matching rows from the cross product 56 | // or a row with nulls for b if there are no matches 57 | for (let aRow of a.rows) { 58 | // find all rows in cross product which come from this row in table a using the _tableRows array 59 | const cpa = cp.rows.filter((cpr) => cpr._tableRows.includes(aRow)); 60 | 61 | // apply the filter 62 | const match = cpa.filter(pred); 63 | 64 | if (match.length) { 65 | // we found at least one match so add to result rows 66 | result.rows.push(...match); 67 | } else { 68 | // we did not find a match so create a row with values from a and nulls for b 69 | 70 | let aValues = {}; 71 | let bValues = {}; 72 | 73 | // values from a 74 | for (const key in aRow) { 75 | aValues[`${a.name}.${key}`] = aRow[key]; 76 | } 77 | 78 | // nulls for b 79 | for (const key in b.rows[0]) { 80 | bValues[`${b.name}.${key}`] = null; 81 | } 82 | 83 | result.rows.push({...aValues, ...bValues}); 84 | } 85 | } 86 | 87 | return result; 88 | }; 89 | 90 | /** 91 | * rightJoin takes two tables and a predicate. Result will be a table which includes the cross join of all rows which satisfy the predicate and which has no nulls in table b. 92 | */ 93 | const RIGHT_JOIN = (a, b, pred) => { 94 | return LEFT_JOIN(b, a, pred); 95 | }; 96 | 97 | export { INNER_JOIN as JOIN, CROSS_JOIN, INNER_JOIN, LEFT_JOIN, RIGHT_JOIN } 98 | -------------------------------------------------------------------------------- /src/limit.js: -------------------------------------------------------------------------------- 1 | /** 2 | * LIMIT 3 | */ 4 | 5 | // LIMIT returns the number of rows specified 6 | 7 | const LIMIT = (table, limit) => { 8 | return { 9 | name: table.name, 10 | rows: table.rows.slice(0, limit), 11 | } 12 | } 13 | 14 | export { LIMIT } 15 | -------------------------------------------------------------------------------- /src/offset.js: -------------------------------------------------------------------------------- 1 | /** 2 | * OFFSET 3 | */ 4 | 5 | // OFFSET skips the number of rows before returning results 6 | 7 | const OFFSET = (table, offset) => { 8 | return { 9 | name: table.name, 10 | rows: table.rows.slice(offset), 11 | } 12 | } 13 | 14 | export { OFFSET } 15 | -------------------------------------------------------------------------------- /src/orderBy.js: -------------------------------------------------------------------------------- 1 | /** 2 | * ORDER_BY 3 | */ 4 | 5 | // ORDER_BY sorts the given table using the provided relation function 6 | // the relation function takes two rows and returns -1 if row A comes first or 1 if row B comes first 7 | 8 | const ORDER_BY = (table, rel) => { 9 | return { 10 | name: table.name, 11 | rows: table.rows.sort(rel), 12 | } 13 | } 14 | 15 | export { ORDER_BY } 16 | -------------------------------------------------------------------------------- /src/output.js: -------------------------------------------------------------------------------- 1 | import {Console} from 'console' 2 | import {Transform} from 'stream' 3 | 4 | // CSV output 5 | const csv = (a) => { 6 | a.rows.forEach((i) => delete i["_tableRows"]); 7 | a.rows.forEach((i) => delete i["_groupedValues"]); 8 | console.log(Object.keys(a.rows[0]).join(',')); 9 | for (let i of a.rows) { 10 | const outputValues = []; 11 | for (let value of Object.values(i)) { 12 | if (value === '') { 13 | outputValues.push(''); 14 | } else if (Array.isArray(value)) { 15 | outputValues.push(`"[${value.join(',')}]"`) 16 | } else { 17 | outputValues.push(value); 18 | } 19 | } 20 | console.log(outputValues.join(',')); 21 | } 22 | }; 23 | 24 | // Table output 25 | // The console.table table has an extra "(index)" column which is very confusing in this context 26 | // so we remove it. 27 | 28 | const ts = new Transform({ 29 | transform(chunk, enc, cb) { 30 | cb(null, chunk) 31 | } 32 | }) 33 | const logger = new Console({stdout: ts}) 34 | 35 | // @see https://stackoverflow.com/a/67859384 36 | function getTable(data) { 37 | logger.table(data) 38 | return (ts.read() || '').toString() 39 | } 40 | 41 | const table = (t) => { 42 | let outRows; 43 | outRows = []; 44 | // make a copy of t without _ columns 45 | for (const r of t.rows) { 46 | const newRow = {}; 47 | for (const k in r) { 48 | if (k[0] !== '_') { 49 | newRow[k] = r[k]; 50 | } 51 | } 52 | outRows.push(newRow); 53 | } 54 | 55 | let table = getTable(outRows); 56 | let result = ''; 57 | for (let row of table.split(/[\r\n]+/)) { 58 | let r = row.replace(/[^┬]*┬/, '┌'); 59 | r = r.replace(/^├─*┼/, '├'); 60 | r = r.replace(/│[^│]*/, ''); 61 | r = r.replace(/^└─*┴/, '└'); 62 | r = r.replace(/'/g, ' '); 63 | result += `${r}\n`; 64 | } 65 | console.log(result); 66 | } 67 | 68 | export {csv, table} 69 | -------------------------------------------------------------------------------- /src/select.js: -------------------------------------------------------------------------------- 1 | /** 2 | * select 3 | */ 4 | 5 | // select just picks columns from the provided table and optionally renames the columns 6 | // aliases are a map of {column:alias} 7 | const SELECT = (table, columns, aliases = {}) => { 8 | const newrows = []; 9 | 10 | const colnames = {}; 11 | 12 | for (const col of columns) { 13 | colnames[col] = aliases[col] ? aliases[col] : col; 14 | } 15 | 16 | for (const row of table.rows) { 17 | const newrow = {}; 18 | for (let column of columns) { 19 | newrow[colnames[column]] = row[column]; 20 | } 21 | newrows.push(newrow); 22 | } 23 | 24 | return { 25 | name: table.name, 26 | rows: newrows, 27 | }; 28 | } 29 | 30 | 31 | export { SELECT } 32 | -------------------------------------------------------------------------------- /src/update.js: -------------------------------------------------------------------------------- 1 | /** 2 | * UPDATE 3 | */ 4 | 5 | // set is an object with key/values to set 6 | function UPDATE(table, set, pred) { 7 | return { 8 | name: table.name, 9 | rows: table.rows.map(row => { 10 | if (pred(row)) { 11 | const newRow = {...row}; 12 | for (const key of Object.keys(set)) { 13 | newRow[key] = set[key]; 14 | } 15 | return newRow; 16 | } else { 17 | return row; 18 | } 19 | }) 20 | } 21 | } 22 | 23 | export { UPDATE } 24 | -------------------------------------------------------------------------------- /src/util.js: -------------------------------------------------------------------------------- 1 | const US = String.fromCharCode(0x1f); // unitSeparator 2 | 3 | export { US } 4 | -------------------------------------------------------------------------------- /src/where.js: -------------------------------------------------------------------------------- 1 | // WHERE - where is run after a FROM/JOIN to reduce the output set 2 | 3 | /** 4 | * WHERE takes a table and a predicate and reduces rows to the ones which match the predicate 5 | */ 6 | 7 | const WHERE = (table, pred) => { 8 | return { 9 | name: table.name, 10 | rows: table.rows.filter(pred) 11 | }; 12 | } 13 | 14 | export { WHERE } 15 | -------------------------------------------------------------------------------- /yarn-error.log: -------------------------------------------------------------------------------- 1 | Arguments: 2 | /Users/josh/.nodenv/versions/14.9.0/bin/node /usr/local/Cellar/yarn/1.22.15/libexec/bin/yarn.js init 3 | 4 | PATH: 5 | /Users/josh/.nodenv/versions/14.9.0/bin:/usr/local/Cellar/nodenv/1.4.0/libexec:/usr/local/go/bin:/Users/josh/opt/anaconda3/bin:/Users/josh/opt/anaconda3/condabin:/Users/josh/.opam/default/bin:/Users/josh/.nodenv/shims:/Users/josh/.nvm/versions/node/v12.18.2/bin:/Users/josh/.yarn/bin:/Users/josh/.cabal/bin:/Users/josh/.ghcup/bin:/Users/josh/.ebcli-virtual-env/executables:/Users/josh/go/bin:~/bin:/usr/local/bin:/usr/bin:/bin:/usr/sbin:/sbin:/opt/local/bin:/opt/local/sbin:/Applications/LibreOffice.app/Contents/MacOS:/usr/local/nvim-osx64/bin:/Users/josh/optio-neo4j/bin:/Users/josh/bin:/Users/josh/.local/bin:/usr/local/share/dotnet:/Library/Frameworks/Mono.framework/Versions/Current/bin:/usr/local/bin:/usr/bin:/bin:/usr/sbin:/sbin:/Users/josh/go/bin 6 | 7 | Yarn version: 8 | 1.22.15 9 | 10 | Node version: 11 | 14.9.0 12 | 13 | Platform: 14 | darwin x64 15 | 16 | Trace: 17 | Error: canceled 18 | at Interface. (/usr/local/Cellar/yarn/1.22.15/libexec/lib/cli.js:137145:13) 19 | at Interface.emit (events.js:314:20) 20 | at Interface._ttyWrite (readline.js:875:16) 21 | at ReadStream.onkeypress (readline.js:213:10) 22 | at ReadStream.emit (events.js:314:20) 23 | at emitKeys (internal/readline/utils.js:335:14) 24 | at emitKeys.next () 25 | at ReadStream.onData (readline.js:1144:36) 26 | at ReadStream.emit (events.js:314:20) 27 | at addChunk (_stream_readable.js:303:12) 28 | 29 | npm manifest: 30 | No manifest 31 | 32 | yarn manifest: 33 | No manifest 34 | 35 | Lockfile: 36 | No lockfile 37 | --------------------------------------------------------------------------------