fb98fb9281
- Add testing with PostgresSQL 16.6.1 and pg 8.13.1 - Add Linux user creation instructions with password setup - Document SCRAM auth - Updated pg dependency to 8.13.1 - SheetJSPG.js removed trailing whitespace The guide now includes more detailed Linux setup instructions and authentication requirements for PostgreSQL deployments.
173 lines
5.6 KiB
JavaScript
173 lines
5.6 KiB
JavaScript
const pg = require("pg"), format = require("pg-format");
|
|
const XLSX = require("xlsx");
|
|
const opts = {
|
|
database:"SheetJSPG",
|
|
host: "127.0.0.1", // localhost
|
|
port: 5432,
|
|
//user: "",
|
|
//password: ""
|
|
};
|
|
|
|
function deduceType(cells) {
|
|
if (!cells || cells.length === 0) return 'text';
|
|
|
|
const nonEmptyCells = cells.filter(cell => cell && cell.v != null);
|
|
if (nonEmptyCells.length === 0) return 'text';
|
|
|
|
// Check for dates by looking at both cell type and formatted value
|
|
const isDateCell = cell => cell?.t === 'd' || (cell?.t === 'n' && cell.w && /\d{4}-\d{2}-\d{2}|\d{1,2}\/\d{1,2}\/\d{4}|\d{2}-[A-Za-z]{3}-\d{4}|[A-Za-z]{3}-\d{2}|\d{1,2}-[A-Za-z]{3}/.test(cell.w));
|
|
|
|
if (nonEmptyCells.some(isDateCell)) { return 'date'; }
|
|
|
|
// Check for booleans
|
|
const allBooleans = nonEmptyCells.every(cell => cell.t === 'b');
|
|
if (allBooleans) { return 'boolean'; }
|
|
|
|
// Check for numbers
|
|
const allNumbers = nonEmptyCells.every(cell => cell.t === 'n' || (cell.t === 's' && !isNaN(cell.v.replace(/[,$\s%()]/g, ''))));
|
|
|
|
if (allNumbers) {
|
|
const numbers = nonEmptyCells.map(cell => {
|
|
if (cell.t === 'n') return cell.v;
|
|
return parseFloat(cell.v.replace(/[,$\s%()]/g, ''));
|
|
});
|
|
|
|
const needsPrecision = numbers.some(num => {
|
|
const str = num.toString();
|
|
return str.includes('e') ||
|
|
(str.includes('.') && str.split('.')[1].length > 6) ||
|
|
Math.abs(num) > 1e15;
|
|
});
|
|
|
|
return needsPrecision ? 'numeric' : 'double precision';
|
|
}
|
|
return 'text'; // default to string type
|
|
}
|
|
|
|
function parseValue(cell, type) {
|
|
if (!cell || cell.v == null) return null;
|
|
|
|
switch (type) {
|
|
case 'date':
|
|
if (cell.t === 'd') { return cell.v.toISOString().split('T')[0]; }
|
|
if (cell.t === 'n') {
|
|
const date = new Date((cell.v - 25569) * 86400 * 1000);
|
|
return date.toISOString().split('T')[0];
|
|
}
|
|
return null;
|
|
|
|
case 'numeric':
|
|
case 'double precision':
|
|
if (cell.t === 'n') return cell.v;
|
|
if (cell.t === 's') {
|
|
const cleaned = cell.v.replace(/[,$\s%()]/g, '');
|
|
if (!isNaN(cleaned)) return parseFloat(cleaned);
|
|
}
|
|
return null;
|
|
|
|
case 'boolean':
|
|
return cell.t === 'b' ? cell.v : null;
|
|
|
|
default:
|
|
return String(cell.v);
|
|
}
|
|
}
|
|
|
|
/* create table and load data given a worksheet and a PostgreSQL client */
|
|
async function sheet_to_pg_table(client, worksheet, tableName) {
|
|
if (!worksheet['!ref']) return;
|
|
|
|
const range = XLSX.utils.decode_range(worksheet['!ref']);
|
|
|
|
/* Extract headers from first row, clean names for PostgreSQL */
|
|
const headers = [];
|
|
for (let col = range.s.c; col <= range.e.c; col++) {
|
|
const cellAddress = XLSX.utils.encode_cell({ r: range.s.r, c: col });
|
|
const cell = worksheet[cellAddress];
|
|
const headerValue = cell ? String(cell.v).replace(/[^a-zA-Z0-9_]/g, '_') : `column_${col + 1}`;
|
|
headers.push(headerValue.toLowerCase());
|
|
}
|
|
|
|
/* Group cell values by column for type deduction */
|
|
const columnValues = headers.map(() => []);
|
|
for (let row = range.s.r + 1; row <= range.e.r; row++) {
|
|
for (let col = range.s.c; col <= range.e.c; col++) {
|
|
const cellAddress = XLSX.utils.encode_cell({ r: row, c: col });
|
|
const cell = worksheet[cellAddress];
|
|
columnValues[col].push(cell);
|
|
}
|
|
}
|
|
|
|
/* Deduce PostgreSQL type for each column */
|
|
const types = {};
|
|
headers.forEach((header, idx) => {
|
|
types[header] = deduceType(columnValues[idx]);
|
|
});
|
|
|
|
/* Delete table if it exists in the DB */
|
|
await client.query(format('DROP TABLE IF EXISTS %I', tableName));
|
|
|
|
/* Create table */
|
|
const createTableSQL = format(
|
|
'CREATE TABLE %I (%s)',
|
|
tableName,
|
|
headers.map(header => format('%I %s', header, types[header])).join(', ')
|
|
);
|
|
await client.query(createTableSQL);
|
|
|
|
/* Insert data row by row */
|
|
for (let row = range.s.r + 1; row <= range.e.r; row++) {
|
|
const values = headers.map((header, col) => {
|
|
const cellAddress = XLSX.utils.encode_cell({ r: row, c: col });
|
|
const cell = worksheet[cellAddress];
|
|
return parseValue(cell, types[header]);
|
|
});
|
|
|
|
const insertSQL = format(
|
|
'INSERT INTO %I (%s) VALUES (%s)',
|
|
tableName,
|
|
headers.map(h => format('%I', h)).join(', '),
|
|
values.map(() => '%L').join(', ')
|
|
);
|
|
await client.query(format(insertSQL, ...values));
|
|
}
|
|
}
|
|
|
|
(async() => {
|
|
|
|
/* read file and get first worksheet */
|
|
const oldwb = XLSX.readFile("pres.numbers");
|
|
const oldws = oldwb.Sheets[oldwb.SheetNames[0]];
|
|
|
|
/* import data to postgres */
|
|
let client = new pg.Client(opts);
|
|
try {
|
|
/* open connection to PostgreSQL database */
|
|
await client.connect();
|
|
|
|
/* create table and load data given a worksheet */
|
|
await sheet_to_pg_table(client, oldws, "Presidents");
|
|
} finally {
|
|
/* disconnect */
|
|
await client.end();
|
|
}
|
|
|
|
/* export data to xlsx */
|
|
client = new pg.Client(opts);
|
|
try {
|
|
/* open connection to PostgreSQL database */
|
|
await client.connect();
|
|
|
|
/* fetch all data from specified table */
|
|
const res = await client.query(format(`SELECT * FROM %I`, "Presidents"));
|
|
|
|
/* export to file */
|
|
const newws = XLSX.utils.json_to_sheet(res.rows);
|
|
const newwb = XLSX.utils.book_new();
|
|
XLSX.utils.book_append_sheet(newwb, newws, "Export");
|
|
XLSX.writeFile(newwb, "SheetJSPGExport.xlsx");
|
|
} finally {
|
|
/* disconnect */
|
|
await client.end();
|
|
}
|
|
})(); |