Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix: json and jsonb parsing in postgres-js #1785

Merged
merged 10 commits into from
Aug 6, 2024
2 changes: 2 additions & 0 deletions drizzle-orm/src/postgres-js/driver.ts
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,8 @@ export function drizzle<TSchema extends Record<string, unknown> = Record<string,
client.options.parsers[type as any] = transparentParser;
client.options.serializers[type as any] = transparentParser;
}
client.options.serializers['114'] = transparentParser;
client.options.serializers['3802'] = transparentParser;

const dialect = new PgDialect();
let logger;
Expand Down
157 changes: 157 additions & 0 deletions integration-tests/tests/pg/pg-common.ts
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,7 @@ import {
intersect,
intersectAll,
interval,
json,
jsonb,
macaddr,
macaddr8,
Expand Down Expand Up @@ -199,6 +200,12 @@ const users2MySchemaTable = mySchema.table('users2', {
cityId: integer('city_id').references(() => citiesTable.id),
});

const jsonTestTable = pgTable('jsontest', {
id: serial('id').primaryKey(),
json: json('json').$type<{ string: string; number: number }>(),
jsonb: jsonb('jsonb').$type<{ string: string; number: number }>(),
});

let pgContainer: Docker.Container;

export async function createDockerDB(): Promise<{ connectionString: string; container: Docker.Container }> {
Expand Down Expand Up @@ -358,6 +365,16 @@ export function tests() {
)
`,
);

await db.execute(
sql`
create table jsontest (
id serial primary key,
json json,
jsonb jsonb
)
`,
);
});

async function setupSetOperationTest(db: PgDatabase<PgQueryResultHKT>) {
Expand Down Expand Up @@ -4481,5 +4498,145 @@ export function tests() {

expect(users.length).toBeGreaterThan(0);
});

test('proper json and jsonb handling', async (ctx) => {
const { db } = ctx.pg;

const jsonTable = pgTable('json_table', {
json: json('json').$type<{ name: string; age: number }>(),
jsonb: jsonb('jsonb').$type<{ name: string; age: number }>(),
});

await db.execute(sql`drop table if exists ${jsonTable}`);

await db.execute(sql`create table ${jsonTable} (json json, jsonb jsonb)`);

await db.insert(jsonTable).values({ json: { name: 'Tom', age: 75 }, jsonb: { name: 'Pete', age: 23 } });

const result = await db.select().from(jsonTable);

const justNames = await db.select({
name1: sql<string>`${jsonTable.json}->>'name'`.as('name1'),
name2: sql<string>`${jsonTable.jsonb}->>'name'`.as('name2'),
}).from(jsonTable);

expect(result).toStrictEqual([
{
json: { name: 'Tom', age: 75 },
jsonb: { name: 'Pete', age: 23 },
},
]);

expect(justNames).toStrictEqual([
{
name1: 'Tom',
name2: 'Pete',
},
]);
});

test('set json/jsonb fields with objects and retrieve with the ->> operator', async (ctx) => {
const { db } = ctx.pg;

const obj = { string: 'test', number: 123 };
const { string: testString, number: testNumber } = obj;

await db.insert(jsonTestTable).values({
json: obj,
jsonb: obj,
});

const result = await db.select({
jsonStringField: sql<string>`${jsonTestTable.json}->>'string'`,
jsonNumberField: sql<string>`${jsonTestTable.json}->>'number'`,
jsonbStringField: sql<string>`${jsonTestTable.jsonb}->>'string'`,
jsonbNumberField: sql<string>`${jsonTestTable.jsonb}->>'number'`,
}).from(jsonTestTable);

expect(result).toStrictEqual([{
jsonStringField: testString,
jsonNumberField: String(testNumber),
jsonbStringField: testString,
jsonbNumberField: String(testNumber),
}]);
});

test('set json/jsonb fields with strings and retrieve with the ->> operator', async (ctx) => {
const { db } = ctx.pg;

const obj = { string: 'test', number: 123 };
const { string: testString, number: testNumber } = obj;

await db.insert(jsonTestTable).values({
json: sql`${JSON.stringify(obj)}`,
jsonb: sql`${JSON.stringify(obj)}`,
});

const result = await db.select({
jsonStringField: sql<string>`${jsonTestTable.json}->>'string'`,
jsonNumberField: sql<string>`${jsonTestTable.json}->>'number'`,
jsonbStringField: sql<string>`${jsonTestTable.jsonb}->>'string'`,
jsonbNumberField: sql<string>`${jsonTestTable.jsonb}->>'number'`,
}).from(jsonTestTable);

expect(result).toStrictEqual([{
jsonStringField: testString,
jsonNumberField: String(testNumber),
jsonbStringField: testString,
jsonbNumberField: String(testNumber),
}]);
});

test('set json/jsonb fields with objects and retrieve with the -> operator', async (ctx) => {
const { db } = ctx.pg;

const obj = { string: 'test', number: 123 };
const { string: testString, number: testNumber } = obj;

await db.insert(jsonTestTable).values({
json: obj,
jsonb: obj,
});

const result = await db.select({
jsonStringField: sql<string>`${jsonTestTable.json}->'string'`,
jsonNumberField: sql<number>`${jsonTestTable.json}->'number'`,
jsonbStringField: sql<string>`${jsonTestTable.jsonb}->'string'`,
jsonbNumberField: sql<number>`${jsonTestTable.jsonb}->'number'`,
}).from(jsonTestTable);

expect(result).toStrictEqual([{
jsonStringField: testString,
jsonNumberField: testNumber,
jsonbStringField: testString,
jsonbNumberField: testNumber,
}]);
});

test('set json/jsonb fields with strings and retrieve with the -> operator', async (ctx) => {
const { db } = ctx.pg;

const obj = { string: 'test', number: 123 };
const { string: testString, number: testNumber } = obj;

await db.insert(jsonTestTable).values({
json: sql`${JSON.stringify(obj)}`,
jsonb: sql`${JSON.stringify(obj)}`,
});

const result = await db.select({
jsonStringField: sql<string>`${jsonTestTable.json}->'string'`,
jsonNumberField: sql<number>`${jsonTestTable.json}->'number'`,
jsonbStringField: sql<string>`${jsonTestTable.jsonb}->'string'`,
jsonbNumberField: sql<number>`${jsonTestTable.jsonb}->'number'`,
}).from(jsonTestTable);

expect(result).toStrictEqual([{
jsonStringField: testString,
jsonNumberField: testNumber,
jsonbStringField: testString,
jsonbNumberField: testNumber,
}]);
});
});
}