From cf1367137da5775dc23cb57f0e4071776e1ff90f Mon Sep 17 00:00:00 2001 From: Ciro Spaciari Date: Sat, 27 Sep 2025 01:12:29 -0700 Subject: [PATCH] feat(sql.array) add support to sql.array (#22946) ### What does this PR do? Fixes https://github.com/oven-sh/bun/issues/17030 In this case should work as expected just passing a normal array should be serialized as JSON/JSONB Fixes https://github.com/oven-sh/bun/issues/17798 Insert and update helpers should work as expected here when using sql.array helper: ```sql CREATE TABLE user ( id SERIAL PRIMARY KEY, name VARCHAR NOT NULL, roles TEXT[] ); ``` ```js const item = { id: 1, name: "test", role: sql.array(['a', 'b'], "TEXT") }; await sql` UPDATE user SET ${sql(item)} WHERE id = 1 `; ``` Fixes https://github.com/oven-sh/bun/issues/22281 Should work using sql.array(array, "TEXT") Fixes https://github.com/oven-sh/bun/issues/22165 Fixes https://github.com/oven-sh/bun/issues/22155 Add sql.array(array, typeNameOrTypeID) in Bun.SQL (https://github.com/oven-sh/bun/issues/15088) ### How did you verify your code works? Tests --------- Co-authored-by: autofix-ci[bot] <114827586+autofix-ci[bot]@users.noreply.github.com> --- packages/bun-types/sql.d.ts | 77 +++++++++ src/js/bun/sql.ts | 10 ++ src/js/internal/sql/mysql.ts | 6 +- src/js/internal/sql/postgres.ts | 245 ++++++++++++++++++++++++++- src/js/internal/sql/shared.ts | 67 +++++++- src/js/internal/sql/sqlite.ts | 6 +- test/js/sql/sql.test.ts | 290 ++++++++++++++++++++++++++++++++ 7 files changed, 690 insertions(+), 11 deletions(-) diff --git a/packages/bun-types/sql.d.ts b/packages/bun-types/sql.d.ts index 7b0526b380..59681350ff 100644 --- a/packages/bun-types/sql.d.ts +++ b/packages/bun-types/sql.d.ts @@ -12,6 +12,68 @@ declare module "bun" { release(): void; } + type ArrayType = + | "BOOLEAN" + | "BYTEA" + | "CHAR" + | "NAME" + | "TEXT" + | "CHAR" + | "VARCHAR" + | "SMALLINT" + | "INT2VECTOR" + | "INTEGER" + | "INT" + | "BIGINT" + | "REAL" + | "DOUBLE PRECISION" + | "NUMERIC" + | "MONEY" + | "OID" + | "TID" + | "XID" + | "CID" + | "JSON" + | "JSONB" + | "JSONPATH" + | "XML" + | "POINT" + | "LSEG" + | "PATH" + | "BOX" + | "POLYGON" + | "LINE" + | "CIRCLE" + | "CIDR" + | "MACADDR" + | "INET" + | "MACADDR8" + | "DATE" + | "TIME" + | "TIMESTAMP" + | "TIMESTAMPTZ" + | "INTERVAL" + | "TIMETZ" + | "BIT" + | "VARBIT" + | "ACLITEM" + | "PG_DATABASE" + | (string & {}); + + /** + * Represents a SQL array parameter + */ + interface SQLArrayParameter { + /** + * The serialized values of the array parameter + */ + serializedValues: string; + /** + * The type of the array parameter + */ + arrayType: ArrayType; + } + /** * Represents a client within a transaction context Extends SQL with savepoint * functionality @@ -630,6 +692,21 @@ declare module "bun" { */ reserve(): Promise; + /** + * Creates a new SQL array parameter + * @param values - The values to create the array parameter from + * @param typeNameOrTypeID - The type name or type ID to create the array parameter from, if omitted it will default to JSON + * @returns A new SQL array parameter + * + * @example + * ```ts + * const array = sql.array([1, 2, 3], "INT"); + * await sql`CREATE TABLE users_posts (user_id INT, posts_id INT[])`; + * await sql`INSERT INTO users_posts (user_id, posts_id) VALUES (${user.id}, ${array})`; + * ``` + */ + array(values: any[], typeNameOrTypeID?: number | ArrayType): SQLArrayParameter; + /** * Begins a new transaction. * diff --git a/src/js/bun/sql.ts b/src/js/bun/sql.ts index dc063c0a1a..dc436d367f 100644 --- a/src/js/bun/sql.ts +++ b/src/js/bun/sql.ts @@ -316,6 +316,7 @@ const SQL: typeof Bun.SQL = function SQL( // reserve is allowed to be called inside reserved connection but will return a new reserved connection from the pool // this matchs the behavior of the postgres package reserved_sql.reserve = () => sql.reserve(); + reserved_sql.array = sql.array; function onTransactionFinished(transaction_promise: Promise) { reservedTransaction.delete(transaction_promise); } @@ -590,6 +591,7 @@ const SQL: typeof Bun.SQL = function SQL( // reserve is allowed to be called inside transaction connection but will return a new reserved connection from the pool and will not be part of the transaction // this matchs the behavior of the postgres package transaction_sql.reserve = () => sql.reserve(); + transaction_sql.array = sql.array; transaction_sql.connect = () => { if (state.connectionState & ReservedConnectionState.closed) { @@ -829,6 +831,10 @@ const SQL: typeof Bun.SQL = function SQL( pool.connect(onReserveConnected.bind(promiseWithResolvers), true); return promiseWithResolvers.promise; }; + + sql.array = (values: any[], typeNameOrID: number | string | undefined = undefined) => { + return pool.array(values, typeNameOrID); + }; sql.rollbackDistributed = async function (name: string) { if (pool.closed) { throw pool.connectionClosedError(); @@ -964,6 +970,10 @@ defaultSQLObject.reserve = (...args) => { ensureDefaultSQL(); return lazyDefaultSQL.reserve(...args); }; +defaultSQLObject.array = (...args) => { + ensureDefaultSQL(); + return lazyDefaultSQL.array(...args); +}; defaultSQLObject.commitDistributed = (...args) => { ensureDefaultSQL(); return lazyDefaultSQL.commitDistributed(...args); diff --git a/src/js/internal/sql/mysql.ts b/src/js/internal/sql/mysql.ts index d3431b1144..e338ddadfd 100644 --- a/src/js/internal/sql/mysql.ts +++ b/src/js/internal/sql/mysql.ts @@ -1,6 +1,6 @@ import type { MySQLErrorOptions } from "internal/sql/errors"; import type { Query } from "./query"; -import type { DatabaseAdapter, SQLHelper, SQLResultArray, SSLMode } from "./shared"; +import type { ArrayType, DatabaseAdapter, SQLArrayParameter, SQLHelper, SQLResultArray, SSLMode } from "./shared"; const { SQLHelper, SSLMode, SQLResultArray } = require("internal/sql/shared"); const { Query, @@ -549,7 +549,9 @@ class MySQLAdapter connection.queries.delete(handler); } } - + array(_values: any[], _typeNameOrID?: number | ArrayType): SQLArrayParameter { + throw new Error("MySQL doesn't support arrays"); + } getTransactionCommands(options?: string): import("./shared").TransactionCommands { let BEGIN = "START TRANSACTION"; if (options) { diff --git a/src/js/internal/sql/postgres.ts b/src/js/internal/sql/postgres.ts index 4e6a0c32f2..a86c78ca5c 100644 --- a/src/js/internal/sql/postgres.ts +++ b/src/js/internal/sql/postgres.ts @@ -1,12 +1,18 @@ import type { PostgresErrorOptions } from "internal/sql/errors"; import type { Query } from "./query"; -import type { DatabaseAdapter, SQLHelper, SQLResultArray, SSLMode } from "./shared"; -const { SQLHelper, SSLMode, SQLResultArray } = require("internal/sql/shared"); +import type { ArrayType, DatabaseAdapter, SQLArrayParameter, SQLHelper, SQLResultArray, SSLMode } from "./shared"; +const { SQLHelper, SSLMode, SQLResultArray, SQLArrayParameter } = require("internal/sql/shared"); const { Query, SQLQueryFlags, symbols: { _strings, _values, _flags, _results, _handle }, } = require("internal/sql/query"); +function isTypedArray(value: any) { + // Buffer should be treated as a normal object + // Typed arrays should be treated like an array + return ArrayBuffer.isView(value) && !Buffer.isBuffer(value); +} + const { PostgresError } = require("internal/sql/errors"); const { @@ -17,6 +23,203 @@ const { const cmds = ["", "INSERT", "DELETE", "UPDATE", "MERGE", "SELECT", "MOVE", "FETCH", "COPY"]; +const escapeBackslash = /\\/g; +const escapeQuote = /"/g; + +function arrayEscape(value: string) { + return value.replace(escapeBackslash, "\\\\").replace(escapeQuote, '\\"'); +} +const POSTGRES_ARRAY_TYPES = { + // Boolean + 1000: "BOOLEAN", // bool_array + + // Binary + 1001: "BYTEA", // bytea_array + + // Character types + 1002: "CHAR", // char_array + 1003: "NAME", // name_array + 1009: "TEXT", // text_array + 1014: "CHAR", // bpchar_array + 1015: "VARCHAR", // varchar_array + + // Numeric types + 1005: "SMALLINT", // int2_array + 1006: "INT2VECTOR", // int2vector_array + 1007: "INTEGER", // int4_array + 1016: "BIGINT", // int8_array + 1021: "REAL", // float4_array + 1022: "DOUBLE PRECISION", // float8_array + 1231: "NUMERIC", // numeric_array + 791: "MONEY", // money_array + + // OID types + 1028: "OID", // oid_array + 1010: "TID", // tid_array + 1011: "XID", // xid_array + 1012: "CID", // cid_array + + // JSON types + 199: "JSON", // json_array + 3802: "JSONB", // jsonb (not array) + 3807: "JSONB", // jsonb_array + 4072: "JSONPATH", // jsonpath + 4073: "JSONPATH", // jsonpath_array + + // XML + 143: "XML", // xml_array + + // Geometric types + 1017: "POINT", // point_array + 1018: "LSEG", // lseg_array + 1019: "PATH", // path_array + 1020: "BOX", // box_array + 1027: "POLYGON", // polygon_array + 629: "LINE", // line_array + 719: "CIRCLE", // circle_array + + // Network types + 651: "CIDR", // cidr_array + 1040: "MACADDR", // macaddr_array + 1041: "INET", // inet_array + 775: "MACADDR8", // macaddr8_array + + // Date/Time types + 1182: "DATE", // date_array + 1183: "TIME", // time_array + 1115: "TIMESTAMP", // timestamp_array + 1185: "TIMESTAMPTZ", // timestamptz_array + 1187: "INTERVAL", // interval_array + 1270: "TIMETZ", // timetz_array + + // Bit string types + 1561: "BIT", // bit_array + 1563: "VARBIT", // varbit_array + + // ACL + 1034: "ACLITEM", // aclitem_array + + // System catalog types + 12052: "PG_DATABASE", // pg_database_array + 10052: "PG_DATABASE", // pg_database_array2 +}; + +function isPostgresNumericType(type: string) { + switch (type) { + case "BIT": // bit_array + case "VARBIT": // varbit_array + case "SMALLINT": // int2_array + case "INT2VECTOR": // int2vector_array + case "INTEGER": // int4_array + case "INT": // int4_array + case "BIGINT": // int8_array + case "REAL": // float4_array + case "DOUBLE PRECISION": // float8_array + case "NUMERIC": // numeric_array + case "MONEY": // money_array + return true; + default: + return false; + } +} +function isPostgresJsonType(type: string) { + switch (type) { + case "JSON": + case "JSONB": + return true; + default: + return false; + } +} +function getPostgresArrayType(typeId: number) { + return POSTGRES_ARRAY_TYPES[typeId] || null; +} + +function arrayValueSerializer(type: ArrayType, is_numeric: boolean, is_json: boolean, value: any) { + // we do minimal to none type validation, we just try to format nicely and let the server handle if is valid SQL + // postgres will try to convert string -> array type + // postgres will emit a nice error saying what value dont have the expected format outputing the value in the error + if ($isArray(value) || isTypedArray(value)) { + if (!value.length) return "{}"; + const delimiter = type === "BOX" ? ";" : ","; + return `{${value.map(arrayValueSerializer.bind(this, type, is_numeric, is_json)).join(delimiter)}}`; + } + + switch (typeof value) { + case "undefined": + return "null"; + case "string": + if (is_json) { + return `"${arrayEscape(JSON.stringify(value))}"`; + } + return `"${arrayEscape(value)}"`; + + case "bigint": + case "number": + if (is_numeric || is_json) { + return "" + value; + } + return `"${value}"`; + case "boolean": + switch (type) { + case "BOOLEAN": + return value === true ? "t" : "f"; + case "JSON": + case "JSONB": + return value === true ? "true" : "false"; + default: + if (is_numeric) { + // convert to int if is a numeric array + return "" + (value ? 1 : 0); + } + // fallback to string + return value === true ? '"true"' : '"false"'; + } + default: + if (value instanceof Date) { + const isoValue = value.toISOString(); + if (is_json) { + return `"${arrayEscape(JSON.stringify(isoValue))}"`; + } + return `"${arrayEscape(isoValue)}"`; + } + if (Buffer.isBuffer(value)) { + const hexValue = value.toString("hex"); + // bytea array + if (type === "BYTEA") { + return `"\\x${arrayEscape(hexValue)}"`; + } + if (is_json) { + return `"${arrayEscape(JSON.stringify(hexValue))}"`; + } + return `"${arrayEscape(hexValue)}"`; + } + // fallback to JSON.stringify + return `"${arrayEscape(JSON.stringify(value))}"`; + } +} +function getArrayType(typeNameOrID: number | ArrayType | undefined = undefined): ArrayType { + const typeOfType = typeof typeNameOrID; + if (typeOfType === "number") { + return getPostgresArrayType(typeNameOrID as number) ?? "JSON"; + } + if (typeOfType === "string") { + return (typeNameOrID as string)?.toUpperCase(); + } + // default to JSON so we accept most of the types + return "JSON"; +} +function serializeArray(values: any[], type: ArrayType) { + if (!$isArray(values) && !isTypedArray(values)) return values; + + if (!values.length) return "{}"; + + // Only _box (1020) has the ';' delimiter for arrays, all other types use the ',' delimiter + const delimiter = type === "BOX" ? ";" : ","; + + return `{${values.map(arrayValueSerializer.bind(this, type, isPostgresNumericType(type), isPostgresJsonType(type))).join(delimiter)}}`; +} + function wrapPostgresError(error: Error | PostgresErrorOptions) { if (Error.isError(error)) { return error; @@ -572,6 +775,11 @@ class PostgresAdapter } } + array(values: any[], typeNameOrID?: number | ArrayType): SQLArrayParameter { + const arrayType = getArrayType(typeNameOrID); + return new SQLArrayParameter(serializeArray(values, arrayType), arrayType); + } + getTransactionCommands(options?: string): import("./shared").TransactionCommands { let BEGIN = "BEGIN"; if (options) { @@ -1015,6 +1223,11 @@ class PostgresAdapter } normalizeQuery(strings: string | TemplateStringsArray, values: unknown[], binding_idx = 1): [string, unknown[]] { + // This function handles array values in single fields: + // - JSON/JSONB are the only field types that can be arrays themselves, so we serialize them + // - SQL array field types (e.g., INTEGER[], TEXT[]) require the sql.array() helper + // - All other types are handled natively + if (typeof strings === "string") { // identifier or unsafe query return [strings, values || []]; @@ -1089,6 +1302,8 @@ class PostgresAdapter query += `$${binding_idx++}${k < lastColumnIndex ? ", " : ""}`; if (typeof columnValue === "undefined") { binding_values.push(null); + } else if ($isArray(columnValue)) { + binding_values.push(serializeArray(columnValue, "JSON")); } else { binding_values.push(columnValue); } @@ -1108,6 +1323,12 @@ class PostgresAdapter query += `$${binding_idx++}${j < lastColumnIndex ? ", " : ""}`; if (typeof columnValue === "undefined") { binding_values.push(null); + } else if ($isArray(columnValue)) { + // Handle array values in single fields: + // - JSON/JSONB fields can be an array + // - For dedicated SQL array field types (e.g., INTEGER[], TEXT[]), + // users should use the sql.array() helper instead + binding_values.push(serializeArray(columnValue, "JSON")); } else { binding_values.push(columnValue); } @@ -1139,6 +1360,8 @@ class PostgresAdapter if (typeof value_from_key === "undefined") { binding_values.push(null); + } else if ($isArray(value_from_key)) { + binding_values.push(serializeArray(value_from_key, "JSON")); } else { binding_values.push(value_from_key); } @@ -1147,6 +1370,8 @@ class PostgresAdapter const value = items[j]; if (typeof value === "undefined") { binding_values.push(null); + } else if ($isArray(value)) { + binding_values.push(serializeArray(value, "JSON")); } else { binding_values.push(value); } @@ -1175,18 +1400,28 @@ class PostgresAdapter if (typeof columnValue === "undefined") { binding_values.push(null); } else { - binding_values.push(columnValue); + if ($isArray(columnValue)) { + binding_values.push(serializeArray(columnValue, "JSON")); + } else { + binding_values.push(columnValue); + } } } query += " "; // the user can add where clause after this } + } else if (value instanceof SQLArrayParameter) { + query += `$${binding_idx++}::${value.arrayType}[] `; + binding_values.push(value.serializedValues); } else { - //TODO: handle sql.array parameters query += `$${binding_idx++} `; if (typeof value === "undefined") { binding_values.push(null); } else { - binding_values.push(value); + if ($isArray(value)) { + binding_values.push(serializeArray(value, "JSON")); + } else { + binding_values.push(value); + } } } } diff --git a/src/js/internal/sql/shared.ts b/src/js/internal/sql/shared.ts index ea16b2d978..85748fcb55 100644 --- a/src/js/internal/sql/shared.ts +++ b/src/js/internal/sql/shared.ts @@ -7,7 +7,69 @@ declare global { } } -export type { SQLResultArray }; +type ArrayType = + | "BOOLEAN" + | "BYTEA" + | "CHAR" + | "NAME" + | "TEXT" + | "CHAR" + | "VARCHAR" + | "SMALLINT" + | "INT2VECTOR" + | "INTEGER" + | "INT" + | "BIGINT" + | "REAL" + | "DOUBLE PRECISION" + | "NUMERIC" + | "MONEY" + | "OID" + | "TID" + | "XID" + | "CID" + | "JSON" + | "JSONB" + | "JSONPATH" + | "XML" + | "POINT" + | "LSEG" + | "PATH" + | "BOX" + | "POLYGON" + | "LINE" + | "CIRCLE" + | "CIDR" + | "MACADDR" + | "INET" + | "MACADDR8" + | "DATE" + | "TIME" + | "TIMESTAMP" + | "TIMESTAMPTZ" + | "INTERVAL" + | "TIMETZ" + | "BIT" + | "VARBIT" + | "ACLITEM" + | "PG_DATABASE" + | (string & {}); +export type { ArrayType, SQLArrayParameter, SQLResultArray }; +class SQLArrayParameter { + serializedValues: string; + arrayType: ArrayType; + constructor(serializedValues: string, arrayType: ArrayType) { + this.serializedValues = serializedValues; + this.arrayType = arrayType; + } + toString() { + return this.serializedValues; + } + toJSON() { + return this.serializedValues; + } +} + class SQLResultArray extends PublicArray { public count!: number | null; public command!: string | null; @@ -828,6 +890,7 @@ export interface DatabaseAdapter { detachConnectionCloseHandler?(connection: Connection, handler: () => void): void; getTransactionCommands(options?: string): TransactionCommands; + array(values: any[], typeNameOrID?: number | string): SQLArrayParameter; getDistributedTransactionCommands?(name: string): TransactionCommands | null; validateTransactionOptions?(options: string): { valid: boolean; error?: string }; @@ -850,7 +913,7 @@ export default { SQLHelper, normalizeSSLMode, SQLResultArray, - + SQLArrayParameter, // @ts-expect-error we're exporting a const enum which works in our builtins // generator but not in typescript officially SSLMode, diff --git a/src/js/internal/sql/sqlite.ts b/src/js/internal/sql/sqlite.ts index 8e1c944438..a123380091 100644 --- a/src/js/internal/sql/sqlite.ts +++ b/src/js/internal/sql/sqlite.ts @@ -1,6 +1,6 @@ import type * as BunSQLiteModule from "bun:sqlite"; import type { BaseQueryHandle, Query, SQLQueryResultMode } from "./query"; -import type { DatabaseAdapter, OnConnected, SQLHelper, SQLResultArray } from "./shared"; +import type { ArrayType, DatabaseAdapter, OnConnected, SQLArrayParameter, SQLHelper, SQLResultArray } from "./shared"; const { SQLHelper, SQLResultArray } = require("internal/sql/shared"); const { @@ -735,7 +735,9 @@ class SQLiteAdapter implements DatabaseAdapter { + test("SQL heper should support sql.array", async () => { + await using sql = postgres(options); + const random_name = "test_" + randomUUIDv7("hex").replaceAll("-", ""); + await sql`CREATE TEMPORARY TABLE ${sql(random_name)} ( + id SERIAL PRIMARY KEY, + name VARCHAR NOT NULL, + roles TEXT[] + );`; + + const [{ id, name, roles }] = + await sql`insert into ${sql(random_name)} (name, roles) values (${"test"}, ${sql.array(["a", "b"], "TEXT")}) returning *`; + + expect(id).toBe(1); + expect(name).toBe("test"); + expect(roles).toEqual(["a", "b"]); + + const [{ id: update_id, name: update_name, roles: update_roles }] = + await sql`UPDATE ${sql(random_name)} SET ${sql({ name: "test2", roles: sql.array(["c", "d"], "TEXT") })} WHERE id = ${id} RETURNING *`; + expect(update_id).toBe(1); + expect(update_name).toBe("test2"); + expect(update_roles).toEqual(["c", "d"]); + }); + + test("sql.array should support jsonb and json", async () => { + await using sql = postgres(options); + { + const [{ x }] = await sql`select ${sql.array([{ a: 1 }, { b: 2 }], "JSONB")} as x`; + expect(x).toEqual([{ a: 1 }, { b: 2 }]); + } + { + const [{ x }] = await sql`select ${sql.array([{ a: 1 }, { b: 2 }], "JSON")} as x`; + expect(x).toEqual([{ a: 1 }, { b: 2 }]); + } + + { + // should handle most common types properly + const date = new Date(Date.UTC(2025, 1, 1)); + const buffer = Buffer.from([0x00, 0x01, 0x02, 0x03, 0x04]); + const [{ x }] = + await sql`select ${sql.array([date, 1n, 1, 1.1, true, false, null, undefined, "hello", buffer], "JSON")} as x`; + expect(x).toEqual([date.toISOString(), 1, 1, 1.1, true, false, null, null, "hello", buffer.toString("hex")]); + } + }); + + test("should be able to insert array in jsonb fields", async () => { + await using sql = postgres(options); + const random_name = "test_" + randomUUIDv7("hex").replaceAll("-", ""); + await sql`CREATE TEMPORARY TABLE ${sql(random_name)} ( + id SERIAL PRIMARY KEY, + json JSONB + );`; + + await sql`insert into ${sql(random_name)} (json) values (${["a", "b"]})`; + const [{ id, json }] = await sql`select * from ${sql(random_name)}`; + + expect(id).toBe(1); + // TODO: we should properly parse the jsonb values here but we are returning the string as is + // internally we are probably trying to JSON.parse the string but it fails because of the array format is different + expect(json).toEqual('{"\\"a\\"","\\"b\\""}'); + }); + test("should be able to insert array in fields", async () => { + await using sql = postgres(options); + const random_name = "test_" + randomUUIDv7("hex").replaceAll("-", ""); + await sql`CREATE TEMPORARY TABLE ${sql(random_name)} ( + id SERIAL PRIMARY KEY, + json JSON + );`; + + await sql`insert into ${sql(random_name)} (json) values (${["a", "b"]})`; + const [{ id, json }] = await sql`select * from ${sql(random_name)}`; + expect(id).toBe(1); + // TODO: we should properly parse the jsonb values here + // internally we are probably trying to JSON.parse the string but it fails because of the array format is different + expect(json).toEqual('{"\\"a\\"","\\"b\\""}'); + }); + + test("sql.array should support TEXT arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array(["hello", "world", "test"], "TEXT")} as x`; + expect(x).toEqual(["hello", "world", "test"]); + }); + + test("sql.array should support BOOLEAN arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array([true, false, true], "BOOLEAN")} as x`; + expect(x).toEqual([true, false, true]); + }); + + test("sql.array should support SMALLINT arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array([1, 2, 3, -32768, 32767], "SMALLINT")} as x`; + expect(x).toEqual([1, 2, 3, -32768, 32767]); + }); + + test("sql.array should support INTEGER arrays", async () => { + await using sql = postgres(options); + + { + const [{ x }] = await sql`select ${sql.array([100000, -2147483648, 2147483647], "INT")} as x`; + expect(x).toEqual(new Int32Array([100000, -2147483648, 2147483647])); + } + { + const [{ x }] = + await sql`select ${sql.array(Int32Array.from([100000, -2147483648, 2147483647]), "INT")} as x`; + expect(x).toEqual(new Int32Array([100000, -2147483648, 2147483647])); + } + }); + + test("sql.array should support BIGINT arrays", async () => { + await using sql = postgres(options); + + const bigints = [1n, 9999999999n, -9999999999n, 2147483648n]; + const [{ x }] = await sql`select ${sql.array(bigints, "BIGINT")} as x`; + expect(x).toEqual(bigints.map(n => n.toString())); + }); + + test("sql.array should support REAL (float4) arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array([1.5, 2.7, -3.14], "REAL")} as x`; + expect(x[0]).toBeCloseTo(1.5); + expect(x[1]).toBeCloseTo(2.7); + expect(x[2]).toBeCloseTo(-3.14); + }); + + test("sql.array should support DOUBLE PRECISION (float8) arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array([1.123456789, 2.987654321, Math.PI], "DOUBLE PRECISION")} as x`; + expect(x[0]).toBeCloseTo(1.123456789); + expect(x[1]).toBeCloseTo(2.987654321); + expect(x[2]).toBeCloseTo(Math.PI); + }); + + test("sql.array should support NUMERIC arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = + await sql`select ${sql.array([1.1, 2.22, 333.333, "99999999999999999999.9999"], "NUMERIC")} as x`; + expect(x).toEqual(["1.1", "2.22", "333.333", "99999999999999999999.9999"]); + }); + + test("sql.array should support DATE arrays", async () => { + await using sql = postgres(options); + + const date1 = new Date("2025-01-01"); + const date2 = new Date("2025-12-31"); + const [{ x }] = await sql`select ${sql.array([date1, date2], "DATE")} as x`; + expect(x[0]).toEqual(date1); + expect(x[1]).toEqual(date2); + }); + + test("sql.array should support TIMESTAMP arrays", async () => { + await using sql = postgres(options); + + const ts1 = new Date("2025-01-01T12:30:45"); + const ts2 = new Date("2025-06-15T18:45:30"); + const [{ x }] = await sql`select ${sql.array([ts1, ts2], "TIMESTAMP")} as x`; + expect(new Date(x[0])).toEqual(ts1); + expect(new Date(x[1])).toEqual(ts2); + }); + + test("sql.array should support TIMESTAMPTZ arrays", async () => { + await using sql = postgres(options); + + const ts1 = new Date(Date.UTC(2025, 0, 1, 10, 30, 0)); + const ts2 = new Date(Date.UTC(2025, 5, 15, 20, 45, 0)); + const [{ x }] = await sql`select ${sql.array([ts1, ts2], "TIMESTAMPTZ")} as x`; + expect(new Date(x[0])).toEqual(ts1); + expect(new Date(x[1])).toEqual(ts2); + }); + + test("sql.array should support TIME arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array(["12:30:45", "18:45:30", "00:00:00"], "TIME")} as x`; + expect(x).toEqual(["12:30:45", "18:45:30", "00:00:00"]); + }); + + test("sql.array should support INTERVAL arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array(["1 day", "2 hours", "30 minutes"], "INTERVAL")} as x`; + expect(x).toEqual(["1 day", "02:00:00", "00:30:00"]); + }); + + test("sql.array should support UUID arrays", async () => { + await using sql = postgres(options); + + const uuids = ["123e4567-e89b-12d3-a456-426614174000", "550e8400-e29b-41d4-a716-446655440000"]; + const [{ x }] = await sql`select ${sql.array(uuids, "UUID")} as x`; + // TODO: we should parse it as an array of UUIDs + expect(x).toEqual("{123e4567-e89b-12d3-a456-426614174000,550e8400-e29b-41d4-a716-446655440000}"); + }); + + test("sql.array should support INET arrays", async () => { + await using sql = postgres(options); + + const ips = ["192.168.1.1", "10.0.0.1", "::1", "2001:db8::1"]; + const [{ x }] = await sql`select ${sql.array(ips, "INET")} as x`; + expect(x).toEqual(ips); + }); + + test("sql.array should support CIDR arrays", async () => { + await using sql = postgres(options); + + const cidrs = ["192.168.1.0/24", "10.0.0.0/8", "2001:db8::/32"]; + const [{ x }] = await sql`select ${sql.array(cidrs, "CIDR")} as x`; + expect(x).toEqual(cidrs); + }); + + test("sql.array should support MACADDR arrays", async () => { + await using sql = postgres(options); + + const macs = ["08:00:27:01:02:03", "aa:bb:cc:dd:ee:ff"]; + const [{ x }] = await sql`select ${sql.array(macs, "MACADDR")} as x`; + expect(x).toEqual(macs); + }); + + test("sql.array should support BIT arrays", async () => { + await using sql = postgres(options); + + const bits = ["101", "1111", "0000"]; + const [{ x }] = await sql`select ${sql.array(bits, "BIT")} as x`; + expect(x).toEqual(["1", "1", "0"]); + }); + + test("sql.array should support VARBIT arrays", async () => { + await using sql = postgres(options); + + const varbits = ["1", "101010", "11111111"]; + const [{ x }] = await sql`select ${sql.array(varbits, "VARBIT")} as x`; + expect(x).toEqual(varbits); + }); + + test("sql.array should support MONEY arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array(["$1.50", "$999.99", "-$50.00"], "MONEY")} as x`; + expect(x).toEqual(["$1.50", "$999.99", "-$50.00"]); + }); + + test("sql.array should support CHAR arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array(["a", "b", "c"], "CHAR")} as x`; + expect(x).toEqual(["a", "b", "c"]); + }); + + test("sql.array should support VARCHAR arrays", async () => { + await using sql = postgres(options); + + const [{ x }] = await sql`select ${sql.array(["hello", "world", "test"], "VARCHAR")} as x`; + expect(x).toEqual(["hello", "world", "test"]); + }); + + test("sql.array should support geometric types", async () => { + await using sql = postgres(options); + + // POINT arrays + const points = ["(1,2)", "(3.5,4.5)", "(-1,-2)"]; + const [{ p }] = await sql`select ${sql.array(points, "POINT")} as p`; + expect(p).toEqual(points); + + // BOX arrays + const boxes = ["((0,0),(1,1))", "((2,2),(4,4))"]; + const [{ b }] = await sql`select ${sql.array(boxes, "BOX")} as b`; + expect(b.length).toBe(2); + + // CIRCLE arrays + const circles = ["<(0,0),5>", "<(10,10),2.5>"]; + const [{ c }] = await sql`select ${sql.array(circles, "CIRCLE")} as c`; + expect(c.length).toBe(2); + }); + + test("sql.array should handle mixed types with explicit casting", async () => { + await using sql = postgres(options); + + // Everything gets cast to the specified type + const date = new Date(); + const mixed = [1, "2", 3.5, date]; + const [{ x }] = await sql`select ${sql.array(mixed, "TEXT")} as x`; + expect(x).toEqual(["1", "2", "3.5", date.toISOString()]); + }); + }); + describe("Time/TimeZ", () => { test("PostgreSQL TIME and TIMETZ types are handled correctly", async () => { const db = postgres(options);