@demmings/gssql
Version:
Google Sheets QUERY function replacement using real SQL select syntax.
1,260 lines (1,056 loc) • 227 kB
JavaScript
/* *** DEBUG START ***
// Remove comments for testing in NODE
import { Sql, GasSql, gsSQL } from './Sql.js';
import { Table } from './Table.js';
import { TableData } from './TableData.js';
import { Logger, Utilities } from '../GasMocks.js';
import { Select2Object } from './Select2Object.js';
import { SelectTables } from './Views.js';
export { Range };
export { SqlTester };
export { TestSql };
export { SpreadsheetApp };
// GAS Mock Ups.
class SpreadsheetApp {
static getActiveSpreadsheet() {
return new SpreadsheetApp();
}
getRangeByName(tableNamedRange) {
const dataRange = new Range(tableNamedRange);
return dataRange.getMockData() === null ? null : dataRange;
}
getSheetByName(sheetTabName) {
let sheetObj = new Sheet(sheetTabName);
if (sheetObj.getSheetValues(1, 1, 1, 1) === null)
return null;
return sheetObj;
}
static getUi() {
return new Ui();
}
}
class Ui {
createMenu(name) {
return this;
}
addItem(dest, func) {
return this;
}
addToUi() {
return this;
}
}
class Sheet {
constructor(sheetName) {
this.sheetName = sheetName;
}
getLastColumn() {
let data = this.getSheetValues(-1, -1, -1, -1);
if (data !== null && data.length > 0)
return data[0].length;
return -1
}
getLastRow() {
let data = this.getSheetValues(-1, -1, -1, -1);
if (data !== null && data.length > 0)
return data.length;
return -1;
}
getSheetValues(startRow, startCol, lastRow, lastColumn) {
let tester = new SqlTester();
switch (this.sheetName.toUpperCase()) {
case "MASTER TRANSACTIONS":
return tester.masterTransactionsTable();
default:
return null;
}
}
getRange(row, col, numRows, numCols) {
return new Range();
}
}
class Range {
constructor(tableNameRange = "") {
this.tableNameRange = tableNameRange;
}
getValues() {
return this.getMockData();
}
getValue() {
return this.getMockData()
}
clearContent() {
return this;
}
clearFormat() {
return this;
}
clear() {
return this;
}
setValues(values) {
return this;
}
setFontWeight(font) {
return this;
}
setFormula(formula) {
return this;
}
setBackground(background) {
return this;
}
setFormulas(formulas) {
return this;
}
// Set data to be returned for any named range tested.
getMockData() {
let tester = new SqlTester();
switch (this.tableNameRange.toUpperCase()) {
case 'STARTINCOMEDATE':
return '6/7/2019';
case 'ENDINCOMEDATE':
return '6/20/2019';
case "MASTER_TRANSACTIONS":
case "MASTER TRANSACTIONS!$A$1:$I":
case "MASTER TRANSACTIONS!$A$1:$I30":
return tester.masterTransactionsTable();
case 'ACCOUNTNAMESDATA':
return tester.bookTable();
default:
return null;
}
}
}
// *** DEBUG END ***/
/**
* Runs all tests and reports back the result of the tests.
* @customfunction
*/
function SQLselfTest() {
const success = testerSql() ? "Success" : "Failed";
return [[success]];
}
function SqlLiveDataTest() {
let tester = new SqlTester();
tester.liveTest1();
tester.liveTest2();
}
/**
* Function should be commented out when NOT running in a TEST SHEET.
* It will create a menu option that allows you to create a gsSQL()
* statement for every test SQL in TestSQL().
*/
function onOpen() {
if (SpreadsheetApp.getActiveSpreadsheet().getSheetByName("gsSqlTest") === null) {
// Only create menu option on test sheet.
return true;
}
// This line calls the SpreadsheetApp and gets its UI
// Or DocumentApp or FormApp.
const ui = SpreadsheetApp.getUi();
//These lines create the menu items and
// tie them to functions we will write in Apps Script
ui.createMenu('gsSQL Options')
.addItem('Generate Tests on TDD SHEET !!!', 'customMenuGenerateTests')
.addToUi();
}
/**
* @type {TestedStatements[]}
*/
let sqlTestCases = [];
/**
* Expected to be run as a menu item.
* Runs all internal tests, collects the SQL from each test and generates
* a =gsSQL() string and writes it to the current active screen.
* Each customfunction is written in column A, starting two rows below the
* last row in the current sheet. Room is left after the expected results
* and the subsequent gsSQL() will be updated 3 rows after.
*/
function customMenuGenerateTests() {
sqlTestCases = []; // Reset collected test case array.
testerSql();
TestSql.generateTestCustomFunctions();
}
/**
* Needed by Google Sheets Testing app.
* @param {String} functionName
* @param {any[][]} array1
* @param {any[][]} array2
* @returns {String[][]}
* @customfunction
*/
function isEqual(functionName, array1, array2) {
const test = new SqlTester();
const status = test.isEqual(functionName, array1, array2) ? "Equal" : "Not Equal";
const results = [];
results.push([functionName]);
results.push([status]);
return results;
}
class TestedStatements {
/**
*
* @param {String} statement
* @param {any[]} bindVariables
* @param {any[][]} data
* @param {Map<String,Table>} tables
* @param {Boolean} generateColumnTitles
*/
constructor(statement, bindVariables, data, tables, generateColumnTitles) {
this.statement = statement;
this.bindVariables = bindVariables;
this.expectedOutputlines = data.length;
this.data = data;
this.tables = tables;
this.generateColumnTitles = generateColumnTitles;
this.generateTableDefinition = false;
// @ts-ignore
for (let tableInfo of this.tables.values()) {
if (!tableInfo.hasColumnTitle)
this.generateTableDefinition = true;
}
}
/**
*
* @returns {String}
*/
getTableDefinitionString() {
let definition = "{";
let tabDef = "";
// @ts-ignore
for (let table of this.tables.values()) {
let rangeName = table.tableName;
if (table.tableData.length > 0) {
rangeName += "!A2:" + Table.numberToSheetColumnLetter(table.tableData[0].length)
}
if (tabDef !== "") {
tabDef += ";";
}
tabDef += "{";
tabDef += '"' + table.tableName + '",';
tabDef += '"' + rangeName + '",';
tabDef += "60, " + table.hasColumnTitle.toString();
tabDef += "}";
}
definition += tabDef + "}";
return definition;
}
}
class TestSql extends Sql {
constructor() {
super();
}
/**
*
* @param {String} stmt
* @returns {any[][]}
*/
execute(stmt) {
let bindings = [...super.getBindData()];
let tables = super.getTables();
let generateColumnTitles = super.areColumnTitlesOutput();
const data = super.execute(stmt);
let test = new TestedStatements(stmt, bindings, data, tables, generateColumnTitles);
sqlTestCases.push(test);
return data;
}
static generateTestCustomFunctions() {
let sheet = SpreadsheetApp.getActiveSpreadsheet().getSheetByName("TDD");
if (sheet === null) {
Logger.log("Invalid SHEET. 'TDD' not found.");
return;
}
const SUMMARY_ITEMS_PER_ROW = 10;
const SHEET_HEADER_ROWS = 6;
// Clear out old tests.
sheet.getRange(SHEET_HEADER_ROWS, 1, sheet.getLastRow(), sheet.getLastColumn()).clearContent().clearFormat().clear();
const rowsForSummary = Math.ceil(sqlTestCases.length / SUMMARY_ITEMS_PER_ROW) * 3;
const summaryTestResults = [];
let summaryTestResultRow = [];
let blankRow = [];
let testCount = 1;
let lastRow = sheet.getLastRow() + 3 + rowsForSummary;
for (const testCase of sqlTestCases) {
let descriptionRange = sheet.getRange(lastRow - 1, 1, 1, 2);
let testNumber = "Test #" + testCount;
let descriptionRow = [[testNumber, testCase.statement]];
descriptionRange.setValues(descriptionRow);
descriptionRange.setFontWeight("bold");
let formula = TestSql.makeCustomFormulaString(testCase);
let formulaRange = sheet.getRange(lastRow, 1);
formulaRange.setFormula(formula);
// Write out expected results.
if (testCase.data.length > 0) {
let expectedRange = sheet.getRange(lastRow, 3 + testCase.data[0].length, testCase.data.length, testCase.data[0].length);
// expectedRange.setNumberFormat("@");
expectedRange.setValues(testCase.data);
expectedRange.setFontWeight("bold").setBackground("yellow");
let resultsRange = sheet.getRange(lastRow, 1, testCase.data.length, testCase.data[0].length);
resultsRange.setBackground("cyan");
let resultFormula = TestSql.makeTestResultFormulaString(testCount, resultsRange, expectedRange);
summaryTestResultRow.push(resultFormula);
blankRow.push("");
if (summaryTestResultRow.length >= SUMMARY_ITEMS_PER_ROW) {
summaryTestResults.push(summaryTestResultRow);
summaryTestResults.push(blankRow);
summaryTestResults.push(blankRow);
summaryTestResultRow = [];
blankRow = [];
}
}
lastRow = lastRow + testCase.expectedOutputlines + 3;
testCount++;
}
if (summaryTestResultRow.length > 0) {
while (summaryTestResultRow.length < SUMMARY_ITEMS_PER_ROW) {
summaryTestResultRow.push("");
}
summaryTestResults.push(summaryTestResultRow);
}
if (summaryTestResults.length > 0) {
Logger.log(`Items=${summaryTestResults.length}. Cols=${summaryTestResults[0].length}`);
let summaryRange = sheet.getRange(SHEET_HEADER_ROWS, 1, summaryTestResults.length, summaryTestResults[0].length);
summaryRange.setFormulas(summaryTestResults);
}
}
/**
*
* @param {TestedStatements} testCase
* @returns {String}
*/
static makeCustomFormulaString(testCase) {
let tableDefinitionString = "";
if (testCase.generateTableDefinition) {
tableDefinitionString = testCase.getTableDefinitionString();
}
let formula = '=gsSQL("' + testCase.statement + '"';
if (testCase.bindVariables.length > 0 || !testCase.generateColumnTitles) {
formula += "," + tableDefinitionString + ", " + testCase.generateColumnTitles.toString();
for (const bindData of testCase.bindVariables) {
formula += ", ";
if (typeof bindData === 'string') {
formula += '"' + bindData + '"';
}
else if (bindData instanceof Date) {
formula += '"' + Utilities.formatDate(bindData, "GMT+1", "MM/dd/yyyy") + '"';
}
else {
formula += bindData;
}
}
}
else if (tableDefinitionString !== "") {
formula += "," + tableDefinitionString + ", true";
}
formula += ')';
return formula;
}
static makeTestResultFormulaString(testNumber, rangeResults, rangeExpected) {
let formula = '=isEqual("Test #' + testNumber.toString() + '"';
formula += "," + rangeResults.getA1Notation();
formula += "," + rangeExpected.getA1Notation();
formula += ")";
return formula;
}
}
class SqlTester {
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/books.csv'
INTO TABLE books
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE books (id CHAR(6), title VARCHAR(200),
type VARCHAR(20), author_id CHAR(6), editor_id CHAR(6), translator_id CHAR(6));
*/
bookTable(extraRecords = 0) {
let recs = [
["id", "title", "type", "author id", "editor id", "translator id"],
["1", "Time to Grow Up!", "original", "11", "21", ""],
["2", "Your Trip", "translated", "15", "22", "32"],
["3", "Lovely Love", "original", "14", "24", ""],
["4", "Dream Your Life", "original", "11", "24", ""],
["5", "Oranges", "translated", "12", "25", "31"],
["6", "Your Happy Life", "translated", "15", "22", "33"],
["7", "Applied AI", "translated", "13", "23", "34"],
["9", "Book with Mysterious Author", "translated", "1", "23", "34"],
["8", "My Last Book", "original", "11", "28", ""]
];
for (let i = 0; i < extraRecords; i++) {
let newRecord = [];
newRecord.push((10 + i).toString());
newRecord.push("Great Boook volume " + (1 + i).toString());
newRecord.push(i % 2 === 0 ? "original" : "translated");
newRecord.push((11 + i).toString());
newRecord.push((12 + i).toString());
newRecord.push((13 + i).toString());
recs.push(newRecord);
}
return recs;
}
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/booksales.csv'
INTO TABLE booksales
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE booksales (invoice CHAR(6), book_id CHAR(6),
customer_id CHAR(6), quantity integer, price double, date date);
*/
bookSalesTable(extraRecords = 0) {
let recs = [
["Invoice", "Book Id", "Customer ID", "Quantity", "Price", "Date"],
["I7200", "9", "C1", 10, 34.95, "05/01/2022"],
["I7201", "8", "C2", 3, 29.95, "05/01/2022"],
["I7201", "7", "C2", 5, 18.99, "05/01/2022"],
["I7202", "9", "C3", 1, 59.99, "05/02/2022"],
["I7203", "1", "", 1, 90, "05/02/2022"],
["I7204", "2", "C4", 100, 65.49, "05/03/2022"],
["I7204", "3", "C4", 150, 24.95, "05/03/2022"],
["I7204", "4", "C4", 50, 19.99, "05/03/2022"],
["I7205", "7", "C1", 1, 33.97, "05/04/2022"],
["I7206", "7", "C2", 100, 17.99, "05/04/2022"]
];
for (let i = 0; i < extraRecords; i++) {
let newRecord = [];
newRecord.push("I" + (707 + i).toString());
newRecord.push((10 + i).toString());
newRecord.push("C" + (5 + i).toString());
newRecord.push(i % 100);
newRecord.push(i % 100 + 1 / (i % 99 === 0 ? 99 : i % 99));
newRecord.push((1 + i % 12).toString() + "/" + (i % 28).toString() + "/" + (2022 + i % 50).toString());
recs.push(newRecord);
}
return recs;
}
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/bookreturns.csv'
INTO TABLE bookreturns
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE bookreturns (rma CHAR(7), book_id CHAR(6),
customer_id CHAR(6), quantity integer, price double, date date);
*/
bookReturnsTable() {
return [
["RMA", "Book Id", "Customer ID", "Quantity", "Price", "Date"],
["Rma001", "9", "c1", 10, 34.95, "05/01/2022"],
["rma020", "8", "c2", 3, 29.95, "05/01/2022"],
["rmA030", "7", "c2", 5, 18.99, "05/01/2022"],
["RMA040", "9", "c3", 1, 59.99, "05/02/2022"],
["rma005", "1", "c1", 1, 90, "05/02/2022"],
["RMA600", "2", "c4", 100, 65.49, "05/03/2022"],
["Rma701", "3", "c4", 150, 24.95, "05/03/2022"],
["RmA800", "4", "c4", 50, 19.99, "05/03/2022"],
["RMA900", "7", "c1", 1, 33.97, "05/04/2022"],
["rma1010", "7", "c2", 100, 17.99, "05/04/2022"]
];
}
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/customers.csv'
INTO TABLE customers
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE customers (id CHAR(6), name VARCHAR(100),
address VARCHAR(200), city VARCHAR(50), phone CHAR(20), email VARCHAR(200));
*/
customerTable() {
return [
["ID", "Name", "Address", "City", "Phone", "eMail"],
["C1", "Numereo Uno", "101 One Way", "One Point City", "9051112111", "bigOne@gmail.com"],
["C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com"],
["C3", "Tres Buon Goods", "3 Way St", "Tres City", "5193133303", "thrice@hotmail.com"],
["C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com"],
["C5", "Fe Fi Fo Giant Tiger", "5 ohFive St.", "FifthDom", "4165551234", " fiver@gmail.com"],
["C6", "Sx in Cars", "6 Seventh St", "Sx City", "6661116666", "gotyourSix@hotmail.com "],
["C7", "7th Heaven", "7 Eight Crt.", "Lucky City", "5551117777", " timesAcharm@gmail.com "]
];
}
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/authors.csv'
INTO TABLE authors
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE authors (id CHAR(6), first_name VARCHAR(100),
last_name VARCHAR(200));
*/
authorsTable() {
return [
["id", "first_name", "last_name"],
["11", "Ellen", "Writer"],
["12", "Olga", "Savelieva"],
["13", "Jack", "Smart"],
["14", "Donald", "Brain"],
["15", "Yao", "Dou"]
];
}
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/editors.csv'
INTO TABLE editors
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE editors (id CHAR(6), first_name VARCHAR(100),
last_name VARCHAR(200));
*/
editorsTable() {
return [
["id", "first name", "last name"],
["13", "Jack", "Smart"],
["21", "Daniel", "Brown"],
["22", "Mark", "Johnson"],
["23", "Maria", "Evans"],
["24", "Cathrine", "Roberts"],
["25", "Sebastian", "Wright"],
["26", "Barbara", "Jones"],
["27", "Matthew", "Smith"],
["50", "Jack", "Dumb"],
["51", "Daniel", "Smart"]
];
}
/*
LOAD DATA INFILE '/home/cdemmings/Projects/Sheets/CanadianRetirementPlanner/SQL/csv/translators.csv'
INTO TABLE translators
FIELDS
TERMINATED BY ', '
ENCLOSED BY '\"'
ESCAPED BY ''
LINES TERMINATED BY '\n'
IGNORE 1 ROWS;
*/
/* CREATE TABLE translators (id CHAR(6), first_name VARCHAR(100),
last_name VARCHAR(200));
*/
translatorsTable() {
return [
["id", "first_name", "last_name"],
["31", "Ira", "Davies"],
["32", "Ling", "Weng"],
["33", "Kristian", "Green"],
["34", "Roman", "Edwards"]
];
}
masterTransactionsTable() {
return [
["Name of Institution", "Transaction Date", "Description 1", "Description 2", "Amount", "Expense Category", "Account", "Gross", "Balance"],
["Royal Bank of Canada", new Date("6/7/2019"), "Interac purchase - 3707 NADIM'S NO FRIL", "", -47.85, "Food & Dining - Groceries", "", "", ""],
["Royal Bank of Canada", new Date("6/7/2019"), "Interac purchase - 2357 FRESHCO 3826", "", -130.36, "Food & Dining - Groceries", "", "", ""],
["Royal Bank of Canada", new Date("6/7/2019"), "Payroll Deposit WEST UNIFIED CO", "", 2343.48, "Income - Paycheck", "", "", ""],
["Royal Bank of Canada", new Date("6/7/2019"), "MBNA-MASTERCARD", "", -500, "Transfer - CC", "", "", ""],
["Royal Bank of Canada", new Date("6/7/2019"), "e-Transfer sent S.E", "", -575, "Utilities - Rent", "", "", ""],
["Royal Bank of Canada", new Date("6/11/2019"), "Insurance ADMIN.BY GWL", "", 122.4, "Health & Fitness - Health Insurance", "", "", ""],
["Royal Bank of Canada", new Date("6/13/2019"), "Misc Payment GOODLIFE CLUBS", "", -24.85, "Health & Fitness - Gym", "", "", ""],
["Royal Bank of Canada", new Date("6/13/2019"), "WHITBY TAXES", "", -100, "Taxes - Property Tax", "", "", ""],
["Royal Bank of Canada", new Date("6/13/2019"), "Online Transfer to Deposit Account-***9", "", -15, "Transfer - Savings acct", "", "", ""],
["Royal Bank of Canada", new Date("6/14/2019"), "Interac purchase - 8727 NADIM'S NO FRIL", "", -86.73, "Food & Dining - Groceries", "", "", ""],
["Royal Bank of Canada", new Date("6/14/2019"), "Insurance ADMIN.BY GWL", "", 300, "Health & Fitness - Dentist", "", "", ""],
["Royal Bank of Canada", new Date("6/17/2019"), "Interac purchase - 0238 BAMIYAN KABOB", "", -12.98, "Food & Dining - Restaurants", "", "", ""],
["Royal Bank of Canada", new Date("6/17/2019"), "Interac purchase - 1236 NADIM'S NO FRIL", "", -33.32, "Food & Dining - Groceries", "", "", ""],
["Royal Bank of Canada", new Date("6/17/2019"), "Deposit ONLINE TRANSFER", "", 12000, "Transfer - Savings acct", "", "", ""],
["Royal Bank of Canada", new Date("6/18/2019"), "MBNA-MASTERCARD", "", -1100, "Transfer - CC", "", "", ""],
["MBNA Mastercard", new Date("6/19/2019"), "PAYMENT", "", 1100, "Transfer - Savings acct", "", "", ""],
["Royal Bank of Canada", new Date("6/19/2019"), "Utility Bill Pmt Enbridge Gas", "", -108, "Utilities - Heating (Gas)", "", "", ""],
["MBNA Mastercard", new Date("6/20/2019"), "JOE'S NO FRILLS 3141 WHITBY ON", "", -41.77, "Food & Dining - Groceries", "", "", ""],
["MBNA Mastercard", new Date("6/20/2019"), "PIONEER STN#200 WHITBY ON", "", -28.17, "Auto - Fuel", "", "", ""],
["MBNA Mastercard", new Date("6/20/2019"), "AVIVA GENERAL INSURANC MARKHAM ON", "", -137.93, "Utilities - Insurance", "", "", ""],
["MBNA Mastercard", new Date("6/20/2019"), "AVIVA GENERAL INSURANC MARKHAM ON", "", -307.73, "Auto - Insurance", "", "", ""],
["Royal Bank of Canada", new Date("6/20/2019"), "Misc Payment Archdiocese TO", "", -22, "Gifts & Donations - Donations", "", "", ""],
["Royal Bank of Canada", new Date("6/20/2019"), "ELEXICON-WHITBY", "", -95, "Utilities - Electricity", "", "", ""],
["Royal Bank of Canada", new Date("6/20/2019"), "WHITBY TAXES", "", -100, "Taxes - Property Tax", "", "", ""]
];
}
yearlySalesTable() {
return [
["Name", "Jan", "Feb", "Mar", "Apr", "May", "Jun", "Jul", "Aug", "Sep", "Oct", "Nov", "Dec"],
["Chris", 50, "", "", "", 60, "", "", "", "", "", "", ""],
["Fred", "", "", "", "", "", "", 20, 30, "", "", "", ""],
["Dan", "", "", "", "", "", 10, 20, 31, "", "", "", ""],
["Kev", "", 10, 20, "", 60, "", "", "", "", "", "", ""],
["Dori", "", "", "", "", "", "", "", "", "", "", "", 50],
["Gab", 50, "", "", "", 60, "", "", 10, "20", "", "", ""]
]
}
selectAll1() {
return this.selectAllAuthors("selectAll1", "select * from authors");
}
selectAllCase1() {
return this.selectAllAuthors("selectAllCase1", "Select * from authors");
}
selectIsNotNull1() {
return this.selectAllAuthors("selectIsNotNull1", "select * from authors where id is not null");
}
selectAllAuthors(functionName, stmt) {
let data = new TestSql()
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["AUTHORS.ID", "AUTHORS.FIRST_NAME", "AUTHORS.LAST_NAME"],
["11", "Ellen", "Writer"],
["12", "Olga", "Savelieva"],
["13", "Jack", "Smart"],
["14", "Donald", "Brain"],
["15", "Yao", "Dou"]];
return this.isEqual(functionName, data, expected);
}
selectAllAuthorsToObject(functionName) {
let stmt = "select * from authors";
let data = new Select2Object()
.addTableData("authors", this.authorsTable())
.execute(stmt);
let expected = [{ "id": "11", "first_name": "Ellen", "last_name": "Writer" },
{ "id": "12", "first_name": "Olga", "last_name": "Savelieva" },
{ "id": "13", "first_name": "Jack", "last_name": "Smart" },
{ "id": "14", "first_name": "Donald", "last_name": "Brain" },
{ "id": "15", "first_name": "Yao", "last_name": "Dou" }];
return this.isEqual("selectAllAuthorsToObject", data, expected);
}
selectAnAuthorsToObject(functionName) {
let stmt = "select * from authors where first_name = ?1";
let data = new Select2Object()
.addTableData("authors", this.authorsTable())
.addBindVariable("Jack")
.execute(stmt);
let expected = [{ "id": "13", "first_name": "Jack", "last_name": "Smart" }];
return this.isEqual("selectAnAuthorsToObject", data, expected);
}
selectIsNull1() {
let stmt = "select * from authors where id is null";
let data = new TestSql()
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["AUTHORS.ID", "AUTHORS.FIRST_NAME", "AUTHORS.LAST_NAME"]];
return this.isEqual("selectIsNull1", data, expected);
}
innerJoin1a() {
let stmt = "SELECT books.id, books.title, authors.first_name, authors.last_name " +
"FROM books " +
"INNER JOIN authors " +
"ON books.author_id = authors.id " +
"ORDER BY books.id";
return this.innerJoin1(stmt, "innerJoin1a");
}
innerJoin1case() {
let stmt = "SELECT books.id, books.title, authors.first_name, authors.last_name " +
"FROM books " +
"Inner Join authors " +
"ON books.author_id = authors.id " +
"ORDER BY books.id";
return this.innerJoin1(stmt, "innerJoin1case");
}
innerJoin1(stmt, funcName) {
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "authors.first_name", "authors.last_name"],
["1", "Time to Grow Up!", "Ellen", "Writer"],
["2", "Your Trip", "Yao", "Dou"],
["3", "Lovely Love", "Donald", "Brain"],
["4", "Dream Your Life", "Ellen", "Writer"],
["5", "Oranges", "Olga", "Savelieva"],
["6", "Your Happy Life", "Yao", "Dou"],
["7", "Applied AI", "Jack", "Smart"],
["8", "My Last Book", "Ellen", "Writer"]];
return this.isEqual(funcName, data, expected);
}
innerJoin2() {
let stmt = "SELECT books.id, books.title, books.type, authors.last_name, " +
"translators.last_name " +
"FROM books " +
"INNER JOIN authors " +
"ON books.author_id = authors.id " +
"INNER JOIN translators " +
"ON books.translator_id = translators.id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("translators", this.translatorsTable())
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "books.type", "authors.last_name", "translators.last_name"],
["2", "Your Trip", "translated", "Dou", "Weng"],
["5", "Oranges", "translated", "Savelieva", "Davies"],
["6", "Your Happy Life", "translated", "Dou", "Green"],
["7", "Applied AI", "translated", "Smart", "Edwards"]];
return this.isEqual("innerJoin2", data, expected);
}
innerJoin2ToObject() {
let stmt = "SELECT books.id, books.title, books.type, authors.last_name, " +
"translators.last_name " +
"FROM books " +
"INNER JOIN authors " +
"ON books.author_id = authors.id " +
"INNER JOIN translators " +
"ON books.translator_id = translators.id " +
"ORDER BY books.id";
let data = new Select2Object()
.addTableData("books", this.bookTable())
.addTableData("translators", this.translatorsTable())
.addTableData("authors", this.authorsTable())
.execute(stmt);
let expected = [{ "books.id": "2", "books.title": "Your Trip", "books.type": "translated", "authors.last_name": "Dou", "translators.last_name": "Weng" },
{ "books.id": "5", "books.title": "Oranges", "books.type": "translated", "authors.last_name": "Savelieva", "translators.last_name": "Davies" },
{ "books.id": "6", "books.title": "Your Happy Life", "books.type": "translated", "authors.last_name": "Dou", "translators.last_name": "Green" },
{ "books.id": "7", "books.title": "Applied AI", "books.type": "translated", "authors.last_name": "Smart", "translators.last_name": "Edwards" }];
let test1 = this.isEqual("innerJoin2ToObject(a)", data, expected);
data = data.filter(v => v["authors.last_name"] === "Smart");
expected = [{ "books.id": "7", "books.title": "Applied AI", "books.type": "translated", "authors.last_name": "Smart", "translators.last_name": "Edwards" }];
let test2 = this.isEqual("innerJoin2ToObject(b)", data, expected);;
return test1 && test2;
}
innerJoinAlias1() {
let stmt = "SELECT b.id, b.title, a.first_name, a.last_name " +
"FROM books as b " +
"INNER JOIN authors as a " +
"ON b.author_id = a.id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["b.id", "b.title", "a.first_name", "a.last_name"],
["1", "Time to Grow Up!", "Ellen", "Writer"],
["2", "Your Trip", "Yao", "Dou"],
["3", "Lovely Love", "Donald", "Brain"],
["4", "Dream Your Life", "Ellen", "Writer"],
["5", "Oranges", "Olga", "Savelieva"],
["6", "Your Happy Life", "Yao", "Dou"],
["7", "Applied AI", "Jack", "Smart"],
["8", "My Last Book", "Ellen", "Writer"]];
return this.isEqual("innerJoinAlias1", data, expected);
}
innerJoinAlias2() {
let stmt = "SELECT b.id, b.title, a.first_name, a.last_name " +
"FROM books as b " +
"INNER JOIN authors as a " +
"ON b.author_id = a.id " +
"ORDER BY books.id";
let testSQL = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true);
let data = testSQL.execute(stmt);
let expected = [["b.id", "b.title", "a.first_name", "a.last_name"],
["1", "Time to Grow Up!", "Ellen", "Writer"],
["2", "Your Trip", "Yao", "Dou"],
["3", "Lovely Love", "Donald", "Brain"],
["4", "Dream Your Life", "Ellen", "Writer"],
["5", "Oranges", "Olga", "Savelieva"],
["6", "Your Happy Life", "Yao", "Dou"],
["7", "Applied AI", "Jack", "Smart"],
["8", "My Last Book", "Ellen", "Writer"]];
this.isEqual("innerJoinAlias2a", data, expected);
stmt = "SELECT b1.id, b1.title, a2.first_name, a2.last_name " +
"FROM books as b1 " +
"INNER JOIN authors as a2 " +
"ON b1.author_id = a2.id " +
"ORDER BY books.id";
data = testSQL.execute(stmt);
expected = [["b1.id", "b1.title", "a2.first_name", "a2.last_name"],
["1", "Time to Grow Up!", "Ellen", "Writer"],
["2", "Your Trip", "Yao", "Dou"],
["3", "Lovely Love", "Donald", "Brain"],
["4", "Dream Your Life", "Ellen", "Writer"],
["5", "Oranges", "Olga", "Savelieva"],
["6", "Your Happy Life", "Yao", "Dou"],
["7", "Applied AI", "Jack", "Smart"],
["8", "My Last Book", "Ellen", "Writer"]];
return this.isEqual("innerJoinAlias2b", data, expected);
}
join2a() {
let stmt = "SELECT books.id, books.title, books.type, translators.last_name " +
"FROM books " +
"JOIN translators " +
"ON books.translator_id = translators.id " +
"ORDER BY books.id";
return this.join2(stmt, "join2a");
}
join2b() {
let stmt = "sElEcT books.id, books.title, books.type, translators.last_name " +
"froM books " +
"Join translators " +
"On books.translator_id = translators.id " +
"ORDEr By books.id";
return this.join2(stmt, "join2b");
}
join2(stmt, funcName) {
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("translators", this.translatorsTable())
.enableColumnTitle(true)
.execute(stmt)
let expected = [["books.id", "books.title", "books.type", "translators.last_name"],
["2", "Your Trip", "translated", "Weng"],
["5", "Oranges", "translated", "Davies"],
["6", "Your Happy Life", "translated", "Green"],
["7", "Applied AI", "translated", "Edwards"],
["9", "Book with Mysterious Author", "translated", "Edwards"]];
return this.isEqual(funcName, data, expected);
}
join3() {
let stmt = "SELECT books.id, books.title, editors.last_name " +
"FROM books " +
"LEFT JOIN editors " +
"ON books.editor_id = editors.id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("editors", this.editorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "editors.last_name"],
["1", "Time to Grow Up!", "Brown"],
["2", "Your Trip", "Johnson"],
["3", "Lovely Love", "Roberts"],
["4", "Dream Your Life", "Roberts"],
["5", "Oranges", "Wright"],
["6", "Your Happy Life", "Johnson"],
["7", "Applied AI", "Evans"],
["8", "My Last Book", null],
["9", "Book with Mysterious Author", "Evans"]];
return this.isEqual("join3", data, expected);
}
joinLimit1() {
let stmt = "SELECT books.id, books.title, editors.last_name " +
"FROM books " +
"LEFT JOIN editors " +
"ON books.editor_id = editors.id " +
"ORDER BY books.id " +
"LIMIT 5";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("editors", this.editorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "editors.last_name"],
["1", "Time to Grow Up!", "Brown"],
["2", "Your Trip", "Johnson"],
["3", "Lovely Love", "Roberts"],
["4", "Dream Your Life", "Roberts"],
["5", "Oranges", "Wright"]];
return this.isEqual("joinLimit1", data, expected);
}
leftJoin1() {
let stmt = "SELECT books.id, books.title, books.type, authors.last_name, " +
"translators.last_name " +
"FROM books " +
"LEFT JOIN authors " +
"ON books.author_id = authors.id " +
"LEFT JOIN translators " +
"ON books.translator_id = translators.id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("translators", this.translatorsTable())
.addTableData("authors", this.authorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "books.type", "authors.last_name", "translators.last_name"],
["1", "Time to Grow Up!", "original", "Writer", null],
["2", "Your Trip", "translated", "Dou", "Weng"],
["3", "Lovely Love", "original", "Brain", null],
["4", "Dream Your Life", "original", "Writer", null],
["5", "Oranges", "translated", "Savelieva", "Davies"],
["6", "Your Happy Life", "translated", "Dou", "Green"],
["7", "Applied AI", "translated", "Smart", "Edwards"],
["8", "My Last Book", "original", "Writer", null],
["9", "Book with Mysterious Author", "translated", null, "Edwards"]];
return this.isEqual("leftJoin1", data, expected);
}
rightJoin1() {
let stmt = "SELECT books.id, books.title, editors.last_name, editors.id " +
"FROM books " +
"RIGHT JOIN editors " +
"ON books.editor_id = editors.id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("editors", this.editorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "editors.last_name", "editors.id"],
[null, null, "Smart", "13"],
[null, null, "Jones", "26"],
[null, null, "Smith", "27"],
[null, null, "Dumb", "50"],
[null, null, "Smart", "51"],
["1", "Time to Grow Up!", "Brown", "21"],
["2", "Your Trip", "Johnson", "22"],
["3", "Lovely Love", "Roberts", "24"],
["4", "Dream Your Life", "Roberts", "24"],
["5", "Oranges", "Wright", "25"],
["6", "Your Happy Life", "Johnson", "22"],
["7", "Applied AI", "Evans", "23"],
["9", "Book with Mysterious Author", "Evans", "23"]];
return this.isEqual("rightJoin1", data, expected);
}
rightJoin1a() {
let stmt = "SELECT books.id, books.title, editors.last_name, editors.id " +
"FROM books " +
"right join editors on editors.id = books.editor_id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("editors", this.editorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "editors.last_name", "editors.id"],
[null, null, "Smart", "13"],
[null, null, "Jones", "26"],
[null, null, "Smith", "27"],
[null, null, "Dumb", "50"],
[null, null, "Smart", "51"],
["1", "Time to Grow Up!", "Brown", "21"],
["2", "Your Trip", "Johnson", "22"],
["3", "Lovely Love", "Roberts", "24"],
["4", "Dream Your Life", "Roberts", "24"],
["5", "Oranges", "Wright", "25"],
["6", "Your Happy Life", "Johnson", "22"],
["7", "Applied AI", "Evans", "23"],
["9", "Book with Mysterious Author", "Evans", "23"]];
return this.isEqual("rightJoin1a", data, expected);
}
rightJoin2() {
let stmt = "SELECT books.id, books.title, books.translator_id, " +
"editors.last_name, editors.id, " +
"translators.last_name " +
"FROM books " +
"RIGHT JOIN editors " +
"ON books.editor_id = editors.id " +
"RIGHT JOIN translators " +
"ON books.translator_id = translators.id " +
"ORDER BY books.id";
let data = new TestSql()
.addTableData("books", this.bookTable())
.addTableData("translators", this.translatorsTable())
.addTableData("editors", this.editorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["books.id", "books.title", "books.translator_id", "editors.last_name", "editors.id", "translators.last_name"],
["2", "Your Trip", "32", "Johnson", "22", "Weng"],
["5", "Oranges", "31", "Wright", "25", "Davies"],
["6", "Your Happy Life", "33", "Johnson", "22", "Green"],
["7", "Applied AI", "34", "Evans", "23", "Edwards"],
["9", "Book with Mysterious Author", "34", "Evans", "23", "Edwards"]];
return this.isEqual("rightJoin2", data, expected);
}
fullJoin1() {
let stmt = "SELECT authors.id, authors.last_name, editors.id, editors.last_name " +
"FROM authors " +
"FULL JOIN editors " +
"ON authors.id = editors.id ";
let data = new TestSql()
.addTableData("authors", this.authorsTable())
.addTableData("editors", this.editorsTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["authors.id", "authors.last_name", "editors.id", "editors.last_name"],
["11", "Writer", null, null],
["12", "Savelieva", null, null],
["13", "Smart", "13", "Smart"],
["14", "Brain", null, null],
["15", "Dou", null, null],
[null, null, "21", "Brown"],
[null, null, "22", "Johnson"],
[null, null, "23", "Evans"],
[null, null, "24", "Roberts"],
[null, null, "25", "Wright"],
[null, null, "26", "Jones"],
[null, null, "27", "Smith"],
[null, null, "50", "Dumb"],
[null, null, "51", "Smart"]];
return this.isEqual("fullJoin1", data, expected);
}
// FULL JOIN not supported in mySQL - so no comparison is possible.
fullJoin2() {
let stmt = "SELECT *, customers.address, customers.id, customers.name " +
"FROM booksales " +
"FULL JOIN customers " +
"ON customer_id = customers.id ";
let data = new TestSql()
.addTableData("booksales", this.bookSalesTable())
.addTableData("customers", this.customerTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["BOOKSALES.INVOICE", "BOOKSALES.BOOK_ID", "BOOKSALES.CUSTOMER_ID", "BOOKSALES.QUANTITY", "BOOKSALES.PRICE", "BOOKSALES.DATE", "CUSTOMERS.ID", "CUSTOMERS.NAME", "CUSTOMERS.ADDRESS", "CUSTOMERS.CITY", "CUSTOMERS.PHONE", "CUSTOMERS.EMAIL", "customers.address", "customers.id", "customers.name"],
["I7200", "9", "C1", 10, 34.95, "05/01/2022", "C1", "Numereo Uno", "101 One Way", "One Point City", "9051112111", "bigOne@gmail.com", "101 One Way", "C1", "Numereo Uno"],
["I7201", "8", "C2", 3, 29.95, "05/01/2022", "C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com", "202 Second St.", "C2", "Dewy Tuesdays"],
["I7201", "7", "C2", 5, 18.99, "05/01/2022", "C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com", "202 Second St.", "C2", "Dewy Tuesdays"],
["I7202", "9", "C3", 1, 59.99, "05/02/2022", "C3", "Tres Buon Goods", "3 Way St", "Tres City", "5193133303", "thrice@hotmail.com", "3 Way St", "C3", "Tres Buon Goods"],
["I7203", "1", "", 1, 90, "05/02/2022", null, null, null, null, null, null, null, null, null],
["I7204", "2", "C4", 100, 65.49, "05/03/2022", "C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com", "40 Four St", "C4", "ForMe Resellers"],
["I7204", "3", "C4", 150, 24.95, "05/03/2022", "C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com", "40 Four St", "C4", "ForMe Resellers"],
["I7204", "4", "C4", 50, 19.99, "05/03/2022", "C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com", "40 Four St", "C4", "ForMe Resellers"],
["I7205", "7", "C1", 1, 33.97, "05/04/2022", "C1", "Numereo Uno", "101 One Way", "One Point City", "9051112111", "bigOne@gmail.com", "101 One Way", "C1", "Numereo Uno"],
["I7206", "7", "C2", 100, 17.99, "05/04/2022", "C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com", "202 Second St.", "C2", "Dewy Tuesdays"],
[null, null, null, null, null, null, "C5", "Fe Fi Fo Giant Tiger", "5 ohFive St.", "FifthDom", "4165551234", " fiver@gmail.com", "5 ohFive St.", "C5", "Fe Fi Fo Giant Tiger"],
[null, null, null, null, null, null, "C6", "Sx in Cars", "6 Seventh St", "Sx City", "6661116666", "gotyourSix@hotmail.com ", "6 Seventh St", "C6", "Sx in Cars"],
[null, null, null, null, null, null, "C7", "7th Heaven", "7 Eight Crt.", "Lucky City", "5551117777", " timesAcharm@gmail.com ", "7 Eight Crt.", "C7", "7th Heaven"]];
return this.isEqual("fullJoin2", data, expected);
}
fullJoin3() {
let stmt = "SELECT * " +
"FROM booksales " +
"FULL JOIN customers " +
"ON booksales.customer_id = customers.id " +
"FULL JOIN books " +
"ON booksales.Book_Id = books.id";
let data = new TestSql()
.addTableData("booksales", this.bookSalesTable())
.addTableData("customers", this.customerTable())
.addTableData("books", this.bookTable())
.enableColumnTitle(true)
.execute(stmt);
let expected = [["BOOKSALES.INVOICE", "BOOKSALES.BOOK_ID", "BOOKSALES.CUSTOMER_ID", "BOOKSALES.QUANTITY", "BOOKSALES.PRICE", "BOOKSALES.DATE", "CUSTOMERS.ID", "CUSTOMERS.NAME", "CUSTOMERS.ADDRESS", "CUSTOMERS.CITY", "CUSTOMERS.PHONE", "CUSTOMERS.EMAIL", "BOOKS.ID", "BOOKS.TITLE", "BOOKS.TYPE", "BOOKS.AUTHOR_ID", "BOOKS.EDITOR_ID", "BOOKS.TRANSLATOR_ID"],
["I7200", "9", "C1", 10, 34.95, "05/01/2022", "C1", "Numereo Uno", "101 One Way", "One Point City", "9051112111", "bigOne@gmail.com", "9", "Book with Mysterious Author", "translated", "1", "23", "34"],
["I7201", "8", "C2", 3, 29.95, "05/01/2022", "C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com", "8", "My Last Book", "original", "11", "28", ""],
["I7201", "7", "C2", 5, 18.99, "05/01/2022", "C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com", "7", "Applied AI", "translated", "13", "23", "34"],
["I7202", "9", "C3", 1, 59.99, "05/02/2022", "C3", "Tres Buon Goods", "3 Way St", "Tres City", "5193133303", "thrice@hotmail.com", "9", "Book with Mysterious Author", "translated", "1", "23", "34"],
["I7203", "1", "", 1, 90, "05/02/2022", null, null, null, null, null, null, "1", "Time to Grow Up!", "original", "11", "21", ""],
["I7204", "2", "C4", 100, 65.49, "05/03/2022", "C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com", "2", "Your Trip", "translated", "15", "22", "32"],
["I7204", "3", "C4", 150, 24.95, "05/03/2022", "C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com", "3", "Lovely Love", "original", "14", "24", ""],
["I7204", "4", "C4", 50, 19.99, "05/03/2022", "C4", "ForMe Resellers", "40 Four St", "FourtNight City", "2894441234", "fourtimes@hotmail.com", "4", "Dream Your Life", "original", "11", "24", ""],
["I7205", "7", "C1", 1, 33.97, "05/04/2022", "C1", "Numereo Uno", "101 One Way", "One Point City", "9051112111", "bigOne@gmail.com", "7", "Applied AI", "translated", "13", "23", "34"],
["I7206", "7", "C2", 100, 17.99, "05/04/2022", "C2", "Dewy Tuesdays", "202 Second St.", "Second City", "4162022222", "twoguys@gmail.com", "7", "Applied AI", "translated", "13", "23", "34"],
[null, null, null, null, null, null, "C5", "Fe Fi Fo Giant Tiger", "5 ohFive St.", "FifthDom", "4165551234", " fiver@gmail.com", null, null, null, null, null, null],
[null, null, null, null, null, null, "C6", "Sx in Cars", "6 Seventh St", "Sx City", "6661116666", "gotyourSix@hotmail.com ", null, null, null, null, null, null],
[null, null, null, null, null, null, "C7", "7th Heaven", "7 Eight Crt.", "Lucky City", "5551117777", " timesAcharm@gmail.com ", null, null, null, null, null, null],
[null, null, null, null, null, null, null, null, null, null, null, null, "5", "Oranges", "translated", "12", "25", "31"],
[null, null, null, null, null, null, null, null, null, null, null, null, "6", "Your Happy Life", "translated", "15", "22", "33"]];
return this.isEqual("fullJoin3", data, expected);
}
whereIn1() {
let stmt = "SELECT books.id, books.title, books.author_id " +
"FROM books "