Skip to content
57 changes: 57 additions & 0 deletions src/15utility.js
Original file line number Diff line number Diff line change
Expand Up @@ -1347,5 +1347,62 @@ var getXLSX = function () {
return XLSX;
};

/**
* Type converter regex patterns
*/
var reTypeConverter = {
str: /string|char$|text/i,
int: /int$/i,
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What about INTEGER? It needs. ^int aswell

num: /float|double|real|^num|decimal|money/i,
bool: /^bool/i,
date: /^date|^time/i,
};

/**
* Convert a value to the appropriate type based on column definition
* @param {*} value - The value to convert
* @param {string} dbtypeid - The database type (INT, FLOAT, STRING, etc.)
* @return {*} The converted value
*/
utils.convertValueToType = function (value, dbtypeid) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

please rename to "typeConverter" so its aligned with reTypeConverter

// If value is null or undefined, return as is
if (value === null || value === undefined) {
return value;
}

// If no type specified, try to auto-convert if it looks like a number
if (!dbtypeid) {
if (alasql.options.csvStringToNumber && typeof value === 'string' && value.length > 0) {
if (value == +value) {
return +value;
}
}
return value;
}

// Check type using regex patterns
if (reTypeConverter.str.test(dbtypeid)) {
return String(value);
}
if (reTypeConverter.int.test(dbtypeid)) {
return parseInt(value, 10);
}
if (reTypeConverter.num.test(dbtypeid)) {
return parseFloat(value);
}
if (reTypeConverter.bool.test(dbtypeid)) {
if (typeof value === 'string') {
return /^(true|1|yes)$/i.test(value);
}
return Boolean(value);
}
if (reTypeConverter.date.test(dbtypeid)) {
return value instanceof Date ? value : new Date(value);
}

// Unknown type, return as is
return value;
};

// set AlaSQl path
alasql.path = alasql.utils.findAlaSQLPath();
3 changes: 3 additions & 0 deletions src/17alasql.js
Original file line number Diff line number Diff line change
Expand Up @@ -131,6 +131,9 @@ alasql.options = {

/** Whether GETDATE() and NOW() return dates as string. If false, then a Date object is returned */
dateAsString: true,

/** Automatically convert string values to numbers when reading from CSV files. Set to false to preserve string types */
csvStringToNumber: true,
};

//alasql.options.worker = false;
Expand Down
19 changes: 13 additions & 6 deletions src/40select.js
Original file line number Diff line number Diff line change
Expand Up @@ -300,12 +300,19 @@ yy.Select = class Select {
cb
);`;
} else {
// Into AlaSQL tables
query.intofns = `alasql
.databases[${JSON.stringify(this.into.databaseid || databaseid)}]
.tables[${JSON.stringify(this.into.tableid)}]
.data.push(r);
`;
// Into AlaSQL tables - convert types based on column definitions
var dbid = this.into.databaseid || databaseid;
var tblid = this.into.tableid;
query.intofns = `
var db = alasql.databases[${JSON.stringify(dbid)}];
var table = db.tables[${JSON.stringify(tblid)}];
var converted = {};
for (var key in r) {
var colDef = table.xcolumns && table.xcolumns[key];
converted[key] = alasql.utils.convertValueToType(r[key], colDef ? colDef.dbtypeid : null);
}
table.data.push(converted);
`;
}
} else if (this.into instanceof yy.VarValue) {
//
Expand Down
32 changes: 3 additions & 29 deletions src/84from.js
Original file line number Diff line number Diff line change
Expand Up @@ -333,50 +333,24 @@ alasql.from.CSV = function (contents, opts, cb, idx, query) {
var r = {};
hs.forEach(function (h, idx) {
r[h] = a[idx];
// Please avoid === here
if (
!opt.raw &&
typeof r[h] !== 'undefined' &&
r[h].length !== 0 &&
r[h].trim() == +r[h]
) {
// jshint ignore:line
r[h] = +r[h];
}
// Keep as string - type conversion happens at INSERT time based on column definitions
});
rows.push(r);
}
} else {
var r = {};
hs.forEach(function (h, idx) {
r[h] = a[idx];
if (
!opt.raw &&
typeof r[h] !== 'undefined' &&
r[h].length !== 0 &&
r[h].trim() == +r[h]
) {
// jshint ignore:line
r[h] = +r[h];
}
// Keep as string - type conversion happens at INSERT time based on column definitions
});
rows.push(r);
}
n++;
} else {
var r = {};
// different bug here, if headers are not defined, the numerical values will not be parsed
// Keep as string - type conversion happens at INSERT time based on column definitions
a.forEach(function (v, idx) {
r[idx] = a[idx];
if (
!opt.raw &&
typeof r[idx] !== 'undefined' &&
r[idx].length !== 0 &&
r[idx].trim() == +r[idx]
) {
// jshint ignore:line
r[idx] = +r[idx];
}
});
rows.push(r);
}
Expand Down
178 changes: 178 additions & 0 deletions test/test-csv-string-type.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,178 @@
if (typeof exports === 'object') {
var assert = require('assert');
var alasql = require('..');
var fs = require('fs');
}

describe('Test CSV string type preservation and column type conversion', function () {
const test = 'csvstringtype';

before(function () {
alasql('create database test' + test);
alasql('use test' + test);
});

after(function () {
alasql('drop database test' + test);
});

it('A) CSV parser always keeps values as strings', function () {
var csvData = '"117.20";"500"\n"88.33";"600"';
var res = alasql('SELECT * FROM CSV(?, {separator:";", headers:false})', [csvData]);
assert.deepEqual(res, [
{0: '117.20', 1: '500'},
{0: '88.33', 1: '600'},
]);
});

it('B) STRING type - preserves string values', function () {
alasql('CREATE TABLE test_string (id STRING, name STRING)');
var csvData = '"id";"name"\n"117.20";"test"\n"88.33";"item"';
alasql('SELECT * INTO test_string FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_string');
assert.deepEqual(res, [
{id: '117.20', name: 'test'},
{id: '88.33', name: 'item'},
]);
alasql('DROP TABLE test_string');
});

it('C) STRING type - converts numbers to strings', function () {
alasql('CREATE TABLE test_str_num (code STRING, qty STRING)');
var csvData = '"code";"qty"\n"123";"456"';
alasql('SELECT * INTO test_str_num FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_str_num');
assert.deepEqual(res, [{code: '123', qty: '456'}]);
alasql('DROP TABLE test_str_num');
});

it('D) INT type - converts strings to integers', function () {
alasql('CREATE TABLE test_int (id INT, qty INT)');
var csvData = '"id";"qty"\n"123";"456"';
alasql('SELECT * INTO test_int FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_int');
assert.deepEqual(res, [{id: 123, qty: 456}]);
alasql('DROP TABLE test_int');
});

it('E) INT type - truncates decimal values', function () {
alasql('CREATE TABLE test_int_dec (amount INT)');
var csvData = '"amount"\n"99.99"\n"123.45"';
alasql('SELECT * INTO test_int_dec FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_int_dec');
assert.deepEqual(res, [{amount: 99}, {amount: 123}]);
alasql('DROP TABLE test_int_dec');
});

it('F) FLOAT type - preserves decimal precision', function () {
alasql('CREATE TABLE test_float (price FLOAT, cost FLOAT)');
var csvData = '"price";"cost"\n"99.99";"123.45"';
alasql('SELECT * INTO test_float FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_float');
assert.deepEqual(res, [{price: 99.99, cost: 123.45}]);
alasql('DROP TABLE test_float');
});

it('G) FLOAT type - converts string decimals to numbers', function () {
alasql('CREATE TABLE test_float_str (amount FLOAT)');
var csvData = '"amount"\n"117.20"\n"88.33"';
alasql('SELECT * INTO test_float_str FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_float_str');
assert.deepEqual(res, [{amount: 117.2}, {amount: 88.33}]);
alasql('DROP TABLE test_float_str');
});

it('H) BOOLEAN type - converts string true/false', function () {
alasql('CREATE TABLE test_bool (active BOOLEAN, enabled BOOLEAN)');
var csvData = '"active";"enabled"\n"true";"false"\n"1";"0"';
alasql('SELECT * INTO test_bool FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_bool');
assert.deepEqual(res, [
{active: true, enabled: false},
{active: true, enabled: false},
]);
alasql('DROP TABLE test_bool');
});

it('I) BOOLEAN type - handles yes/no strings', function () {
alasql('CREATE TABLE test_bool_yn (flag BOOLEAN)');
var csvData = '"flag"\n"yes"\n"no"';
alasql('SELECT * INTO test_bool_yn FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_bool_yn');
assert.deepEqual(res, [{flag: true}, {flag: false}]);
alasql('DROP TABLE test_bool_yn');
});

it('J) DATE type - converts string dates', function () {
alasql('CREATE TABLE test_date (created DATE)');
var csvData = '"created"\n"2023-01-15"';
alasql('SELECT * INTO test_date FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_date');
assert.deepEqual(res, [{created: new Date('2023-01-15')}]);
alasql('DROP TABLE test_date');
});

it('K) Mixed types - all conversions work together', function () {
alasql('CREATE TABLE test_mixed (id STRING, qty INT, price FLOAT, active BOOLEAN)');
var csvData = '"id";"qty";"price";"active"\n"117.20";"10";"99.99";"true"';
alasql('SELECT * INTO test_mixed FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_mixed');
assert.deepEqual(res, [{id: '117.20', qty: 10, price: 99.99, active: true}]);
alasql('DROP TABLE test_mixed');
});

it('L) No column definitions with csvStringToNumber=true - auto-converts', function () {
alasql.options.csvStringToNumber = true;
alasql('CREATE TABLE test_nodef');
var csvData = '"id";"amount"\n"117.20";"500"';
alasql('SELECT * INTO test_nodef FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_nodef');
assert.deepEqual(res, [{id: 117.2, amount: 500}]);
alasql('DROP TABLE test_nodef');
});

it('M) No column definitions with csvStringToNumber=false - preserves strings', function () {
alasql.options.csvStringToNumber = false;
alasql('CREATE TABLE test_nodef2');
var csvData = '"id";"amount"\n"117.20";"500"';
alasql('SELECT * INTO test_nodef2 FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_nodef2');
assert.deepEqual(res, [{id: '117.20', amount: '500'}]);
alasql('DROP TABLE test_nodef2');
alasql.options.csvStringToNumber = true; // Restore default
});

it('N) VARCHAR and CHAR types work like STRING', function () {
alasql('CREATE TABLE test_varchar (name VARCHAR, code CHAR)');
var csvData = '"name";"code"\n"123.45";"ABC"';
alasql('SELECT * INTO test_varchar FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_varchar');
assert.deepEqual(res, [{name: '123.45', code: 'ABC'}]);
alasql('DROP TABLE test_varchar');
});

it('O) NULL and undefined values are preserved', function () {
alasql('CREATE TABLE test_nulls (id STRING, qty INT)');
var csvData = '"id";"qty"\n"A001";""';
alasql('SELECT * INTO test_nulls FROM CSV(?, {separator:";"})', [csvData]);
var res = alasql('SELECT * FROM test_nulls');
// Empty string in CSV becomes empty string, then parseInt returns NaN
assert.deepEqual(res, [{id: 'A001', qty: NaN}]);
alasql('DROP TABLE test_nulls');
});

it('P) TSV also respects column types', function () {
alasql('CREATE TABLE test_tsv (id STRING, amount INT)');
var tsvData = 'id\tamount\n117.20\t500';
alasql('SELECT * INTO test_tsv FROM TSV(?)', [tsvData]);
var res = alasql('SELECT * FROM test_tsv');
assert.deepEqual(res, [{id: '117.20', amount: 500}]);
alasql('DROP TABLE test_tsv');
});

it('Q) Direct SELECT from CSV without INSERT returns strings', function () {
var csvData = '"id";"name"\n"117.20";"test"';
var res = alasql('SELECT * FROM CSV(?, {separator:";"})', [csvData]);
assert.deepEqual(res, [{id: '117.20', name: 'test'}]);
});
});