diff --git a/db/mysql/migrations/20220627184654_init/migration.sql b/db/mysql/migrations/20220627184654_init/migration.sql new file mode 100644 index 00000000..94ed7394 --- /dev/null +++ b/db/mysql/migrations/20220627184654_init/migration.sql @@ -0,0 +1,99 @@ +-- CreateTable +CREATE TABLE `account` ( + `user_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, + `username` VARCHAR(255) NOT NULL, + `password` VARCHAR(60) NOT NULL, + `is_admin` BOOLEAN NOT NULL DEFAULT false, + `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + `updated_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + + UNIQUE INDEX `username`(`username`), + PRIMARY KEY (`user_id`) +) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + +-- CreateTable +CREATE TABLE `event` ( + `event_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, + `website_id` INTEGER UNSIGNED NOT NULL, + `session_id` INTEGER UNSIGNED NOT NULL, + `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + `url` VARCHAR(500) NOT NULL, + `event_type` VARCHAR(50) NOT NULL, + `event_value` VARCHAR(50) NOT NULL, + + INDEX `event_created_at_idx`(`created_at`), + INDEX `event_session_id_idx`(`session_id`), + INDEX `event_website_id_idx`(`website_id`), + PRIMARY KEY (`event_id`) +) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + +-- CreateTable +CREATE TABLE `pageview` ( + `view_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, + `website_id` INTEGER UNSIGNED NOT NULL, + `session_id` INTEGER UNSIGNED NOT NULL, + `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + `url` VARCHAR(500) NOT NULL, + `referrer` VARCHAR(500) NULL, + + INDEX `pageview_created_at_idx`(`created_at`), + INDEX `pageview_session_id_idx`(`session_id`), + INDEX `pageview_website_id_created_at_idx`(`website_id`, `created_at`), + INDEX `pageview_website_id_idx`(`website_id`), + INDEX `pageview_website_id_session_id_created_at_idx`(`website_id`, `session_id`, `created_at`), + PRIMARY KEY (`view_id`) +) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + +-- CreateTable +CREATE TABLE `session` ( + `session_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, + `session_uuid` VARCHAR(36) NOT NULL, + `website_id` INTEGER UNSIGNED NOT NULL, + `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + `hostname` VARCHAR(100) NULL, + `browser` VARCHAR(20) NULL, + `os` VARCHAR(20) NULL, + `device` VARCHAR(20) NULL, + `screen` VARCHAR(11) NULL, + `language` VARCHAR(35) NULL, + `country` CHAR(2) NULL, + + UNIQUE INDEX `session_uuid`(`session_uuid`), + INDEX `session_created_at_idx`(`created_at`), + INDEX `session_website_id_idx`(`website_id`), + PRIMARY KEY (`session_id`) +) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + +-- CreateTable +CREATE TABLE `website` ( + `website_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, + `website_uuid` VARCHAR(36) NOT NULL, + `user_id` INTEGER UNSIGNED NOT NULL, + `name` VARCHAR(100) NOT NULL, + `domain` VARCHAR(500) NULL, + `share_id` VARCHAR(64) NULL, + `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + + UNIQUE INDEX `website_uuid`(`website_uuid`), + UNIQUE INDEX `share_id`(`share_id`), + INDEX `website_user_id_idx`(`user_id`), + PRIMARY KEY (`website_id`) +) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + +-- AddForeignKey +ALTER TABLE `event` ADD CONSTRAINT `event_ibfk_2` FOREIGN KEY (`session_id`) REFERENCES `session`(`session_id`) ON DELETE CASCADE ON UPDATE NO ACTION; + +-- AddForeignKey +ALTER TABLE `event` ADD CONSTRAINT `event_ibfk_1` FOREIGN KEY (`website_id`) REFERENCES `website`(`website_id`) ON DELETE CASCADE ON UPDATE NO ACTION; + +-- AddForeignKey +ALTER TABLE `pageview` ADD CONSTRAINT `pageview_ibfk_2` FOREIGN KEY (`session_id`) REFERENCES `session`(`session_id`) ON DELETE CASCADE ON UPDATE NO ACTION; + +-- AddForeignKey +ALTER TABLE `pageview` ADD CONSTRAINT `pageview_ibfk_1` FOREIGN KEY (`website_id`) REFERENCES `website`(`website_id`) ON DELETE CASCADE ON UPDATE NO ACTION; + +-- AddForeignKey +ALTER TABLE `session` ADD CONSTRAINT `session_ibfk_1` FOREIGN KEY (`website_id`) REFERENCES `website`(`website_id`) ON DELETE CASCADE ON UPDATE NO ACTION; + +-- AddForeignKey +ALTER TABLE `website` ADD CONSTRAINT `website_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `account`(`user_id`) ON DELETE CASCADE ON UPDATE NO ACTION; diff --git a/db/mysql/schema.prisma b/db/mysql/schema.prisma index 40969d66..e2985142 100644 --- a/db/mysql/schema.prisma +++ b/db/mysql/schema.prisma @@ -9,7 +9,7 @@ datasource db { model account { user_id Int @id @default(autoincrement()) @db.UnsignedInt - username String @unique @db.VarChar(255) + username String @unique(map: "username") @db.VarChar(255) password String @db.VarChar(60) is_admin Boolean @default(false) created_at DateTime? @default(now()) @db.Timestamp(0) @@ -25,12 +25,12 @@ model event { url String @db.VarChar(500) event_type String @db.VarChar(50) event_value String @db.VarChar(50) - session session @relation(fields: [session_id], references: [session_id]) - website website @relation(fields: [website_id], references: [website_id]) + session session @relation(fields: [session_id], references: [session_id], onDelete: Cascade, onUpdate: NoAction, map: "event_ibfk_2") + website website @relation(fields: [website_id], references: [website_id], onDelete: Cascade, onUpdate: NoAction, map: "event_ibfk_1") - @@index([created_at], name: "event_created_at_idx") - @@index([session_id], name: "event_session_id_idx") - @@index([website_id], name: "event_website_id_idx") + @@index([created_at]) + @@index([session_id]) + @@index([website_id]) } model pageview { @@ -40,19 +40,19 @@ model pageview { created_at DateTime? @default(now()) @db.Timestamp(0) url String @db.VarChar(500) referrer String? @db.VarChar(500) - session session @relation(fields: [session_id], references: [session_id]) - website website @relation(fields: [website_id], references: [website_id]) + session session @relation(fields: [session_id], references: [session_id], onDelete: Cascade, onUpdate: NoAction, map: "pageview_ibfk_2") + website website @relation(fields: [website_id], references: [website_id], onDelete: Cascade, onUpdate: NoAction, map: "pageview_ibfk_1") - @@index([created_at], name: "pageview_created_at_idx") - @@index([session_id], name: "pageview_session_id_idx") - @@index([website_id, created_at], name: "pageview_website_id_created_at_idx") - @@index([website_id], name: "pageview_website_id_idx") - @@index([website_id, session_id, created_at], name: "pageview_website_id_session_id_created_at_idx") + @@index([created_at]) + @@index([session_id]) + @@index([website_id, created_at]) + @@index([website_id]) + @@index([website_id, session_id, created_at]) } model session { session_id Int @id @default(autoincrement()) @db.UnsignedInt - session_uuid String @unique @db.VarChar(36) + session_uuid String @unique(map: "session_uuid") @db.VarChar(36) website_id Int @db.UnsignedInt created_at DateTime? @default(now()) @db.Timestamp(0) hostname String? @db.VarChar(100) @@ -62,26 +62,26 @@ model session { screen String? @db.VarChar(11) language String? @db.VarChar(35) country String? @db.Char(2) - website website @relation(fields: [website_id], references: [website_id]) + website website @relation(fields: [website_id], references: [website_id], onDelete: Cascade, onUpdate: NoAction, map: "session_ibfk_1") event event[] pageview pageview[] - @@index([created_at], name: "session_created_at_idx") - @@index([website_id], name: "session_website_id_idx") + @@index([created_at]) + @@index([website_id]) } model website { website_id Int @id @default(autoincrement()) @db.UnsignedInt - website_uuid String @unique @db.VarChar(36) + website_uuid String @unique(map: "website_uuid") @db.VarChar(36) user_id Int @db.UnsignedInt name String @db.VarChar(100) domain String? @db.VarChar(500) - share_id String? @unique @db.VarChar(64) + share_id String? @unique(map: "share_id") @db.VarChar(64) created_at DateTime? @default(now()) @db.Timestamp(0) - account account @relation(fields: [user_id], references: [user_id]) + account account @relation(fields: [user_id], references: [user_id], onDelete: Cascade, onUpdate: NoAction, map: "website_ibfk_1") event event[] pageview pageview[] session session[] - @@index([user_id], name: "website_user_id_idx") + @@index([user_id]) }