feat: add support for jsonpath column type in PostgreSQL (#11684)

This commit is contained in:
Piotr Kuczynski 2025-09-26 18:56:53 +02:00 committed by GitHub
parent e0e7de14ca
commit 4f05718237
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
7 changed files with 88 additions and 1 deletions

View File

@ -60,7 +60,7 @@ Additional options can be added to the `extra` object and will be passed directl
### Column types for `postgres`
`int`, `int2`, `int4`, `int8`, `smallint`, `integer`, `bigint`, `decimal`, `numeric`, `real`, `float`, `float4`, `float8`, `double precision`, `money`, `character varying`, `varchar`, `character`, `char`, `text`, `citext`, `hstore`, `bytea`, `bit`, `varbit`, `bit varying`, `timetz`, `timestamptz`, `timestamp`, `timestamp without time zone`, `timestamp with time zone`, `date`, `time`, `time without time zone`, `time with time zone`, `interval`, `bool`, `boolean`, `enum`, `point`, `line`, `lseg`, `box`, `path`, `polygon`, `circle`, `cidr`, `inet`, `macaddr`, `macaddr8`, `tsvector`, `tsquery`, `uuid`, `xml`, `json`, `jsonb`, `int4range`, `int8range`, `numrange`, `tsrange`, `tstzrange`, `daterange`, `int4multirange`, `int8multirange`, `nummultirange`, `tsmultirange`, `tstzmultirange`, `multidaterange`, `geometry`, `geography`, `cube`, `ltree`
`int`, `int2`, `int4`, `int8`, `smallint`, `integer`, `bigint`, `decimal`, `numeric`, `real`, `float`, `float4`, `float8`, `double precision`, `money`, `character varying`, `varchar`, `character`, `char`, `text`, `citext`, `hstore`, `bytea`, `bit`, `varbit`, `bit varying`, `timetz`, `timestamptz`, `timestamp`, `timestamp without time zone`, `timestamp with time zone`, `date`, `time`, `time without time zone`, `time with time zone`, `interval`, `bool`, `boolean`, `enum`, `point`, `line`, `lseg`, `box`, `path`, `polygon`, `circle`, `cidr`, `inet`, `macaddr`, `macaddr8`, `tsvector`, `tsquery`, `uuid`, `xml`, `json`, `jsonb`, `jsonpath`, `int4range`, `int8range`, `numrange`, `tsrange`, `tstzrange`, `daterange`, `int4multirange`, `int8multirange`, `nummultirange`, `tsmultirange`, `tstzmultirange`, `multidaterange`, `geometry`, `geography`, `cube`, `ltree`
### Column types for `cockroachdb`

View File

@ -175,6 +175,7 @@ export class PostgresDriver implements Driver {
"xml",
"json",
"jsonb",
"jsonpath",
"int4range",
"int8range",
"numrange",

View File

@ -203,6 +203,7 @@ export type SimpleColumnType =
| "xml" // mssql, postgres
| "json" // mysql, postgres, cockroachdb, spanner
| "jsonb" // postgres, cockroachdb
| "jsonpath" // postgres
| "varbinary" // mssql, sap
| "hierarchyid" // mssql
| "sql_variant" // mssql

View File

@ -92,6 +92,7 @@ describe("database schema > column types > postgres", () => {
post.uuid = "0e37df36-f698-11e6-8dd4-cb9ced3df976"
post.json = { id: 1, name: "Post" }
post.jsonb = { id: 1, name: "Post" }
post.jsonpath = '$."name"'
post.int4range = "[10,20)"
post.int8range = "[200000,500000)"
post.numrange = "(10.5,20.2)"
@ -186,6 +187,7 @@ describe("database schema > column types > postgres", () => {
loadedPost.uuid.should.be.equal(post.uuid)
loadedPost.json.should.be.eql(post.json)
loadedPost.jsonb.should.be.eql(post.jsonb)
loadedPost.jsonpath.should.be.eql(post.jsonpath)
loadedPost.int4range.should.be.eql(post.int4range)
loadedPost.int8range.should.be.eql(post.int8range)
loadedPost.numrange.should.be.eql(post.numrange)
@ -324,6 +326,9 @@ describe("database schema > column types > postgres", () => {
table!.findColumnByName("xml")!.type.should.be.equal("xml")
table!.findColumnByName("json")!.type.should.be.equal("json")
table!.findColumnByName("jsonb")!.type.should.be.equal("jsonb")
table!
.findColumnByName("jsonpath")!
.type.should.be.equal("jsonpath")
table!
.findColumnByName("int4range")!
.type.should.be.equal("int4range")

View File

@ -0,0 +1,12 @@
import { Entity } from "../../../../../../src/decorator/entity/Entity"
import { PrimaryGeneratedColumn } from "../../../../../../src/decorator/columns/PrimaryGeneratedColumn"
import { Column } from "../../../../../../src/decorator/columns/Column"
@Entity()
export class JsonPathExample {
@PrimaryGeneratedColumn()
id: number
@Column({ type: "jsonpath" })
path: string
}

View File

@ -215,6 +215,9 @@ export class Post {
@Column("jsonb")
jsonb: object
@Column("jsonpath")
jsonpath: string
// -------------------------------------------------------------------------
// Range Type
// -------------------------------------------------------------------------

View File

@ -0,0 +1,65 @@
import "reflect-metadata"
import { JsonPathExample } from "./entity/JsonPathExample"
import { DataSource } from "../../../../../src/data-source/DataSource"
import {
closeTestingConnections,
createTestingConnections,
reloadTestingDatabases,
} from "../../../../utils/test-utils"
describe("database schema > column types > postgres > jsonpath", () => {
let connections: DataSource[]
before(async () => {
connections = await createTestingConnections({
entities: [__dirname + "/entity/*{.js,.ts}"],
enabledDrivers: ["postgres"],
})
})
beforeEach(() => reloadTestingDatabases(connections))
after(() => closeTestingConnections(connections))
// Based on:
// * https://www.postgresql.org/docs/current/datatype-json.html#DATATYPE-JSONPATH
// * https://www.postgresql.org/docs/current/functions-json.html#FUNCTIONS-SQLJSON-PATH
;[
["$"], // the whole JSON document (context item)
["$foo", `$"foo"`], // variable "foo"
['"bar"'], // string literal
["12.345"], // numeric literal
["true"], // boolean literal
["null"], // null
["$.floor", `$."floor"`], // field accessor on $
["$.floor[*]", `$."floor"[*]`], // the same, followed by wildcard array accessor
// complex path with filters and variables
[
"$.floor[*] ? (@.level < $max_level).apt[*] ? (@.area > $min_area).no",
`$."floor"[*]?(@."level" < $"max_level")."apt"[*]?(@."area" > $"min_area")."no"`,
],
// arithmetic expressions:
["-$.a[*]", `(-$."a"[*])`], // unary
["$.a + 3", `($."a" + 3)`], // binary
["2 * $.a - (3 / $.b + $x.y)", `(2 * $."a" - (3 / $."b" + $"x"."y"))`], // complex expression with variables
].forEach(([path, canonical]) => {
it(`should insert and retrieve jsonpath values as strings for: ${path}`, () =>
Promise.all(
connections.map(async (connection) => {
const repository = connection.getRepository(JsonPathExample)
const example = new JsonPathExample()
example.path = path
await repository.save(example)
const loaded = await repository.findOneByOrFail({
id: example.id,
})
loaded.path.should.be.equal(canonical ?? path)
}),
))
})
})