Unify database changes. Closes #1264

This commit is contained in:
mike 2022-07-06 20:45:53 -07:00
parent af44380ea4
commit 5e0c5643c6
3 changed files with 214 additions and 134 deletions

View File

@ -9,7 +9,7 @@ CREATE TABLE `account` (
UNIQUE INDEX `username`(`username`), UNIQUE INDEX `username`(`username`),
PRIMARY KEY (`user_id`) PRIMARY KEY (`user_id`)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- CreateTable -- CreateTable
CREATE TABLE `event` ( CREATE TABLE `event` (
@ -25,7 +25,7 @@ CREATE TABLE `event` (
INDEX `event_session_id_idx`(`session_id`), INDEX `event_session_id_idx`(`session_id`),
INDEX `event_website_id_idx`(`website_id`), INDEX `event_website_id_idx`(`website_id`),
PRIMARY KEY (`event_id`) PRIMARY KEY (`event_id`)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- CreateTable -- CreateTable
CREATE TABLE `pageview` ( CREATE TABLE `pageview` (
@ -42,7 +42,7 @@ CREATE TABLE `pageview` (
INDEX `pageview_website_id_idx`(`website_id`), INDEX `pageview_website_id_idx`(`website_id`),
INDEX `pageview_website_id_session_id_created_at_idx`(`website_id`, `session_id`, `created_at`), INDEX `pageview_website_id_session_id_created_at_idx`(`website_id`, `session_id`, `created_at`),
PRIMARY KEY (`view_id`) PRIMARY KEY (`view_id`)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- CreateTable -- CreateTable
CREATE TABLE `session` ( CREATE TABLE `session` (
@ -62,7 +62,7 @@ CREATE TABLE `session` (
INDEX `session_created_at_idx`(`created_at`), INDEX `session_created_at_idx`(`created_at`),
INDEX `session_website_id_idx`(`website_id`), INDEX `session_website_id_idx`(`website_id`),
PRIMARY KEY (`session_id`) PRIMARY KEY (`session_id`)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- CreateTable -- CreateTable
CREATE TABLE `website` ( CREATE TABLE `website` (
@ -78,7 +78,7 @@ CREATE TABLE `website` (
UNIQUE INDEX `share_id`(`share_id`), UNIQUE INDEX `share_id`(`share_id`),
INDEX `website_user_id_idx`(`user_id`), INDEX `website_user_id_idx`(`user_id`),
PRIMARY KEY (`website_id`) PRIMARY KEY (`website_id`)
) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- AddForeignKey -- AddForeignKey
ALTER TABLE `event` ADD CONSTRAINT `event_ibfk_2` FOREIGN KEY (`session_id`) REFERENCES `session`(`session_id`) ON DELETE CASCADE ON UPDATE NO ACTION; ALTER TABLE `event` ADD CONSTRAINT `event_ibfk_2` FOREIGN KEY (`session_id`) REFERENCES `session`(`session_id`) ON DELETE CASCADE ON UPDATE NO ACTION;

View File

@ -1,80 +1,102 @@
drop table if exists event; -- CreateTable
drop table if exists pageview; CREATE TABLE `account` (
drop table if exists session; `user_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
drop table if exists website; `username` VARCHAR(255) NOT NULL,
drop table if exists account; `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),
create table account ( UNIQUE INDEX `username`(`username`),
user_id int unsigned not null auto_increment primary key, PRIMARY KEY (`user_id`)
username varchar(255) unique not null, ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
password varchar(60) not null,
is_admin bool not null default false,
created_at timestamp default current_timestamp,
updated_at timestamp default current_timestamp
) ENGINE=InnoDB COLLATE=utf8_general_ci;
create table website ( -- CreateTable
website_id int unsigned not null auto_increment primary key, CREATE TABLE `event` (
website_uuid varchar(36) unique not null, `event_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
user_id int unsigned not null, `website_id` INTEGER UNSIGNED NOT NULL,
name varchar(100) not null, `session_id` INTEGER UNSIGNED NOT NULL,
domain varchar(500), `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0),
share_id varchar(64) unique, `url` VARCHAR(500) NOT NULL,
created_at timestamp default current_timestamp, `event_type` VARCHAR(50) NOT NULL,
foreign key (user_id) references account(user_id) on delete cascade `event_value` VARCHAR(50) NOT NULL,
) ENGINE=InnoDB COLLATE=utf8_general_ci;
create table session ( INDEX `event_created_at_idx`(`created_at`),
session_id int unsigned not null auto_increment primary key, INDEX `event_session_id_idx`(`session_id`),
session_uuid varchar(36) unique not null, INDEX `event_website_id_idx`(`website_id`),
website_id int unsigned not null references website(website_id) on delete cascade, PRIMARY KEY (`event_id`)
created_at timestamp default current_timestamp, ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
hostname varchar(100),
browser varchar(20),
os varchar(20),
device varchar(20),
screen varchar(11),
language varchar(35),
country char(2),
foreign key (website_id) references website(website_id) on delete cascade
) ENGINE=InnoDB COLLATE=utf8_general_ci;
create table pageview ( -- CreateTable
view_id int unsigned not null auto_increment primary key, CREATE TABLE `pageview` (
website_id int unsigned not null, `view_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
session_id int unsigned not null, `website_id` INTEGER UNSIGNED NOT NULL,
created_at timestamp default current_timestamp, `session_id` INTEGER UNSIGNED NOT NULL,
url varchar(500) not null, `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0),
referrer varchar(500), `url` VARCHAR(500) NOT NULL,
foreign key (website_id) references website(website_id) on delete cascade, `referrer` VARCHAR(500) NULL,
foreign key (session_id) references session(session_id) on delete cascade
) ENGINE=InnoDB COLLATE=utf8_general_ci;
create table event ( INDEX `pageview_created_at_idx`(`created_at`),
event_id int unsigned not null auto_increment primary key, INDEX `pageview_session_id_idx`(`session_id`),
website_id int unsigned not null, INDEX `pageview_website_id_created_at_idx`(`website_id`, `created_at`),
session_id int unsigned not null, INDEX `pageview_website_id_idx`(`website_id`),
created_at timestamp default current_timestamp, INDEX `pageview_website_id_session_id_created_at_idx`(`website_id`, `session_id`, `created_at`),
url varchar(500) not null, PRIMARY KEY (`view_id`)
event_type varchar(50) not null, ) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
event_value varchar(50) not null,
foreign key (website_id) references website(website_id) on delete cascade,
foreign key (session_id) references session(session_id) on delete cascade
) ENGINE=InnoDB COLLATE=utf8_general_ci;
create index website_user_id_idx on website(user_id); -- 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,
create index session_created_at_idx on session(created_at); UNIQUE INDEX `session_uuid`(`session_uuid`),
create index session_website_id_idx on session(website_id); INDEX `session_created_at_idx`(`created_at`),
INDEX `session_website_id_idx`(`website_id`),
PRIMARY KEY (`session_id`)
) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
create index pageview_created_at_idx on pageview(created_at); -- CreateTable
create index pageview_website_id_idx on pageview(website_id); CREATE TABLE `website` (
create index pageview_session_id_idx on pageview(session_id); `website_id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
create index pageview_website_id_created_at_idx on pageview(website_id, created_at); `website_uuid` VARCHAR(36) NOT NULL,
create index pageview_website_id_session_id_created_at_idx on pageview(website_id, session_id, created_at); `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),
create index event_created_at_idx on event(created_at); UNIQUE INDEX `website_uuid`(`website_uuid`),
create index event_website_id_idx on event(website_id); UNIQUE INDEX `share_id`(`share_id`),
create index event_session_id_idx on event(session_id); INDEX `website_user_id_idx`(`user_id`),
PRIMARY KEY (`website_id`)
) ENGINE=InnoDB DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
insert into account (username, password, is_admin) values ('admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa', true); -- 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;
-- CreateAdminUser
INSERT INTO account (username, password, is_admin) values ('admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa', true);

View File

@ -1,74 +1,132 @@
drop table if exists event; -- CreateTable
drop table if exists pageview; CREATE TABLE "account" (
drop table if exists session; "user_id" SERIAL NOT NULL,
drop table if exists website; "username" VARCHAR(255) NOT NULL,
drop table if exists account; "password" VARCHAR(60) NOT NULL,
"is_admin" BOOLEAN NOT NULL DEFAULT false,
"created_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP,
create table account ( PRIMARY KEY ("user_id")
user_id serial primary key,
username varchar(255) unique not null,
password varchar(60) not null,
is_admin bool not null default false,
created_at timestamp with time zone default current_timestamp,
updated_at timestamp with time zone default current_timestamp
); );
create table website ( -- CreateTable
website_id serial primary key, CREATE TABLE "event" (
website_uuid uuid unique not null, "event_id" SERIAL NOT NULL,
user_id int not null references account(user_id) on delete cascade, "website_id" INTEGER NOT NULL,
name varchar(100) not null, "session_id" INTEGER NOT NULL,
domain varchar(500), "created_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP,
share_id varchar(64) unique, "url" VARCHAR(500) NOT NULL,
created_at timestamp with time zone default current_timestamp "event_type" VARCHAR(50) NOT NULL,
"event_value" VARCHAR(50) NOT NULL,
PRIMARY KEY ("event_id")
); );
create table session ( -- CreateTable
session_id serial primary key, CREATE TABLE "pageview" (
session_uuid uuid unique not null, "view_id" SERIAL NOT NULL,
website_id int not null references website(website_id) on delete cascade, "website_id" INTEGER NOT NULL,
created_at timestamp with time zone default current_timestamp, "session_id" INTEGER NOT NULL,
hostname varchar(100), "created_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP,
browser varchar(20), "url" VARCHAR(500) NOT NULL,
os varchar(20), "referrer" VARCHAR(500),
device varchar(20),
screen varchar(11), PRIMARY KEY ("view_id")
language varchar(35),
country char(2)
); );
create table pageview ( -- CreateTable
view_id serial primary key, CREATE TABLE "session" (
website_id int not null references website(website_id) on delete cascade, "session_id" SERIAL NOT NULL,
session_id int not null references session(session_id) on delete cascade, "session_uuid" UUID NOT NULL,
created_at timestamp with time zone default current_timestamp, "website_id" INTEGER NOT NULL,
url varchar(500) not null, "created_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP,
referrer varchar(500) "hostname" VARCHAR(100),
"browser" VARCHAR(20),
"os" VARCHAR(20),
"device" VARCHAR(20),
"screen" VARCHAR(11),
"language" VARCHAR(35),
"country" CHAR(2),
PRIMARY KEY ("session_id")
); );
create table event ( -- CreateTable
event_id serial primary key, CREATE TABLE "website" (
website_id int not null references website(website_id) on delete cascade, "website_id" SERIAL NOT NULL,
session_id int not null references session(session_id) on delete cascade, "website_uuid" UUID NOT NULL,
created_at timestamp with time zone default current_timestamp, "user_id" INTEGER NOT NULL,
url varchar(500) not null, "name" VARCHAR(100) NOT NULL,
event_type varchar(50) not null, "domain" VARCHAR(500),
event_value varchar(50) not null "share_id" VARCHAR(64),
"created_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY ("website_id")
); );
create index website_user_id_idx on website(user_id); -- CreateIndex
CREATE UNIQUE INDEX "account.username_unique" ON "account"("username");
create index session_created_at_idx on session(created_at); -- CreateIndex
create index session_website_id_idx on session(website_id); CREATE INDEX "event_created_at_idx" ON "event"("created_at");
create index pageview_created_at_idx on pageview(created_at); -- CreateIndex
create index pageview_website_id_idx on pageview(website_id); CREATE INDEX "event_session_id_idx" ON "event"("session_id");
create index pageview_session_id_idx on pageview(session_id);
create index pageview_website_id_created_at_idx on pageview(website_id, created_at);
create index pageview_website_id_session_id_created_at_idx on pageview(website_id, session_id, created_at);
create index event_created_at_idx on event(created_at); -- CreateIndex
create index event_website_id_idx on event(website_id); CREATE INDEX "event_website_id_idx" ON "event"("website_id");
create index event_session_id_idx on event(session_id);
insert into account (username, password, is_admin) values ('admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa', true); -- CreateIndex
CREATE INDEX "pageview_created_at_idx" ON "pageview"("created_at");
-- CreateIndex
CREATE INDEX "pageview_session_id_idx" ON "pageview"("session_id");
-- CreateIndex
CREATE INDEX "pageview_website_id_created_at_idx" ON "pageview"("website_id", "created_at");
-- CreateIndex
CREATE INDEX "pageview_website_id_idx" ON "pageview"("website_id");
-- CreateIndex
CREATE INDEX "pageview_website_id_session_id_created_at_idx" ON "pageview"("website_id", "session_id", "created_at");
-- CreateIndex
CREATE UNIQUE INDEX "session.session_uuid_unique" ON "session"("session_uuid");
-- CreateIndex
CREATE INDEX "session_created_at_idx" ON "session"("created_at");
-- CreateIndex
CREATE INDEX "session_website_id_idx" ON "session"("website_id");
-- CreateIndex
CREATE UNIQUE INDEX "website.website_uuid_unique" ON "website"("website_uuid");
-- CreateIndex
CREATE UNIQUE INDEX "website.share_id_unique" ON "website"("share_id");
-- CreateIndex
CREATE INDEX "website_user_id_idx" ON "website"("user_id");
-- AddForeignKey
ALTER TABLE "event" ADD FOREIGN KEY ("session_id") REFERENCES "session"("session_id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "event" ADD FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "pageview" ADD FOREIGN KEY ("session_id") REFERENCES "session"("session_id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "pageview" ADD FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "session" ADD FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "website" ADD FOREIGN KEY ("user_id") REFERENCES "account"("user_id") ON DELETE CASCADE ON UPDATE CASCADE;
-- CreateAdminUser
INSERT INTO account (username, password, is_admin) values ('admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa', true);