SQLite support

pull/1292/head
Maxime-J 2022-08-11 17:32:00 +00:00
parent 2181ca4ec8
commit 578a96ee09
7 changed files with 319 additions and 5 deletions

View File

@ -0,0 +1,120 @@
-- CreateTable
CREATE TABLE "account" (
"user_id" INTEGER NOT NULL,
"username" TEXT NOT NULL,
"password" TEXT NOT NULL,
"is_admin" INTEGER NOT NULL DEFAULT 0,
"created_at" DATETIME DEFAULT (strftime('%s000', 'now')),
"updated_at" DATETIME DEFAULT (strftime('%s000', 'now')),
PRIMARY KEY ("user_id")
);
-- CreateTable
CREATE TABLE "event" (
"event_id" INTEGER NOT NULL,
"website_id" INTEGER NOT NULL,
"session_id" INTEGER NOT NULL,
"created_at" DATETIME DEFAULT (strftime('%s000', 'now')),
"url" TEXT NOT NULL,
"event_type" TEXT NOT NULL,
"event_value" TEXT NOT NULL,
PRIMARY KEY ("event_id"),
FOREIGN KEY ("session_id") REFERENCES "session"("session_id") ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE
);
-- CreateTable
CREATE TABLE "pageview" (
"view_id" INTEGER NOT NULL,
"website_id" INTEGER NOT NULL,
"session_id" INTEGER NOT NULL,
"created_at" DATETIME DEFAULT (strftime('%s000', 'now')),
"url" TEXT NOT NULL,
"referrer" TEXT,
PRIMARY KEY ("view_id"),
FOREIGN KEY ("session_id") REFERENCES "session"("session_id") ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE
);
-- CreateTable
CREATE TABLE "session" (
"session_id" INTEGER NOT NULL,
"session_uuid" TEXT NOT NULL,
"website_id" INTEGER NOT NULL,
"created_at" DATETIME DEFAULT (strftime('%s000', 'now')),
"hostname" TEXT,
"browser" TEXT,
"os" TEXT,
"device" TEXT,
"screen" TEXT,
"language" TEXT,
"country" TEXT,
PRIMARY KEY ("session_id"),
FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE
);
-- CreateTable
CREATE TABLE "website" (
"website_id" INTEGER NOT NULL,
"website_uuid" TEXT NOT NULL,
"user_id" INTEGER NOT NULL,
"name" TEXT NOT NULL,
"domain" TEXT,
"share_id" TEXT,
"created_at" DATETIME DEFAULT (strftime('%s000', 'now')),
PRIMARY KEY ("website_id"),
FOREIGN KEY ("user_id") REFERENCES "account"("user_id") ON DELETE CASCADE ON UPDATE CASCADE
);
-- CreateIndex
CREATE UNIQUE INDEX "account.username_unique" ON "account"("username");
-- CreateIndex
CREATE INDEX "event_created_at_idx" ON "event"("created_at");
-- CreateIndex
CREATE INDEX "event_session_id_idx" ON "event"("session_id");
-- CreateIndex
CREATE INDEX "event_website_id_idx" ON "event"("website_id");
-- 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");
-- CreateAdminUser
INSERT INTO account (username, password, is_admin) values ('admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa', true);

View File

@ -0,0 +1,55 @@
-- DropTable
DROP TABLE "event";
-- CreateTable
CREATE TABLE "event" (
"event_id" INTEGER NOT NULL,
"website_id" INTEGER NOT NULL,
"session_id" INTEGER NOT NULL,
"created_at" DATETIME DEFAULT (strftime('%s000', 'now')),
"url" TEXT NOT NULL,
"event_name" TEXT NOT NULL,
PRIMARY KEY ("event_id"),
CONSTRAINT "event_session_id_fkey" FOREIGN KEY ("session_id") REFERENCES "session"("session_id") ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT "event_website_id_fkey" FOREIGN KEY ("website_id") REFERENCES "website"("website_id") ON DELETE CASCADE ON UPDATE CASCADE
);
-- CreateIndex
CREATE INDEX "event_created_at_idx" ON "event"("created_at");
-- CreateIndex
CREATE INDEX "event_session_id_idx" ON "event"("session_id");
-- CreateIndex
CREATE INDEX "event_website_id_idx" ON "event"("website_id");
-- CreateTable
CREATE TABLE "event_data" (
"event_data_id" INTEGER NOT NULL,
"event_id" INTEGER NOT NULL,
"event_data" TEXT NOT NULL,
CONSTRAINT "event_data_pkey" PRIMARY KEY ("event_data_id"),
CONSTRAINT "event_data_event_id_fkey" FOREIGN KEY ("event_id") REFERENCES "event"("event_id") ON DELETE RESTRICT ON UPDATE CASCADE
);
-- CreateIndex
CREATE UNIQUE INDEX "event_data_event_id_key" ON "event_data"("event_id");
-- RenameIndex
DROP INDEX "account.username_unique";
CREATE UNIQUE INDEX "account_username_key" ON "account"("username");
-- RenameIndex
DROP INDEX "session.session_uuid_unique";
CREATE UNIQUE INDEX "session_session_uuid_key" ON "session"("session_uuid");
-- RenameIndex
DROP INDEX "website.share_id_unique";
CREATE UNIQUE INDEX "website_share_id_key" ON "website"("share_id");
-- RenameIndex
DROP INDEX "website.website_uuid_unique";
CREATE UNIQUE INDEX "website_website_uuid_key" ON "website"("website_uuid");

View File

@ -0,0 +1,3 @@
# Please do not edit this file manually
# It should be added in your version-control system (i.e. Git)
provider = "sqlite"

94
db/sqlite/schema.prisma Normal file
View File

@ -0,0 +1,94 @@
generator client {
provider = "prisma-client-js"
}
datasource db {
provider = "sqlite"
url = env("DATABASE_URL")
}
model account {
user_id Int @id @default(autoincrement())
username String @unique
password String
is_admin Boolean @default(false)
created_at DateTime? @default(now())
updated_at DateTime? @default(now())
website website[]
}
model event {
event_id Int @id @default(autoincrement())
website_id Int
session_id Int
created_at DateTime? @default(now())
url String
event_name String
session session @relation(fields: [session_id], references: [session_id], onDelete: Cascade)
website website @relation(fields: [website_id], references: [website_id], onDelete: Cascade)
event_data event_data?
@@index([created_at])
@@index([session_id])
@@index([website_id])
}
model event_data {
event_data_id Int @id @default(autoincrement())
event_id Int @unique
event_data Json
event event @relation(fields: [event_id], references: [event_id])
}
model pageview {
view_id Int @id @default(autoincrement())
website_id Int
session_id Int
created_at DateTime? @default(now())
url String
referrer String?
session session @relation(fields: [session_id], references: [session_id], onDelete: Cascade)
website website @relation(fields: [website_id], references: [website_id], onDelete: Cascade)
@@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())
session_uuid String @unique
website_id Int
created_at DateTime? @default(now())
hostname String?
browser String?
os String?
device String?
screen String?
language String?
country String?
website website @relation(fields: [website_id], references: [website_id], onDelete: Cascade)
pageview pageview[]
event event[]
@@index([created_at])
@@index([website_id])
}
model website {
website_id Int @id @default(autoincrement())
website_uuid String @unique
user_id Int
name String
domain String?
share_id String? @unique
created_at DateTime? @default(now())
account account @relation(fields: [user_id], references: [user_id], onDelete: Cascade)
pageview pageview[]
session session[]
event event[]
@@index([user_id])
}

View File

@ -70,6 +70,7 @@ export const EVENT_COLORS = [
export const RELATIONAL = 'relational';
export const POSTGRESQL = 'postgresql';
export const MYSQL = 'mysql';
export const SQLITE = 'sqlite';
export const CLICKHOUSE = 'clickhouse';
export const MYSQL_DATE_FORMATS = {
@ -88,6 +89,14 @@ export const POSTGRESQL_DATE_FORMATS = {
year: 'YYYY-01-01',
};
export const SQLITE_DATE_FORMATS = {
minute: '%Y-%m-%d %H:%M:00',
hour: '%Y-%m-%d %H:00:00',
day: '%Y-%m-%d',
month: '%Y-%m-01',
year: '%Y-01-01',
};
export const CLICKHOUSE_DATE_FORMATS = {
minute: '%Y-%m-%d %H:%M:00',
hour: '%Y-%m-%d %H:00:00',

View File

@ -6,6 +6,8 @@ import {
MYSQL_DATE_FORMATS,
POSTGRESQL,
POSTGRESQL_DATE_FORMATS,
SQLITE,
SQLITE_DATE_FORMATS,
CLICKHOUSE,
RELATIONAL,
FILTER_IGNORED,
@ -83,6 +85,10 @@ export function getDatabase() {
return POSTGRESQL;
}
if (type === 'file') {
return SQLITE;
}
return type;
}
@ -95,6 +101,10 @@ export function getAnalyticsDatabase() {
return POSTGRESQL;
}
if (type === 'file') {
return SQLITE;
}
if (!type) {
return getDatabase();
}
@ -122,9 +132,16 @@ export function getDateQuery(field, unit, timezone) {
return `date_format(convert_tz(${field},'+00:00','${tz}'), '${MYSQL_DATE_FORMATS[unit]}')`;
}
return `date_format(${field}, '${MYSQL_DATE_FORMATS[unit]}')`;
}
if (db === SQLITE) {
if(timezone) {
const tz = moment.tz(timezone).format('Z').substring(0,3);
return `strftime('${SQLITE_DATE_FORMATS[unit]}', substr(${field}, 1, LENGTH(${field}) - 3), 'unixepoch', '${tz} hours')`;
}
return `strftime('${SQLITE_DATE_FORMATS[unit]}', substr(${field}, 1, LENGTH(${field}) - 3), 'unixepoch')`;
}
}
export function getDateQueryClickhouse(field, unit, timezone) {
@ -153,6 +170,10 @@ export function getTimestampInterval(field) {
if (db === MYSQL) {
return `floor(unix_timestamp(max(${field})) - unix_timestamp(min(${field})))`;
}
if (db === SQLITE) {
return `max(substr(${field}, 1, LENGTH(${field}) - 3)) - min(substr(${field}, 1, LENGTH(${field}) - 3))`;
}
}
export function getFilterQuery(table, column, filters = {}, params = []) {
@ -265,11 +286,19 @@ export async function runQuery(query) {
export async function rawQuery(query, params = []) {
const db = getDatabase();
if (db !== POSTGRESQL && db !== MYSQL) {
if (db !== POSTGRESQL && db !== MYSQL && db !== SQLITE) {
return Promise.reject(new Error('Unknown database.'));
}
const sql = db === MYSQL ? query.replace(/\$[0-9]+/g, '?') : query;
const sql = db !== POSTGRESQL ? query.replace(/\$[0-9]+/g, '?') : query;
if (db === SQLITE) {
params.forEach((param, index) => {
if (param instanceof Date) {
params[index] = param.getTime();
}
});
}
return runQuery(prisma.$queryRawUnsafe.apply(prisma, [sql, ...params]));
}
@ -295,7 +324,7 @@ export async function findUnique(data) {
export async function runAnalyticsQuery(queries) {
const db = getAnalyticsDatabase();
if (db === POSTGRESQL || db === MYSQL) {
if (db === POSTGRESQL || db === MYSQL || db === SQLITE) {
return queries[RELATIONAL]();
}

View File

@ -12,12 +12,16 @@ function getDatabaseType() {
return 'postgresql';
}
if (type === 'file') {
return 'sqlite';
}
return type;
}
const databaseType = getDatabaseType();
if (!databaseType || !['mysql', 'postgresql'].includes(databaseType)) {
if (!databaseType || !['mysql', 'postgresql', 'sqlite'].includes(databaseType)) {
throw new Error('Missing or invalid database');
}