2023-07-05 04:46:42 -07:00
import { statSync } from 'fs' ;
import path from 'path' ;
import { UserSettings } from 'n8n-core' ;
2023-06-22 08:51:17 -07:00
import type { MigrationContext , IrreversibleMigration } from '@db/types' ;
2023-07-05 04:46:42 -07:00
import config from '@/config' ;
2023-06-20 10:13:18 -07:00
2023-06-22 08:51:17 -07:00
export class MigrateIntegerKeysToString1690000000002 implements IrreversibleMigration {
2023-07-05 02:26:49 -07:00
transaction = false as const ;
2023-07-05 04:46:42 -07:00
async up ( context : MigrationContext ) {
// eslint-disable-next-line @typescript-eslint/no-use-before-define
await pruneExecutionsData ( context ) ;
const { queryRunner , tablePrefix } = context ;
2023-06-20 10:13:18 -07:00
await queryRunner . query ( `
2023-07-05 02:26:49 -07:00
CREATE TABLE "${tablePrefix}TMP_workflow_entity" ( "id" varchar ( 36 ) PRIMARY KEY NOT NULL , "name" varchar ( 128 ) NOT NULL , "active" boolean NOT NULL , "nodes" text , "connections" text NOT NULL , "createdAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) , "updatedAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) , "settings" text , "staticData" text , "pinData" text , "versionId" varchar ( 36 ) , "triggerCount" integer NOT NULL DEFAULT 0 ) ; ` );
2023-06-20 10:13:18 -07:00
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` INSERT INTO " ${ tablePrefix } TMP_workflow_entity" (id, name, active, nodes, connections, createdAt, updatedAt, settings, staticData, pinData, triggerCount, versionId) SELECT id, name, active, nodes, connections, createdAt, updatedAt, settings, staticData, pinData, triggerCount, versionId FROM " ${ tablePrefix } workflow_entity"; ` ,
2023-06-20 10:13:18 -07:00
) ;
2023-06-21 08:10:47 -07:00
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } workflow_entity"; ` ) ;
2023-07-05 02:26:49 -07:00
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_workflow_entity" RENAME TO " ${ tablePrefix } workflow_entity" ` ,
) ;
2023-06-20 10:13:18 -07:00
await queryRunner . query ( `
2023-07-05 02:26:49 -07:00
CREATE TABLE "${tablePrefix}TMP_tag_entity" ( "id" varchar ( 36 ) PRIMARY KEY NOT NULL , "name" varchar ( 24 ) NOT NULL , "createdAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) , "updatedAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) ) ; ` );
2023-06-20 10:13:18 -07:00
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_tag_entity" SELECT * FROM " ${ tablePrefix } tag_entity"; ` ,
) ;
2023-06-21 08:10:47 -07:00
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } tag_entity"; ` ) ;
2023-06-20 10:13:18 -07:00
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_tag_entity" RENAME TO " ${ tablePrefix } tag_entity"; ` ,
) ;
await queryRunner . query ( `
2023-07-05 02:26:49 -07:00
CREATE TABLE "${tablePrefix}TMP_workflows_tags" ( "workflowId" varchar ( 36 ) NOT NULL , "tagId" integer NOT NULL , CONSTRAINT "FK_${tablePrefix}workflows_tags_workflow_entity" FOREIGN KEY ( "workflowId" ) REFERENCES "${tablePrefix}workflow_entity" ( "id" ) ON DELETE CASCADE ON UPDATE NO ACTION , CONSTRAINT "FK_${tablePrefix}workflows_tags_tag_entity" FOREIGN KEY ( "tagId" ) REFERENCES "${tablePrefix}tag_entity" ( "id" ) ON DELETE CASCADE ON UPDATE NO ACTION , PRIMARY KEY ( "workflowId" , "tagId" ) ) ; ` );
2023-06-20 10:13:18 -07:00
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_workflows_tags" SELECT * FROM " ${ tablePrefix } workflows_tags"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } workflows_tags"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_workflows_tags" RENAME TO " ${ tablePrefix } workflows_tags"; ` ,
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } workflows_tags_tag_id" ON " ${ tablePrefix } workflows_tags" ("tagId"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } workflows_tags_workflow_id" ON " ${ tablePrefix } workflows_tags" ("workflowId"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query ( ` CREATE TABLE " ${ tablePrefix } TMP_workflow_statistics" (
"count" INTEGER DEFAULT 0 ,
"latestEvent" DATETIME ,
"name" VARCHAR ( 128 ) NOT NULL ,
"workflowId" VARCHAR ( 36 ) ,
PRIMARY KEY ( "workflowId" , "name" ) ,
FOREIGN KEY ( "workflowId" ) REFERENCES "${tablePrefix}workflow_entity" ( "id" ) ON DELETE CASCADE
) ; ` );
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_workflow_statistics" SELECT * FROM " ${ tablePrefix } workflow_statistics"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } workflow_statistics"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_workflow_statistics" RENAME TO " ${ tablePrefix } workflow_statistics"; ` ,
) ;
await queryRunner . query (
` CREATE TABLE " ${ tablePrefix } TMP_shared_workflow" (
"createdAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) ,
"updatedAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) ,
"roleId" integer NOT NULL , "userId" varchar NOT NULL ,
"workflowId" VARCHAR ( 36 ) NOT NULL ,
2023-06-21 08:10:47 -07:00
CONSTRAINT "FK_${tablePrefix}shared_workflow_role" FOREIGN KEY ( "roleId" ) REFERENCES "${tablePrefix}role" ( "id" ) ON DELETE NO ACTION ON UPDATE NO ACTION ,
CONSTRAINT "FK_${tablePrefix}shared_workflow_user" FOREIGN KEY ( "userId" ) REFERENCES "${tablePrefix}user" ( "id" ) ON DELETE CASCADE ON UPDATE NO ACTION ,
CONSTRAINT "FK_${tablePrefix}shared_workflow_workflow_entity" FOREIGN KEY ( "workflowId" ) REFERENCES "${tablePrefix}workflow_entity" ( "id" ) ON DELETE CASCADE ON UPDATE NO ACTION ,
2023-06-20 10:13:18 -07:00
PRIMARY KEY ( "userId" , "workflowId" ) ) ; ` ,
) ;
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_shared_workflow" SELECT * FROM " ${ tablePrefix } shared_workflow"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } shared_workflow"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_shared_workflow" RENAME TO " ${ tablePrefix } shared_workflow"; ` ,
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } shared_workflow_workflow_id" ON " ${ tablePrefix } shared_workflow" ("workflowId"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
` CREATE TABLE " ${ tablePrefix } TMP_webhook_entity" ("workflowId" varchar(36) NOT NULL, "webhookPath" varchar NOT NULL, "method" varchar NOT NULL, "node" varchar NOT NULL, "webhookId" varchar, "pathLength" integer, PRIMARY KEY ("webhookPath", "method")); ` ,
) ;
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_webhook_entity" SELECT * FROM " ${ tablePrefix } webhook_entity"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } webhook_entity"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_webhook_entity" RENAME TO " ${ tablePrefix } webhook_entity"; ` ,
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } webhook_entity_webhook_path_method" ON " ${ tablePrefix } webhook_entity" ("webhookId","method","pathLength"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query ( ` CREATE TABLE " ${ tablePrefix } TMP_execution_entity" (
"id" integer PRIMARY KEY AUTOINCREMENT NOT NULL ,
"workflowId" varchar ( 36 ) ,
"finished" boolean NOT NULL ,
"mode" varchar NOT NULL ,
"retryOf" varchar ,
"retrySuccessId" varchar ,
"startedAt" datetime NOT NULL ,
"stoppedAt" datetime ,
"waitTill" datetime ,
"workflowData" text NOT NULL ,
"data" text NOT NULL , "status" varchar ,
2023-06-21 08:10:47 -07:00
FOREIGN KEY ( "workflowId" ) REFERENCES "${tablePrefix}workflow_entity" ( "id" ) ON DELETE CASCADE
2023-06-20 10:13:18 -07:00
) ; ` );
2023-07-31 08:35:53 -07:00
await context . copyTable ( 'execution_entity' , 'TMP_execution_entity' ) ;
2023-06-20 10:13:18 -07:00
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } execution_entity"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_execution_entity" RENAME TO " ${ tablePrefix } execution_entity"; ` ,
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } execution_entity_stopped_at" ON " ${ tablePrefix } execution_entity" ("stoppedAt"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } execution_entity_wait_till" ON " ${ tablePrefix } execution_entity" ("waitTill"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
` CREATE TABLE " ${ tablePrefix } TMP_credentials_entity" ("id" varchar(36) PRIMARY KEY NOT NULL, "name" varchar(128) NOT NULL, "data" text NOT NULL, "type" varchar(32) NOT NULL, "nodesAccess" text NOT NULL, "createdAt" datetime(3) NOT NULL DEFAULT (STRFTIME('%Y-%m-%d %H:%M:%f', 'NOW')), "updatedAt" datetime(3) NOT NULL DEFAULT (STRFTIME('%Y-%m-%d %H:%M:%f', 'NOW'))); ` ,
) ;
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_credentials_entity" SELECT * FROM " ${ tablePrefix } credentials_entity"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } credentials_entity"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_credentials_entity" RENAME TO " ${ tablePrefix } credentials_entity"; ` ,
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } credentials_entity_type" ON " ${ tablePrefix } credentials_entity" ("type"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
` CREATE TABLE " ${ tablePrefix } TMP_shared_credentials" ("createdAt" datetime(3) NOT NULL DEFAULT (STRFTIME('%Y-%m-%d %H:%M:%f', 'NOW')),
"updatedAt" datetime ( 3 ) NOT NULL DEFAULT ( STRFTIME ( '%Y-%m-%d %H:%M:%f' , 'NOW' ) ) ,
"roleId" integer NOT NULL ,
"userId" varchar NOT NULL , "credentialsId" varchar ( 36 ) NOT NULL ,
2023-06-21 08:10:47 -07:00
CONSTRAINT "FK_${tablePrefix}shared_credentials_role" FOREIGN KEY ( "roleId" ) REFERENCES "${tablePrefix}role" ( "id" ) ON DELETE NO ACTION ON UPDATE NO ACTION ,
CONSTRAINT "FK_${tablePrefix}shared_credentials_user" FOREIGN KEY ( "userId" ) REFERENCES "${tablePrefix}user" ( "id" ) ON DELETE CASCADE ON UPDATE NO ACTION ,
CONSTRAINT "FK_${tablePrefix}shared_credentials_credentials" FOREIGN KEY ( "credentialsId" ) REFERENCES "${tablePrefix}credentials_entity" ( "id" ) ON DELETE CASCADE ON UPDATE NO ACTION , PRIMARY KEY ( "userId" , "credentialsId" ) ) ; ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_shared_credentials" SELECT * FROM " ${ tablePrefix } shared_credentials"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } shared_credentials"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_shared_credentials" RENAME TO " ${ tablePrefix } shared_credentials"; ` ,
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE INDEX "idx_ ${ tablePrefix } shared_credentials_credentials" ON " ${ tablePrefix } shared_credentials" ("credentialsId"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query (
2023-06-21 08:10:47 -07:00
` CREATE UNIQUE INDEX "idx_ ${ tablePrefix } shared_credentials_user_credentials" ON " ${ tablePrefix } shared_credentials" ("userId","credentialsId"); ` ,
2023-06-20 10:13:18 -07:00
) ;
await queryRunner . query ( ` CREATE TABLE " ${ tablePrefix } TMP_variables" (
id varchar ( 36 ) PRIMARY KEY NOT NULL ,
"key" TEXT NOT NULL ,
"type" TEXT NOT NULL DEFAULT ( 'string' ) ,
value TEXT ,
UNIQUE ( "key" )
) ; ` );
await queryRunner . query (
` INSERT INTO " ${ tablePrefix } TMP_variables" SELECT * FROM " ${ tablePrefix } variables"; ` ,
) ;
await queryRunner . query ( ` DROP TABLE " ${ tablePrefix } variables"; ` ) ;
await queryRunner . query (
` ALTER TABLE " ${ tablePrefix } TMP_variables" RENAME TO " ${ tablePrefix } variables"; ` ,
) ;
2023-06-22 08:51:17 -07:00
await queryRunner . query (
` CREATE UNIQUE INDEX "idx_ ${ tablePrefix } variables_key" ON " ${ tablePrefix } variables" ("key") ` ,
) ;
2023-06-20 10:13:18 -07:00
}
}
2023-07-05 04:46:42 -07:00
const DESIRED_DATABASE_FILE_SIZE = 1 * 1024 * 1024 * 1024 ; // 1 GB
const migrationsPruningEnabled = process . env . MIGRATIONS_PRUNING_ENABLED === 'true' ;
function getSqliteDbFileSize ( ) : number {
const filename = path . resolve (
UserSettings . getUserN8nFolderPath ( ) ,
config . getEnv ( 'database.sqlite.database' ) ,
) ;
const { size } = statSync ( filename ) ;
return size ;
}
2023-07-13 01:14:48 -07:00
const pruneExecutionsData = async ( { queryRunner , tablePrefix , logger } : MigrationContext ) = > {
2023-07-05 04:46:42 -07:00
if ( migrationsPruningEnabled ) {
const dbFileSize = getSqliteDbFileSize ( ) ;
if ( dbFileSize < DESIRED_DATABASE_FILE_SIZE ) {
2023-07-13 01:14:48 -07:00
logger . debug ( ` DB Size not large enough to prune: ${ dbFileSize } ` ) ;
2023-07-05 04:46:42 -07:00
return ;
}
console . time ( 'pruningData' ) ;
const counting = ( await queryRunner . query (
` select count(id) as rows from " ${ tablePrefix } execution_entity"; ` ,
) ) as Array < { rows : number } > ;
const averageExecutionSize = dbFileSize / counting [ 0 ] . rows ;
const numberOfExecutionsToKeep = Math . floor ( DESIRED_DATABASE_FILE_SIZE / averageExecutionSize ) ;
const query = ` SELECT id FROM " ${ tablePrefix } execution_entity" ORDER BY id DESC limit ${ numberOfExecutionsToKeep } , 1 ` ;
const idToKeep = await queryRunner
. query ( query )
. then ( ( rows : Array < { id : number } > ) = > rows [ 0 ] . id ) ;
const removalQuery = ` DELETE FROM " ${ tablePrefix } execution_entity" WHERE id < ${ idToKeep } and status IN ('success') ` ;
await queryRunner . query ( removalQuery ) ;
console . timeEnd ( 'pruningData' ) ;
} else {
2023-07-13 01:14:48 -07:00
logger . debug ( 'Pruning was requested, but was not enabled' ) ;
2023-07-05 04:46:42 -07:00
}
} ;