Skip to content

Commit

Permalink
support models with fk circular dependencies (#14)
Browse files Browse the repository at this point in the history
* js: support models with fk circular dependency

* update test migrations
  • Loading branch information
ronenlu authored Dec 26, 2023
1 parent d06935e commit 30bf516
Show file tree
Hide file tree
Showing 11 changed files with 197 additions and 65 deletions.
3 changes: 2 additions & 1 deletion .gitignore
Original file line number Diff line number Diff line change
@@ -1 +1,2 @@
node_modules/
node_modules/
.idea/
108 changes: 77 additions & 31 deletions js/src/sequelize_schema.js
Original file line number Diff line number Diff line change
Expand Up @@ -25,44 +25,90 @@ const loadSequelizeModels = (dialect, ...models) => {
db[modelName].associate(db);
}
}
const modelsOrdered = sequelize.modelManager
.getModelsTopoSortedByForeignKey()
.reverse();
const sortedModels = sequelize.modelManager.getModelsTopoSortedByForeignKey();
let sql = "";
for (const model of modelsOrdered) {
const def = sequelize.modelManager.getModel(model.name);
const attr = sequelize
.getQueryInterface()
.queryGenerator.attributesToSQL(def.getAttributes(), { ...def.options });
// create enum types for postgres
if (dialect === "postgres") {
for (const key in attr) {
if (!attr[key].startsWith("ENUM")) {
continue;
}
const enumValues = attr[key].substring(
attr[key].indexOf("("),
attr[key].lastIndexOf(")") + 1,
);
const enumName = `enum_${def.tableName}_${key}`;
sql += `CREATE TYPE "${enumName}" AS ENUM${enumValues};\n`;
if (sortedModels !== null) {
for (const model of sortedModels.reverse()) {
sql += modelToSQL(sequelize, model, dialect);
}
return sql;
}
if (dialect === "sqlite") {
// in sqlite foreign keys constraints are not enforced by default
for (const model of sequelize.modelManager.models) {
sql += modelToSQL(sequelize, model, dialect);
}
return sql;
}
// models have circular dependencies, so need to create table without foreign keys first, then add foreign keys
for (const model of sequelize.modelManager.models) {
sql += modelToSQL(sequelize, model, dialect, true);
}
const queryInterface = sequelize.getQueryInterface();
for (const model of sequelize.modelManager.models) {
// loop over the model attributes and find the foreign keys
for (const key of Object.keys(model.getAttributes())) {
const attribute = model.getAttributes()[key];
if (!attribute.references) {
continue;
}
const query = queryInterface.queryGenerator.attributesToSQL(
{
[key]: queryInterface.normalizeAttribute(attribute),
},
{
context: "changeColumn",
table: model.getTableName(),
},
);
sql += queryInterface.queryGenerator.changeColumnQuery(
model.getTableName(),
query,
);
sql += "\n";
}
}
return sql;
};

// returns DDL string describing single model.
function modelToSQL(sequelize, model, dialect, withOutFKs = false) {
let sql = "";
const def = sequelize.modelManager.getModel(model.name);
const attr = sequelize
.getQueryInterface()
.queryGenerator.attributesToSQL(def.getAttributes(), {
...def.options,
withoutForeignKeyConstraints: withOutFKs,
});
// create enum types for postgres
if (dialect === "postgres") {
for (const key in attr) {
if (!attr[key].startsWith("ENUM")) {
continue;
}
const enumValues = attr[key].substring(
attr[key].indexOf("("),
attr[key].lastIndexOf(")") + 1,
);
const enumName = `enum_${def.tableName}_${key}`;
sql += `CREATE TYPE "${enumName}" AS ENUM${enumValues};\n`;
}
}
sql +=
sequelize
.getQueryInterface()
.queryGenerator.createTableQuery(def.tableName, attr, {
...def.options,
}) + "\n";

for (const index of def.options.indexes) {
sql +=
sequelize
.getQueryInterface()
.queryGenerator.createTableQuery(def.tableName, attr, {
...def.options,
}) + "\n";

for (const index of def.options.indexes) {
sql +=
sequelize
.getQueryInterface()
.queryGenerator.addIndexQuery(def.tableName, index) + ";\n";
}
.queryGenerator.addIndexQuery(def.tableName, index) + ";\n";
}
return sql;
};
}

module.exports = loadSequelizeModels;
3 changes: 2 additions & 1 deletion js/testdata/load-models.js
Original file line number Diff line number Diff line change
Expand Up @@ -3,9 +3,10 @@
const ingredient = require("./models/ingredient");
const recipe = require("./models/recipe");
const recipeIngredient = require("./models/recipe-ingredient");
const user = require("./models/user");
const loadModels = require("../index");

// parse the second argument as the dialect
const dialect = process.argv[2];

console.log(loadModels(dialect, ingredient, recipe, recipeIngredient));
console.log(loadModels(dialect, ingredient, recipe, recipeIngredient, user));
Original file line number Diff line number Diff line change
@@ -1,15 +1,3 @@
-- Create "Recipes" table
CREATE TABLE `Recipes` (
`id` int NOT NULL AUTO_INCREMENT,
`title` varchar(255) NOT NULL,
`description` text NOT NULL,
`instructions` text NOT NULL,
`meal` enum('breakfast','lunch','dinner','dessert') NULL DEFAULT "lunch",
`createdAt` datetime NOT NULL,
`updatedAt` datetime NOT NULL,
`deletedAt` datetime NULL,
PRIMARY KEY (`id`)
) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- Create "Ingredients" table
CREATE TABLE `Ingredients` (
`id` int NOT NULL AUTO_INCREMENT,
Expand All @@ -30,7 +18,36 @@ CREATE TABLE `RecipeIngredients` (
`deletedAt` datetime NULL,
PRIMARY KEY (`recipeId`, `ingredientId`),
INDEX `ingredientId` (`ingredientId`),
UNIQUE INDEX `recipe_ingredients_meassurement_type_meassurement_amount` (`meassurementType`, `meassurementAmount`),
CONSTRAINT `RecipeIngredients_ibfk_1` FOREIGN KEY (`recipeId`) REFERENCES `Recipes` (`id`) ON UPDATE CASCADE ON DELETE CASCADE,
CONSTRAINT `RecipeIngredients_ibfk_2` FOREIGN KEY (`ingredientId`) REFERENCES `Ingredients` (`id`) ON UPDATE CASCADE ON DELETE CASCADE
UNIQUE INDEX `recipe_ingredients_meassurement_type_meassurement_amount` (`meassurementType`, `meassurementAmount`)
) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- Create "Recipes" table
CREATE TABLE `Recipes` (
`id` int NOT NULL AUTO_INCREMENT,
`title` varchar(255) NOT NULL,
`description` text NOT NULL,
`instructions` text NOT NULL,
`userId` int NOT NULL,
`meal` enum('breakfast','lunch','dinner','dessert') NULL DEFAULT "lunch",
`createdAt` datetime NOT NULL,
`updatedAt` datetime NOT NULL,
`deletedAt` datetime NULL,
PRIMARY KEY (`id`),
INDEX `userId` (`userId`)
) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- Create "Users" table
CREATE TABLE `Users` (
`id` int NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
`recipeId` int NOT NULL,
`createdAt` datetime NOT NULL,
`updatedAt` datetime NOT NULL,
`deletedAt` datetime NULL,
PRIMARY KEY (`id`),
INDEX `recipeId` (`recipeId`)
) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- Modify "RecipeIngredients" table
ALTER TABLE `RecipeIngredients` ADD CONSTRAINT `RecipeIngredients_ibfk_1` FOREIGN KEY (`recipeId`) REFERENCES `Recipes` (`id`) ON UPDATE CASCADE ON DELETE CASCADE, ADD CONSTRAINT `RecipeIngredients_ibfk_2` FOREIGN KEY (`ingredientId`) REFERENCES `Ingredients` (`id`) ON UPDATE CASCADE ON DELETE CASCADE;
-- Modify "Recipes" table
ALTER TABLE `Recipes` ADD CONSTRAINT `Recipes_ibfk_1` FOREIGN KEY (`userId`) REFERENCES `Users` (`id`) ON UPDATE CASCADE ON DELETE CASCADE;
-- Modify "Users" table
ALTER TABLE `Users` ADD CONSTRAINT `Users_ibfk_1` FOREIGN KEY (`recipeId`) REFERENCES `Recipes` (`id`) ON UPDATE CASCADE ON DELETE CASCADE;
4 changes: 2 additions & 2 deletions js/testdata/migrations/mysql/atlas.sum
Original file line number Diff line number Diff line change
@@ -1,2 +1,2 @@
h1:cI6IUVRHfJbkk65AWg0ge7Xeb1RGs9oMJkszrVexwss=
20231218113756.sql h1:UGw8bFPavN0GrLFrN0nAl+P7VFaOX/a2yKZXq4P29fA=
h1:OgZsNGmgX9py3k61Yf+DCuyflbFmgILvTDvwJBdVvho=
20231225122102.sql h1:ClhnG2UKDb5t+dwNFT6lcEGeXAG9AXvlwUzq4RwWnUQ=
Original file line number Diff line number Diff line change
Expand Up @@ -9,30 +9,49 @@ CREATE TABLE "public"."Ingredients" (
"deletedAt" timestamptz NULL,
PRIMARY KEY ("id")
);
-- Create "RecipeIngredients" table
CREATE TABLE "public"."RecipeIngredients" (
"recipeId" integer NOT NULL,
"ingredientId" integer NOT NULL,
"meassurementAmount" integer NOT NULL,
"meassurementType" character varying(255) NOT NULL,
"createdAt" timestamptz NOT NULL,
"updatedAt" timestamptz NOT NULL,
"deletedAt" timestamptz NULL,
PRIMARY KEY ("recipeId", "ingredientId")
);
-- Create index "recipe_ingredients_meassurement_type_meassurement_amount" to table: "RecipeIngredients"
CREATE UNIQUE INDEX "recipe_ingredients_meassurement_type_meassurement_amount" ON "public"."RecipeIngredients" ("meassurementType", "meassurementAmount");
-- Create "Recipes" table
CREATE TABLE "public"."Recipes" (
"id" serial NOT NULL,
"title" character varying(255) NOT NULL,
"description" text NOT NULL,
"instructions" text NOT NULL,
"userId" integer NOT NULL,
"meal" "public"."enum_Recipes_meal" NULL DEFAULT 'lunch',
"createdAt" timestamptz NOT NULL,
"updatedAt" timestamptz NOT NULL,
"deletedAt" timestamptz NULL,
PRIMARY KEY ("id")
);
-- Create "RecipeIngredients" table
CREATE TABLE "public"."RecipeIngredients" (
-- Create "Users" table
CREATE TABLE "public"."Users" (
"id" serial NOT NULL,
"name" character varying(255) NOT NULL,
"recipeId" integer NOT NULL,
"ingredientId" integer NOT NULL,
"meassurementAmount" integer NOT NULL,
"meassurementType" character varying(255) NOT NULL,
"createdAt" timestamptz NOT NULL,
"updatedAt" timestamptz NOT NULL,
"deletedAt" timestamptz NULL,
PRIMARY KEY ("recipeId", "ingredientId"),
CONSTRAINT "RecipeIngredients_ingredientId_fkey" FOREIGN KEY ("ingredientId") REFERENCES "public"."Ingredients" ("id") ON UPDATE CASCADE ON DELETE CASCADE,
CONSTRAINT "RecipeIngredients_recipeId_fkey" FOREIGN KEY ("recipeId") REFERENCES "public"."Recipes" ("id") ON UPDATE CASCADE ON DELETE CASCADE
PRIMARY KEY ("id")
);
-- Create index "recipe_ingredients_meassurement_type_meassurement_amount" to table: "RecipeIngredients"
CREATE UNIQUE INDEX "recipe_ingredients_meassurement_type_meassurement_amount" ON "public"."RecipeIngredients" ("meassurementType", "meassurementAmount");
-- Modify "RecipeIngredients" table
ALTER TABLE "public"."RecipeIngredients" ADD
CONSTRAINT "RecipeIngredients_ingredientId_fkey" FOREIGN KEY ("ingredientId") REFERENCES "public"."Ingredients" ("id") ON UPDATE CASCADE ON DELETE CASCADE, ADD
CONSTRAINT "RecipeIngredients_recipeId_fkey" FOREIGN KEY ("recipeId") REFERENCES "public"."Recipes" ("id") ON UPDATE CASCADE ON DELETE CASCADE;
-- Modify "Recipes" table
ALTER TABLE "public"."Recipes" ADD
CONSTRAINT "Recipes_userId_fkey" FOREIGN KEY ("userId") REFERENCES "public"."Users" ("id") ON UPDATE CASCADE ON DELETE CASCADE;
-- Modify "Users" table
ALTER TABLE "public"."Users" ADD
CONSTRAINT "Users_recipeId_fkey" FOREIGN KEY ("recipeId") REFERENCES "public"."Recipes" ("id") ON UPDATE CASCADE ON DELETE CASCADE;
4 changes: 2 additions & 2 deletions js/testdata/migrations/postgres/atlas.sum
Original file line number Diff line number Diff line change
@@ -1,2 +1,2 @@
h1:JCDQK9pnfdBoi3LjhfZWKQ0vmrl01yT+z/iI9z2xcO0=
20231218113750.sql h1:G5dZYzfZamTnaCw/gsxOz0ZtT2QuxwC+OwmeOaaKKbQ=
h1:kv5cFbgcvOA0iW5aiYEf+uQBNZWzgW7SQ3ESNF8G7AM=
20231225122022.sql h1:vB3ZaP+BqXaKCVjtxtuH++OOA1r/EvpuPf7t88i5QJ8=
Original file line number Diff line number Diff line change
Expand Up @@ -12,10 +12,12 @@ CREATE TABLE `Recipes` (
`title` varchar NOT NULL,
`description` text NOT NULL,
`instructions` text NOT NULL,
`userId` integer NOT NULL,
`meal` text NULL DEFAULT 'lunch',
`createdAt` datetime NOT NULL,
`updatedAt` datetime NOT NULL,
`deletedAt` datetime NULL
`deletedAt` datetime NULL,
CONSTRAINT `0` FOREIGN KEY (`userId`) REFERENCES `Users` (`id`) ON UPDATE CASCADE ON DELETE CASCADE
);
-- Create "RecipeIngredients" table
CREATE TABLE `RecipeIngredients` (
Expand All @@ -32,3 +34,13 @@ CREATE TABLE `RecipeIngredients` (
);
-- Create index "recipe_ingredients_meassurement_type_meassurement_amount" to table: "RecipeIngredients"
CREATE UNIQUE INDEX `recipe_ingredients_meassurement_type_meassurement_amount` ON `RecipeIngredients` (`meassurementType`, `meassurementAmount`);
-- Create "Users" table
CREATE TABLE `Users` (
`id` integer NULL PRIMARY KEY AUTOINCREMENT,
`name` varchar NOT NULL,
`recipeId` integer NOT NULL,
`createdAt` datetime NOT NULL,
`updatedAt` datetime NOT NULL,
`deletedAt` datetime NULL,
CONSTRAINT `0` FOREIGN KEY (`recipeId`) REFERENCES `Recipes` (`id`) ON UPDATE CASCADE ON DELETE CASCADE
);
4 changes: 2 additions & 2 deletions js/testdata/migrations/sqlite/atlas.sum
Original file line number Diff line number Diff line change
@@ -1,2 +1,2 @@
h1:XZPNKrbW25KYA84JijT+3mt1j7v061dL4noOCiKC1Ws=
20231218113759.sql h1:Xoq/BkJqpRZ05eyN12Ub/8SOTm/zHVyxelGCmBAtAl4=
h1:tInqZl0Eg+lKPRULTifvfDQozfbKgzUDFbipWDlVw/w=
20231225122837.sql h1:x4/DEpFPl2hmd78T7wgkaxcUwYkyD5kqyaqjXOkOCIs=
8 changes: 8 additions & 0 deletions js/testdata/models/recipe.js
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,10 @@ module.exports = function (sequelize, DataTypes) {
type: DataTypes.TEXT,
allowNull: false,
},
userId: {
type: DataTypes.INTEGER,
allowNull: false,
},
meal: {
type: DataTypes.ENUM,
values: ["breakfast", "lunch", "dinner", "dessert"],
Expand All @@ -32,6 +36,10 @@ module.exports = function (sequelize, DataTypes) {
foreignKey: "recipeId",
as: "ingredients",
});
Recipe.hasMany(models.User, {
foreignKey: "recipeId",
as: "users",
});
};

return Recipe;
Expand Down
28 changes: 28 additions & 0 deletions js/testdata/models/user.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
"use strict";
module.exports = (sequelize, DataTypes) => {
const User = sequelize.define(
"User",
{
name: {
type: DataTypes.STRING,
allowNull: false,
},
recipeId: {
type: DataTypes.INTEGER,
allowNull: false,
},
},
{
paranoid: true,
},
);

User.associate = (models) => {
User.hasMany(models.Recipe, {
foreignKey: "userId",
as: "recipes",
});
};

return User;
};

0 comments on commit 30bf516

Please sign in to comment.