Skip to content

Commit

Permalink
feat(sql): add native support for generated columns (#4884)
Browse files Browse the repository at this point in the history
To use generated columns, you can either use the `generated` option, or
specify it as part of the `columnType`:

```ts
@entity()
export class User {

  @PrimaryKey()
  id!: number;

  @Property({ length: 50 })
  firstName!: string;

  @Property({ length: 50 })
  lastName!: string;

  @Property<User>({ length: 100, generated: cols => `(concat(${cols.firstName}, ' ', ${cols.lastName})) stored` })
  fullName!: string & Opt;

  @Property({ columnType: `varchar(100) generated always as (concat(first_name, ' ', last_name)) virtual` })
  fullName2!: string & Opt;

}
```

To use a generated identity column in PostgreSQL, set the `generated`
option to `identity`:

> To allow providing the value explicitly, use `generated: 'by default
as identity'`.

```ts
@entity()
export class User {

  @PrimaryKey({ generated: 'identity' })
  id!: number;

}
```
  • Loading branch information
B4nan committed Nov 5, 2023
1 parent 91ec2a9 commit a928291
Show file tree
Hide file tree
Showing 45 changed files with 999 additions and 199 deletions.
136 changes: 109 additions & 27 deletions docs/docs/defining-entities.md
Original file line number Diff line number Diff line change
Expand Up @@ -1323,7 +1323,7 @@ export abstract class CustomBaseEntity {

## SQL Generated columns

Knex currently does not support generated columns, so the schema generator cannot properly diff them. To work around this, we can set `ignoreSchemaChanges` on a property to avoid a perpetual diff from the schema generator
To use generated columns, you can either use the `generated` option, or specify it as part of the `columnType`:

<Tabs
groupId="entity-def"
Expand All @@ -1336,18 +1336,24 @@ values={[
}>
<TabItem value="reflect-metadata">

```ts title="./entities/Book.ts"
@Entity
export class Book {
```ts title="./entities/User.ts"
@Entity()
export class User {

@Property()
title!: string;
@PrimaryKey()
id!: number;

@Property({
columnType: 'VARCHAR GENERATED ALWAYS AS (LOWER(`title`)) VIRTUAL',
ignoreSchemaChanges: ['type', 'extra'],
})
titleLower!: string;
@Property({ length: 50 })
firstName!: string;

@Property({ length: 50 })
lastName!: string;

@Property<User>({ length: 100, generated: cols => `(concat(${cols.firstName}, ' ', ${cols.lastName})) stored` })
fullName!: string & Opt;

@Property({ columnType: `varchar(100) generated always as (concat(first_name, ' ', last_name)) virtual` })
fullName2!: string & Opt;

}
```
Expand All @@ -1356,35 +1362,111 @@ export class Book {
<TabItem value="ts-morph">

```ts title="./entities/Book.ts"
@Entity
export class Book {
@Entity()
export class User {

@Property()
title!: string;
@PrimaryKey()
id!: number;

@Property({
columnType: 'VARCHAR GENERATED ALWAYS AS (LOWER(`title`)) VIRTUAL',
ignoreSchemaChanges: ['type', 'extra'],
})
titleLower!: string;
@Property({ length: 50 })
firstName!: string;

@Property({ length: 50 })
lastName!: string;

@Property<User>({ length: 100, generated: cols => `(concat(${cols.firstName}, ' ', ${cols.lastName})) stored` })
fullName!: string & Opt;

@Property({ columnType: `varchar(100) generated always as (concat(first_name, ' ', last_name)) virtual` })
fullName2!: string & Opt;

}
```

</TabItem>
<TabItem value="entity-schema">

```ts title="./entities/User.ts"
export interface IUser {
id: number;
firstName: string;
lastName: string;
fullName: string & Opt;
fullName2: string & Opt;
}

export const User = new EntitySchema<IUser>({
name: 'User',
properties: {
id: { type: 'number', primary: true },
firstName: { type: 'string', length: 50 },
lastName: { type: 'string', length: 50 },
fullName: {
type: 'string',
length: 100,
generated: cols => `(concat(${cols.firstName}, ' ', ${cols.lastName})) stored`,
},
fullName2: {
type: 'string',
columnType: `varchar(100) generated always as (concat(first_name, ' ', last_name)) virtual`,
},
},
});
```

</TabItem>
</Tabs>

To use a generated identity column in PostgreSQL, set the `generated` option to `identity`:

> To allow providing the value explicitly, use `generated: 'by default as identity'`.
<Tabs
groupId="entity-def"
defaultValue="reflect-metadata"
values={[
{label: 'reflect-metadata', value: 'reflect-metadata'},
{label: 'ts-morph', value: 'ts-morph'},
{label: 'EntitySchema', value: 'entity-schema'},
]
}>
<TabItem value="reflect-metadata">

```ts title="./entities/User.ts"
@Entity()
export class User {

@PrimaryKey({ generated: 'identity' })
id!: number;

}
```

</TabItem>
<TabItem value="ts-morph">

```ts title="./entities/Book.ts"
export interface IBook {
title: string;
titleLower: string;
@Entity()
export class User {

@PrimaryKey({ generated: 'identity' })
id!: number;

}
```

</TabItem>
<TabItem value="entity-schema">

```ts title="./entities/User.ts"
export interface IUser {
id: number;
}

export const Book = new EntitySchema<IBook>({
name: 'Book',
export const User = new EntitySchema<IUser>({
name: 'User',
properties: {
title: { type: String },
titleLower: { type: String, columnType: 'VARCHAR GENERATED ALWAYS AS (LOWER(`title`)) VIRTUAL', ignoreSchemaChanges: ['type', 'extra'] },
id: { type: 'number', primary: true, generated: 'identity' },
},
});
```
Expand Down
2 changes: 1 addition & 1 deletion packages/better-sqlite/src/BetterSqliteConnection.ts
Original file line number Diff line number Diff line change
Expand Up @@ -178,7 +178,7 @@ export class BetterSqliteConnection extends AbstractSqlConnection {
if (obj.method === 'raw') {
const query = obj.sql.trim().toLowerCase();

if (query.startsWith('insert into') && query.includes(' returning ')) {
if ((query.startsWith('insert into') || query.startsWith('update ')) && query.includes(' returning ')) {
return 'all';
}

Expand Down
44 changes: 41 additions & 3 deletions packages/better-sqlite/src/BetterSqliteSchemaHelper.ts
Original file line number Diff line number Diff line change
Expand Up @@ -20,16 +20,53 @@ export class BetterSqliteSchemaHelper extends SchemaHelper {
+ `union all select name as table_name from sqlite_temp_master where type = 'table' order by name`;
}

private parseTableDefinition(sql: string, cols: any[]) {
const columns: Dictionary<{ name: string; definition: string }> = {};

// extract all columns definitions
let columnsDef = sql.replaceAll('\n', '').match(new RegExp(`create table [\`"']?.*?[\`"']? \\((.*)\\)`, 'i'))?.[1];

/* istanbul ignore else */
if (columnsDef) {
for (let i = cols.length - 1; i >= 0; i--) {
const col = cols[i];
const re = ` *, *[\`"']?${col.name}[\`"']? (.*)`;
const columnDef = columnsDef.match(new RegExp(re, 'i'));

/* istanbul ignore else */
if (columnDef) {
columns[col.name] = { name: col.name, definition: columnDef[1] };
columnsDef = columnsDef.substring(0, columnDef.index);
}
}
}

return columns;
}

override async getColumns(connection: AbstractSqlConnection, tableName: string, schemaName?: string): Promise<any[]> {
const columns = await connection.execute<any[]>(`pragma table_info('${tableName}')`);
const columns = await connection.execute<any[]>(`pragma table_xinfo('${tableName}')`);
const sql = `select sql from sqlite_master where type = ? and name = ?`;
const tableDefinition = await connection.execute<{ sql: string }>(sql, ['table', tableName], 'get');
const composite = columns.reduce((count, col) => count + (col.pk ? 1 : 0), 0) > 1;
// there can be only one, so naive check like this should be enough
const hasAutoincrement = tableDefinition.sql.toLowerCase().includes('autoincrement');
const columnDefinitions = this.parseTableDefinition(tableDefinition.sql, columns);

return columns.map(col => {
const mappedType = connection.getPlatform().getMappedType(col.type);
let generated: string | undefined;

if (col.hidden > 1) {
const storage = col.hidden === 2 ? 'virtual' : 'stored';
const re = `(generated always)? as \\((.*)\\)( ${storage})?$`;
const match = columnDefinitions[col.name].definition.match(re);

if (match) {
generated = `${match[2]} ${storage}`;
}
}

return {
name: col.name,
type: col.type,
Expand All @@ -39,6 +76,7 @@ export class BetterSqliteSchemaHelper extends SchemaHelper {
mappedType,
unsigned: false,
autoincrement: !composite && col.pk && this.platform.isNumericColumn(mappedType) && hasAutoincrement,
generated,
};
});
}
Expand All @@ -62,7 +100,7 @@ export class BetterSqliteSchemaHelper extends SchemaHelper {
}, {} as Dictionary<string[]>);
}

override async getPrimaryKeys(connection: AbstractSqlConnection, indexes: IndexDef[] = [], tableName: string, schemaName?: string): Promise<string[]> {
override async getPrimaryKeys(connection: AbstractSqlConnection, indexes: IndexDef[], tableName: string, schemaName?: string): Promise<string[]> {
const sql = `pragma table_info(\`${tableName}\`)`;
const cols = await connection.execute<{ pk: number; name: string }[]>(sql);

Expand All @@ -79,8 +117,8 @@ export class BetterSqliteSchemaHelper extends SchemaHelper {
ret.push({
columnNames: [col.name],
keyName: 'primary',
unique: true,
constraint: true,
unique: true,
primary: true,
});
}
Expand Down
7 changes: 6 additions & 1 deletion packages/core/src/decorators/Property.ts
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ import type {
EntityProperty,
Constructor,
CheckCallback,
GeneratedColumnCallback,
AnyString,
AnyEntity,
EntityKey,
Expand Down Expand Up @@ -119,9 +120,13 @@ export type PropertyOptions<Owner> = {
/**
* Set to map some SQL snippet for the entity.
*
* @see https://mikro-orm.io/docs/defining-entities#formulas Formulas}
* @see https://mikro-orm.io/docs/defining-entities#formulas Formulas
*/
formula?: string | ((alias: string) => string);
/**
* For generated columns. This will be appended to the column type after the `generated always` clause.
*/
generated?: string | GeneratedColumnCallback<Owner>;
/**
* Set column as nullable for {@link https://mikro-orm.io/docs/schema-generator Schema Generator}.
*/
Expand Down
1 change: 1 addition & 0 deletions packages/core/src/entity/EntityValidator.ts
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,7 @@ export class EntityValidator {
!prop.default &&
!prop.defaultRaw &&
!prop.onCreate &&
!prop.generated &&
!prop.embedded &&
![ReferenceKind.ONE_TO_MANY, ReferenceKind.MANY_TO_MANY].includes(prop.kind) &&
prop.name !== wrapped.__meta.root.discriminatorColumn &&
Expand Down
50 changes: 41 additions & 9 deletions packages/core/src/metadata/MetadataDiscovery.ts
Original file line number Diff line number Diff line change
@@ -1,7 +1,15 @@
import { basename, extname } from 'path';
import globby from 'globby';

import { EntityMetadata, type AnyEntity, type Constructor, type Dictionary, type EntityClass, type EntityClassGroup, type EntityProperty } from '../typings';
import {
type AnyEntity,
type Constructor,
type Dictionary,
type EntityClass,
type EntityClassGroup,
EntityMetadata,
type EntityProperty,
} from '../typings';
import { Utils } from '../utils/Utils';
import type { Configuration } from '../utils/Configuration';
import { MetadataValidator } from './MetadataValidator';
Expand All @@ -10,7 +18,7 @@ import type { NamingStrategy } from '../naming-strategy/NamingStrategy';
import type { SyncCacheAdapter } from '../cache/CacheAdapter';
import { MetadataStorage } from './MetadataStorage';
import { EntitySchema } from './EntitySchema';
import { Cascade, ReferenceKind, type EventType } from '../enums';
import { Cascade, type EventType, ReferenceKind } from '../enums';
import { MetadataError } from '../errors';
import type { Platform } from '../platforms';
import { ArrayType, BigIntType, BlobType, EnumArrayType, JsonType, t, Type, Uint8ArrayType } from '../types';
Expand Down Expand Up @@ -112,6 +120,7 @@ export class MetadataDiscovery {
filtered.forEach(meta => Object.values(meta.properties).forEach(prop => this.initFieldName(prop)));
filtered.forEach(meta => Object.values(meta.properties).forEach(prop => this.initVersionProperty(meta, prop)));
filtered.forEach(meta => Object.values(meta.properties).forEach(prop => this.initCustomType(meta, prop)));
filtered.forEach(meta => Object.values(meta.properties).forEach(prop => this.initGeneratedColumn(meta, prop)));
filtered.forEach(meta => this.initAutoincrement(meta)); // once again after we init custom types
filtered.forEach(meta => this.initCheckConstraints(meta));

Expand Down Expand Up @@ -1050,13 +1059,7 @@ export class MetadataDiscovery {
}

private initCheckConstraints(meta: EntityMetadata): void {
const map = Object.values(meta.properties).reduce((o, prop) => {
if (prop.fieldNames) {
o[prop.name] = prop.fieldNames[0];
}

return o;
}, {} as Dictionary);
const map = this.createColumnMappingObject(meta);

for (const check of meta.checks) {
const columns = check.property ? meta.properties[check.property].fieldNames : [];
Expand All @@ -1068,6 +1071,35 @@ export class MetadataDiscovery {
}
}

private initGeneratedColumn(meta: EntityMetadata, prop: EntityProperty): void {
if (!prop.generated && prop.columnTypes) {
const match = prop.columnTypes[0].match(/(.*) generated always as (.*)/);

if (match) {
prop.columnTypes[0] = match[1];
prop.generated = match[2];
}

return;
}

const map = this.createColumnMappingObject(meta);

if (prop.generated instanceof Function) {
prop.generated = prop.generated(map);
}
}

private createColumnMappingObject(meta: EntityMetadata<any>) {
return Object.values(meta.properties).reduce((o, prop) => {
if (prop.fieldNames) {
o[prop.name] = prop.fieldNames[0];
}

return o;
}, {} as Dictionary);
}

private getDefaultVersionValue(prop: EntityProperty): string {
if (typeof prop.defaultRaw !== 'undefined') {
return prop.defaultRaw;
Expand Down
2 changes: 2 additions & 0 deletions packages/core/src/typings.ts
Original file line number Diff line number Diff line change
Expand Up @@ -305,6 +305,7 @@ type ExcludeHidden<T, K extends keyof T> = K extends ExtractHiddenProps<T> ? nev
export type EntityDTO<T> = { [K in EntityKey<T> as ExcludeHidden<T, K>]: EntityDTOProp<T[K]> };

export type CheckCallback<T> = (columns: Record<keyof T, string>) => string;
export type GeneratedColumnCallback<T> = (columns: Record<keyof T, string>) => string;

export interface CheckConstraint<T = any> {
name?: string;
Expand All @@ -321,6 +322,7 @@ export interface EntityProperty<Owner = any, Target = any> {
runtimeType: 'number' | 'string' | 'boolean' | 'bigint' | 'Buffer' | 'Date';
targetMeta?: EntityMetadata<Target>;
columnTypes: string[];
generated?: string | GeneratedColumnCallback<Owner>;
customType: Type<any>;
customTypes: Type<any>[];
hasConvertToJSValueSQL: boolean;
Expand Down
Loading

0 comments on commit a928291

Please sign in to comment.