const mysql = require("mysql2/promise"); const XLSX = require("xlsx"); const opts = { database:"SheetJSMariaDB", host: "127.0.0.1", // localhost port: 3306, user: "sheetjs", //password: "" }; /* create table and load data given an array of objects and a mysql2 connection */ async function aoo_to_mariadb_table(conn, aoo, table_name) { /* define types that can be converted (e.g. boolean can be stored in float) */ const T_FLOAT = ["DOUBLE", "BOOLEAN"]; const T_BOOL = ["BOOLEAN"]; /* types is a map from column headers to Knex schema column type */ const types = {}; /* names is an ordered list of the column header names */ const names = []; /* loop across each row object */ aoo.forEach(row => /* Object.entries returns a row of [key, value] pairs */ Object.entries(row).forEach(([k,v]) => { /* If this is first occurrence, mark unknown and append header to names */ if(!types[k]) { types[k] = ""; names.push(k); } /* skip null and undefined values */ if(v == null) return; /* check and resolve type */ switch(typeof v) { /* change type if it is empty or can be stored in a float */ case "number": if(!types[k] || T_FLOAT.includes(types[k])) types[k] = "DOUBLE"; break; /* change type if it is empty or can be stored in a boolean */ case "boolean": if(!types[k] || T_BOOL.includes(types[k])) types[k] = "BOOLEAN"; break; /* no other type can hold strings */ case "string": types[k] = "TEXT"; break; default: types[k] = "TEXT"; break; } }) ); const I = (id) => mysql.escapeId(id), E = (d) => mysql.escape(d); /* Delete table if it exists in the DB */ await conn.execute(`DROP TABLE IF EXISTS ${I(table_name)};`); /* Create table */ { const Istr = Object.entries(types).map(e => `${I(e[0])} ${e[1]}`).join(", "); await conn.execute(`CREATE TABLE ${I(table_name)} (${Istr});`); } /* Insert each row */ for(let row of aoo) { const ent = Object.entries(row); const Istr = ent.map(e => I(e[0])).join(", "); const Vstr = ent.map(e => E(e[1])).join(", "); await conn.execute(`INSERT INTO ${I(table_name)} (${Istr}) VALUES (${Vstr})`); } return conn; } (async() => { /* read file and get first worksheet */ const oldwb = XLSX.readFile("pres.numbers"); const oldws = oldwb.Sheets[oldwb.SheetNames[0]]; /* import data to mariadb */ let conn = await mysql.createConnection(opts); try { /* generate array of objects from worksheet */ const aoo = XLSX.utils.sheet_to_json(oldws); /* create table and load data */ await aoo_to_mariadb_table(conn, aoo, "Presidents"); } finally { /* disconnect */ await conn.end(); } /* export data to xlsx */ conn = await mysql.createConnection(opts); try { /* fetch all data from specified table */ const [ rows ] = await conn.execute(`SELECT * FROM ${mysql.escapeId("Presidents")}`); /* export to file */ const newws = XLSX.utils.json_to_sheet(rows); const newwb = XLSX.utils.book_new(); XLSX.utils.book_append_sheet(newwb, newws, "Export"); XLSX.writeFile(newwb, "SheetJSMariaDBExport.xlsx"); } finally { /* disconnect */ await conn.end(); } })();