Skip to content

Commit

Permalink
feat(core): allow querying by JSON properties
Browse files Browse the repository at this point in the history
We can query by JSON object properties easily:

```ts
const b = await em.findOne(Book, {
  meta: {
    valid: true,
    nested: {
      foo: '123',
      bar: 321,
      deep: {
        baz: 59,
        qux: false,
      },
    },
  },
});
```

Will produce following query (in postgres):

```sql
select "e0".*
from "book" as "e0"
where ("meta"->>'valid')::bool = true
  and "meta"->'nested'->>'foo' = '123'
  and ("meta"->'nested'->>'bar')::float8 = 321
  and ("meta"->'nested'->'deep'->>'baz')::float8 = 59
  and ("meta"->'nested'->'deep'->>'qux')::bool = false
limit 1
```

> All drivers are currently supported (including sqlite and mongo). In postgres we
> also try to cast the value if we detect number or boolean on the right-hand side.

Closes #1359
Related: #1261
  • Loading branch information
B4nan committed Feb 2, 2021
1 parent 7b8e37b commit b8da7be
Show file tree
Hide file tree
Showing 18 changed files with 263 additions and 24 deletions.
57 changes: 57 additions & 0 deletions docs/docs/json-properties.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
---
title: Using JSON properties
---

## Defining JSON properties

Each database driver behaves a bit differently when it comes to JSON properties.
MikroORM tries to unify the experience via [JsonType](custom-types.md#jsontype).
This type will be also used if you specify `type: 'json'`.

```ts
@Entity()
export class Book {

@Property({ type: 'json', nullable: true })
meta?: { foo: string; bar: number };

}
```

## Querying by JSON object properties

> Support for querying by JSON object properties was added in v4.4.2
We can query by JSON object properties easily:

```ts
const b = await em.findOne(Book, {
meta: {
valid: true,
nested: {
foo: '123',
bar: 321,
deep: {
baz: 59,
qux: false,
},
},
},
});
```

Will produce following query (in postgres):

```sql
select "e0".*
from "book" as "e0"
where ("meta"->>'valid')::bool = true
and "meta"->'nested'->>'foo' = '123'
and ("meta"->'nested'->>'bar')::float8 = 321
and ("meta"->'nested'->'deep'->>'baz')::float8 = 59
and ("meta"->'nested'->'deep'->>'qux')::bool = false
limit 1
```

> All drivers are currently supported (including sqlite and mongo). In postgres we
> also try to cast the value if we detect number or boolean on the right-hand side.
1 change: 1 addition & 0 deletions docs/sidebars.js
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@ module.exports = {
'custom-types',
'embeddables',
'entity-schema',
'json-properties',
'metadata-providers',
'metadata-cache',
'schema-generator',
Expand Down
57 changes: 57 additions & 0 deletions docs/versioned_docs/version-4.4/json-properties.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
---
title: Using JSON properties
---

## Defining JSON properties

Each database driver behaves a bit differently when it comes to JSON properties.
MikroORM tries to unify the experience via [JsonType](custom-types.md#jsontype).
This type will be also used if you specify `type: 'json'`.

```ts
@Entity()
export class Book {

@Property({ type: 'json', nullable: true })
meta?: { foo: string; bar: number };

}
```

## Querying by JSON object properties

> Support for querying by JSON object properties was added in v4.4.2
We can query by JSON object properties easily:

```ts
const b = await em.findOne(Book, {
meta: {
valid: true,
nested: {
foo: '123',
bar: 321,
deep: {
baz: 59,
qux: false,
},
},
},
});
```

Will produce following query (in postgres):

```sql
select "e0".*
from "book" as "e0"
where ("meta"->>'valid')::bool = true
and "meta"->'nested'->>'foo' = '123'
and ("meta"->'nested'->>'bar')::float8 = 321
and ("meta"->'nested'->'deep'->>'baz')::float8 = 59
and ("meta"->'nested'->'deep'->>'qux')::bool = false
limit 1
```

> All drivers are currently supported (including sqlite and mongo). In postgres we
> also try to cast the value if we detect number or boolean on the right-hand side.
4 changes: 4 additions & 0 deletions docs/versioned_sidebars/version-4.4-sidebars.json
Original file line number Diff line number Diff line change
Expand Up @@ -131,6 +131,10 @@
"type": "doc",
"id": "version-4.4/entity-schema"
},
{
"type": "doc",
"id": "version-4.4/json-properties"
},
{
"type": "doc",
"id": "version-4.4/metadata-providers"
Expand Down
2 changes: 1 addition & 1 deletion packages/core/src/metadata/MetadataDiscovery.ts
Original file line number Diff line number Diff line change
Expand Up @@ -602,7 +602,7 @@ export class MetadataDiscovery {
path.unshift(this.namingStrategy.propertyToColumnName(rootProperty.name));
path.push(prop.name);

meta.properties[name].fieldNameRaw = this.platform.getSearchJsonPropertySQL(path.join('->')); // for querying in SQL drivers
meta.properties[name].fieldNameRaw = this.platform.getSearchJsonPropertySQL(path.join('->'), prop.type); // for querying in SQL drivers
meta.properties[name].persist = false; // only virtual as we store the whole object
}

Expand Down
6 changes: 5 additions & 1 deletion packages/core/src/platforms/Platform.ts
Original file line number Diff line number Diff line change
Expand Up @@ -161,10 +161,14 @@ export abstract class Platform {
return 'json';
}

getSearchJsonPropertySQL(path: string): string {
getSearchJsonPropertySQL(path: string, type: string): string {
return path;
}

getSearchJsonPropertyKey(path: string[], type: string): string {
return path.join('.');
}

convertsJsonAutomatically(marshall = false): boolean {
return !marshall;
}
Expand Down
22 changes: 21 additions & 1 deletion packages/core/src/utils/QueryHelper.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import { AnyEntity, Dictionary, EntityMetadata, EntityProperty, FilterDef, Filte
import { ARRAY_OPERATORS, GroupOperator } from '../enums';
import { Platform } from '../platforms';
import { MetadataStorage } from '../metadata/MetadataStorage';
import { JsonType } from '../types';

export class QueryHelper {

Expand Down Expand Up @@ -118,6 +119,10 @@ export class QueryHelper {
value = QueryHelper.processCustomType(prop, value, platform, undefined, true);
}

if (prop?.customType instanceof JsonType && Utils.isPlainObject(value)) {
return this.processJsonCondition(o, value, [key], platform);
}

if (Array.isArray(value) && !Utils.isOperator(key) && !QueryHelper.isSupportedOperator(key) && !key.includes('?')) {
if (platform.allowsComparingTuples()) {
// comparing single composite key - use $eq instead of $in
Expand Down Expand Up @@ -193,7 +198,7 @@ export class QueryHelper {
static processCustomType<T>(prop: EntityProperty<T>, cond: FilterQuery<T>, platform: Platform, key?: string, fromQuery?: boolean): FilterQuery<T> {
if (Utils.isPlainObject(cond)) {
return Object.keys(cond).reduce((o, k) => {
if (Utils.isOperator(k, true) || prop.referencedPKs.includes(k)) {
if (Utils.isOperator(k, true) || prop.referencedPKs?.includes(k)) {
o[k] = QueryHelper.processCustomType(prop, cond[k], platform, k, fromQuery);
} else {
o[k] = cond[k];
Expand Down Expand Up @@ -236,6 +241,21 @@ export class QueryHelper {
return !!QueryHelper.SUPPORTED_OPERATORS.find(op => key.includes(op));
}

private static processJsonCondition<T>(o: FilterQuery<T>, value: Dictionary, path: string[], platform: Platform) {
if (Utils.isPlainObject(value)) {
Object.keys(value).forEach(k => {
this.processJsonCondition(o, value[k], [...path, k], platform);
});

return o;
}

const k = platform.getSearchJsonPropertyKey(path, typeof value);
o[k] = value;

return o;
}

}

export const expr = (sql: string) => sql;
4 changes: 4 additions & 0 deletions packages/knex/src/AbstractSqlPlatform.ts
Original file line number Diff line number Diff line change
Expand Up @@ -66,4 +66,8 @@ export abstract class AbstractSqlPlatform extends Platform {
return ret;
}

getSearchJsonPropertySQL(path: string, type: string): string {
return this.getSearchJsonPropertyKey(path.split('->'), type);
}

}
6 changes: 3 additions & 3 deletions packages/mysql-base/src/MySqlPlatform.ts
Original file line number Diff line number Diff line change
Expand Up @@ -11,9 +11,9 @@ export class MySqlPlatform extends AbstractSqlPlatform {
return 'utf8mb4';
}

getSearchJsonPropertySQL(path: string): string {
const [a, b] = path.split('->', 2); // TODO
return `${this.quoteIdentifier(a)}->'$.${b}'`;
getSearchJsonPropertyKey(path: string[], type: string): string {
const [a, ...b] = path;
return `${this.quoteIdentifier(a)}->'$.${b.join('.')}'`;
}

}
17 changes: 10 additions & 7 deletions packages/postgresql/src/PostgreSqlPlatform.ts
Original file line number Diff line number Diff line change
Expand Up @@ -58,17 +58,20 @@ export class PostgreSqlPlatform extends AbstractSqlPlatform {
return 'jsonb';
}

getSearchJsonPropertySQL(path: string): string {
const parts = path.split('->');
const first = parts.shift();
const last = parts.pop();
getSearchJsonPropertyKey(path: string[], type: string): string {
const first = path.shift();
const last = path.pop();
const root = this.quoteIdentifier(first!);
const cast = (key: string) => {
const t = type === 'number' ? 'float8' : (type === 'boolean' ? 'bool' : '');
return t ? `(${key})::${t}` : key;
};

if (parts.length === 0) {
return `${root}->>'${last}'`;
if (path.length === 0) {
return cast(`${root}->>'${last}'`);
}

return `${root}->${parts.map(a => this.quoteValue(a)).join('->')}->>'${last}'`;
return cast(`${root}->${path.map(a => this.quoteValue(a)).join('->')}->>'${last}'`);
}

quoteIdentifier(id: string, quote = '"'): string {
Expand Down
5 changes: 5 additions & 0 deletions packages/sqlite/src/SqlitePlatform.ts
Original file line number Diff line number Diff line change
Expand Up @@ -69,4 +69,9 @@ export class SqlitePlatform extends AbstractSqlPlatform {
return escape(value, true, this.timezone);
}

getSearchJsonPropertyKey(path: string[], type: string): string {
const [a, ...b] = path;
return `json_extract(${this.quoteIdentifier(a)}, '$.${b.join('.')}')`;
}

}
30 changes: 30 additions & 0 deletions tests/EntityManager.mongo.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -594,6 +594,36 @@ describe('EntityManagerMongo', () => {
await expect(conn4.getClientUrl()).toBe('invalid-url-that-was-not-properly-parsed');
});

test('json properties', async () => {
const god = new Author('God', 'hello@heaven.god');
god.identities = ['fb-123', 'pw-231', 'tw-321'];
const bible = new Book('Bible', god);
bible.metaObject = { category: 'god like', items: 3, valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } };
await orm.em.persistAndFlush(bible);
orm.em.clear();

const g = await orm.em.findOneOrFail(Author, god.id, ['books']);
expect(Array.isArray(g.identities)).toBe(true);
expect(g.identities).toEqual(['fb-123', 'pw-231', 'tw-321']);
expect(typeof g.books[0].metaObject).toBe('object');
expect(g.books[0].metaObject).toEqual({ category: 'god like', items: 3, valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } });
orm.em.clear();

const b1 = await orm.em.findOneOrFail(Book, { metaObject: { category: 'god like' } });
const b2 = await orm.em.findOneOrFail(Book, { metaObject: { category: 'god like', items: 3 } });
const b3 = await orm.em.findOneOrFail(Book, { metaObject: { nested: { bar: 321 } } });
const b4 = await orm.em.findOneOrFail(Book, { metaObject: { nested: { foo: '123', bar: 321 } } });
const b5 = await orm.em.findOneOrFail(Book, { metaObject: { valid: true, nested: { foo: '123', bar: 321 } } });
const b6 = await orm.em.findOneOrFail(Book, { metaObject: { valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59 } } } });
const b7 = await orm.em.findOneOrFail(Book, { metaObject: { valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } } });
expect(b1).toBe(b2);
expect(b1).toBe(b3);
expect(b1).toBe(b4);
expect(b1).toBe(b5);
expect(b1).toBe(b6);
expect(b1).toBe(b7);
});

test('findOne by id', async () => {
const authorRepository = orm.em.getRepository(Author);
const jon = new Author('Jon Snow', 'snow@wall.st');
Expand Down
21 changes: 18 additions & 3 deletions tests/EntityManager.mysql.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -525,15 +525,30 @@ describe('EntityManagerMySql', () => {
const god = new Author2('God', 'hello@heaven.god');
god.identities = ['fb-123', 'pw-231', 'tw-321'];
const bible = new Book2('Bible', god);
bible.meta = { category: 'god like', items: 3 };
bible.meta = { category: 'god like', items: 3, valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } };
await orm.em.persistAndFlush(bible);
orm.em.clear();

const g = (await orm.em.findOne(Author2, god.id, ['books']))!;
const g = await orm.em.findOneOrFail(Author2, god.id, ['books']);
expect(Array.isArray(g.identities)).toBe(true);
expect(g.identities).toEqual(['fb-123', 'pw-231', 'tw-321']);
expect(typeof g.books[0].meta).toBe('object');
expect(g.books[0].meta).toEqual({ category: 'god like', items: 3 });
expect(g.books[0].meta).toEqual({ category: 'god like', items: 3, valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } });
orm.em.clear();

const b1 = await orm.em.findOneOrFail(Book2, { meta: { category: 'god like' } });
const b2 = await orm.em.findOneOrFail(Book2, { meta: { category: 'god like', items: 3 } });
const b3 = await orm.em.findOneOrFail(Book2, { meta: { nested: { bar: 321 } } });
const b4 = await orm.em.findOneOrFail(Book2, { meta: { nested: { foo: '123', bar: 321 } } });
const b5 = await orm.em.findOneOrFail(Book2, { meta: { valid: true, nested: { foo: '123', bar: 321 } } });
const b6 = await orm.em.findOneOrFail(Book2, { meta: { valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59 } } } });
const b7 = await orm.em.findOneOrFail(Book2, { meta: { valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } } });
expect(b1).toBe(b2);
expect(b1).toBe(b3);
expect(b1).toBe(b4);
expect(b1).toBe(b5);
expect(b1).toBe(b6);
expect(b1).toBe(b7);
});

test('findOne should initialize entity that is already in IM', async () => {
Expand Down
21 changes: 18 additions & 3 deletions tests/EntityManager.postgre.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -393,15 +393,30 @@ describe('EntityManagerPostgre', () => {
const god = new Author2('God', 'hello@heaven.god');
god.identities = ['fb-123', 'pw-231', 'tw-321'];
const bible = new Book2('Bible', god);
bible.meta = { category: 'god like', items: 3 };
bible.meta = { category: 'god like', items: 3, valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } };
await orm.em.persistAndFlush(bible);
orm.em.clear();

const g = (await orm.em.findOne(Author2, god.id, ['books']))!;
const g = await orm.em.findOneOrFail(Author2, god.id, ['books']);
expect(Array.isArray(g.identities)).toBe(true);
expect(g.identities).toEqual(['fb-123', 'pw-231', 'tw-321']);
expect(typeof g.books[0].meta).toBe('object');
expect(g.books[0].meta).toEqual({ category: 'god like', items: 3 });
expect(g.books[0].meta).toEqual({ category: 'god like', items: 3, valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } });
orm.em.clear();

const b1 = await orm.em.findOneOrFail(Book2, { meta: { category: 'god like' } });
const b2 = await orm.em.findOneOrFail(Book2, { meta: { category: 'god like', items: 3 } });
const b3 = await orm.em.findOneOrFail(Book2, { meta: { nested: { bar: 321 } } });
const b4 = await orm.em.findOneOrFail(Book2, { meta: { nested: { foo: '123', bar: 321 } } });
const b5 = await orm.em.findOneOrFail(Book2, { meta: { valid: true, nested: { foo: '123', bar: 321 } } });
const b6 = await orm.em.findOneOrFail(Book2, { meta: { valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59 } } } });
const b7 = await orm.em.findOneOrFail(Book2, { meta: { valid: true, nested: { foo: '123', bar: 321, deep: { baz: 59, qux: false } } } });
expect(b1).toBe(b2);
expect(b1).toBe(b3);
expect(b1).toBe(b4);
expect(b1).toBe(b5);
expect(b1).toBe(b6);
expect(b1).toBe(b7);
});

test('findOne should initialize entity that is already in IM', async () => {
Expand Down
Loading

0 comments on commit b8da7be

Please sign in to comment.