Validate db schema before startup
This commit is contained in:
@@ -3,13 +3,14 @@ package logs
|
||||
import (
|
||||
server "blackforestbytes.com/simplecloudnotifier"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/dbtools"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/impl/logs/schema"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/schema"
|
||||
"context"
|
||||
"database/sql"
|
||||
"errors"
|
||||
"fmt"
|
||||
"github.com/jmoiron/sqlx"
|
||||
_ "github.com/mattn/go-sqlite3"
|
||||
"github.com/rs/zerolog/log"
|
||||
"gogs.mikescher.com/BlackForestBytes/goext/langext"
|
||||
"gogs.mikescher.com/BlackForestBytes/goext/sq"
|
||||
"time"
|
||||
@@ -67,9 +68,20 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
defer cancel()
|
||||
|
||||
currschema, err := db.ReadSchema(ctx)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if currschema == 0 {
|
||||
|
||||
_, err = db.db.Exec(ctx, schema.LogsSchema1, sq.PP{})
|
||||
schemastr := schema.LogsSchema1
|
||||
|
||||
schemahash, err := sq.HashSqliteSchema(ctx, schemastr)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
_, err = db.db.Exec(ctx, schemastr, sq.PP{})
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@@ -79,7 +91,12 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
return err
|
||||
}
|
||||
|
||||
err = db.pp.Init(ctx)
|
||||
err = db.WriteMetaString(ctx, "schema_hash", schemahash)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
err = db.pp.Init(ctx) // Re-Init
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@@ -87,6 +104,31 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
return nil
|
||||
|
||||
} else if currschema == 1 {
|
||||
|
||||
schemHashDB, err := sq.HashSqliteDatabase(ctx, db.db)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
schemaHashMeta, err := db.ReadMetaString(ctx, "schema_hash")
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
schemHashAsset := schema.LogsHash1
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if schemHashDB != langext.Coalesce(schemaHashMeta, "") || langext.Coalesce(schemaHashMeta, "") != schemHashAsset {
|
||||
log.Debug().Str("schemHashDB", schemHashDB).Msg("Schema (logs db)")
|
||||
log.Debug().Str("schemaHashMeta", langext.Coalesce(schemaHashMeta, "")).Msg("Schema (logs db)")
|
||||
log.Debug().Str("schemHashAsset", schemHashAsset).Msg("Schema (logs db)")
|
||||
return errors.New("database schema does not match (logs db)")
|
||||
} else {
|
||||
log.Debug().Str("schemHash", schemHashDB).Msg("Verified Schema consistency (logs db)")
|
||||
}
|
||||
|
||||
return nil // current
|
||||
} else {
|
||||
return errors.New(fmt.Sprintf("Unknown DB schema: %d", currschema))
|
||||
|
@@ -1,6 +0,0 @@
|
||||
package schema
|
||||
|
||||
import _ "embed"
|
||||
|
||||
//go:embed schema_1.ddl
|
||||
var LogsSchema1 string
|
@@ -1,23 +0,0 @@
|
||||
|
||||
CREATE TABLE `logs`
|
||||
(
|
||||
log_id TEXT NOT NULL,
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
|
||||
PRIMARY KEY (log_id)
|
||||
) STRICT;
|
||||
|
||||
|
||||
CREATE TABLE `meta`
|
||||
(
|
||||
meta_key TEXT NOT NULL,
|
||||
value_int INTEGER NULL,
|
||||
value_txt TEXT NULL,
|
||||
value_real REAL NULL,
|
||||
value_blob BLOB NULL,
|
||||
|
||||
PRIMARY KEY (meta_key)
|
||||
) STRICT;
|
||||
|
||||
|
||||
INSERT INTO meta (meta_key, value_int) VALUES ('schema', 1)
|
@@ -1,7 +0,0 @@
|
||||
CREATE TABLE sqlite_master (
|
||||
type text,
|
||||
name text,
|
||||
tbl_name text,
|
||||
rootpage integer,
|
||||
sql text
|
||||
);
|
@@ -3,13 +3,14 @@ package primary
|
||||
import (
|
||||
server "blackforestbytes.com/simplecloudnotifier"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/dbtools"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/impl/primary/schema"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/schema"
|
||||
"context"
|
||||
"database/sql"
|
||||
"errors"
|
||||
"fmt"
|
||||
"github.com/jmoiron/sqlx"
|
||||
_ "github.com/mattn/go-sqlite3"
|
||||
"github.com/rs/zerolog/log"
|
||||
"gogs.mikescher.com/BlackForestBytes/goext/langext"
|
||||
"gogs.mikescher.com/BlackForestBytes/goext/sq"
|
||||
"time"
|
||||
@@ -67,9 +68,20 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
defer cancel()
|
||||
|
||||
currschema, err := db.ReadSchema(ctx)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if currschema == 0 {
|
||||
|
||||
_, err = db.db.Exec(ctx, schema.PrimarySchema3, sq.PP{})
|
||||
schemastr := schema.PrimarySchema3
|
||||
|
||||
schemahash, err := sq.HashSqliteSchema(ctx, schemastr)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
_, err = db.db.Exec(ctx, schemastr, sq.PP{})
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@@ -79,7 +91,12 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
return err
|
||||
}
|
||||
|
||||
err = db.pp.Init(ctx)
|
||||
err = db.WriteMetaString(ctx, "schema_hash", schemahash)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
err = db.pp.Init(ctx) // Re-Init
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@@ -89,8 +106,33 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
} else if currschema == 1 {
|
||||
return errors.New("cannot autom. upgrade schema 1")
|
||||
} else if currschema == 2 {
|
||||
return errors.New("cannot autom. upgrade schema 2") //TODO
|
||||
return errors.New("cannot autom. upgrade schema 2")
|
||||
} else if currschema == 3 {
|
||||
|
||||
schemHashDB, err := sq.HashSqliteDatabase(ctx, db.db)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
schemaHashMeta, err := db.ReadMetaString(ctx, "schema_hash")
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
schemHashAsset := schema.PrimaryHash3
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if schemHashDB != langext.Coalesce(schemaHashMeta, "") || langext.Coalesce(schemaHashMeta, "") != schemHashAsset {
|
||||
log.Debug().Str("schemHashDB", schemHashDB).Msg("Schema (primary db)")
|
||||
log.Debug().Str("schemaHashMeta", langext.Coalesce(schemaHashMeta, "")).Msg("Schema (primary db)")
|
||||
log.Debug().Str("schemHashAsset", schemHashAsset).Msg("Schema (primary db)")
|
||||
return errors.New("database schema does not match (primary db)")
|
||||
} else {
|
||||
log.Debug().Str("schemHash", schemHashDB).Msg("Verified Schema consistency (primary db)")
|
||||
}
|
||||
|
||||
return nil // current
|
||||
} else {
|
||||
return errors.New(fmt.Sprintf("Unknown DB schema: %d", currschema))
|
||||
|
@@ -1,12 +0,0 @@
|
||||
package schema
|
||||
|
||||
import _ "embed"
|
||||
|
||||
//go:embed schema_1.ddl
|
||||
var PrimarySchema1 string
|
||||
|
||||
//go:embed schema_2.ddl
|
||||
var PrimarySchema2 string
|
||||
|
||||
//go:embed schema_3.ddl
|
||||
var PrimarySchema3 string
|
@@ -1,38 +0,0 @@
|
||||
DROP TABLE IF EXISTS `users`;
|
||||
CREATE TABLE `users`
|
||||
(
|
||||
`user_id` INT(11) NOT NULL AUTO_INCREMENT,
|
||||
`user_key` VARCHAR(64) NOT NULL,
|
||||
`fcm_token` VARCHAR(256) NULL DEFAULT NULL,
|
||||
`messages_sent` INT(11) NOT NULL DEFAULT '0',
|
||||
`timestamp_created` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`timestamp_accessed` DATETIME NULL DEFAULT NULL,
|
||||
|
||||
`quota_today` INT(11) NOT NULL DEFAULT '0',
|
||||
`quota_day` DATE NULL DEFAULT NULL,
|
||||
|
||||
`is_pro` BIT NOT NULL DEFAULT 0,
|
||||
`pro_token` VARCHAR(256) NULL DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`user_id`)
|
||||
);
|
||||
|
||||
DROP TABLE IF EXISTS `messages`;
|
||||
CREATE TABLE `messages`
|
||||
(
|
||||
`message_id` INT(11) NOT NULL AUTO_INCREMENT,
|
||||
`sender_user_id` INT(11) NOT NULL,
|
||||
|
||||
`timestamp_real` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`ack` TINYINT(1) NOT NULL DEFAULT 0,
|
||||
|
||||
`title` VARCHAR(256) NOT NULL,
|
||||
`content` LONGTEXT NULL,
|
||||
`priority` INT(11) NOT NULL,
|
||||
`sendtime` BIGINT UNSIGNED NOT NULL,
|
||||
|
||||
`fcm_message_id` VARCHAR(256) NULL,
|
||||
`usr_message_id` VARCHAR(256) NULL,
|
||||
|
||||
PRIMARY KEY (`message_id`)
|
||||
);
|
@@ -1,47 +0,0 @@
|
||||
CREATE TABLE `users`
|
||||
(
|
||||
`user_id` INTEGER AUTO_INCREMENT,
|
||||
`user_key` TEXT NOT NULL,
|
||||
`fcm_token` TEXT NULL DEFAULT NULL,
|
||||
`messages_sent` INTEGER NOT NULL DEFAULT '0',
|
||||
`timestamp_created` TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`timestamp_accessed` TEXT NULL DEFAULT NULL,
|
||||
|
||||
`quota_today` INTEGER NOT NULL DEFAULT '0',
|
||||
`quota_day` TEXT NULL DEFAULT NULL,
|
||||
|
||||
`is_pro` INTEGER NOT NULL DEFAULT 0,
|
||||
`pro_token` TEXT NULL DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`user_id`)
|
||||
);
|
||||
|
||||
CREATE TABLE `messages`
|
||||
(
|
||||
`message_id` INTEGER AUTO_INCREMENT,
|
||||
`sender_user_id` INTEGER NOT NULL,
|
||||
|
||||
`timestamp_real` TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`ack` INTEGER NOT NULL DEFAULT 0,
|
||||
|
||||
`title` TEXT NOT NULL,
|
||||
`content` TEXT NULL,
|
||||
`priority` INTEGER NOT NULL,
|
||||
`sendtime` INTEGER NOT NULL,
|
||||
|
||||
`fcm_message_id` TEXT NULL,
|
||||
`usr_message_id` TEXT NULL,
|
||||
|
||||
PRIMARY KEY (`message_id`)
|
||||
);
|
||||
|
||||
CREATE TABLE `meta`
|
||||
(
|
||||
`key` TEXT NOT NULL,
|
||||
`value_int` INTEGER NULL,
|
||||
`value_txt` TEXT NULL,
|
||||
|
||||
PRIMARY KEY (`key`)
|
||||
);
|
||||
|
||||
INSERT INTO meta (key, value_int) VALUES ('schema', 2)
|
@@ -1,236 +0,0 @@
|
||||
CREATE TABLE users
|
||||
(
|
||||
user_id TEXT NOT NULL,
|
||||
|
||||
username TEXT NULL DEFAULT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
timestamp_lastread INTEGER NULL DEFAULT NULL,
|
||||
timestamp_lastsent INTEGER NULL DEFAULT NULL,
|
||||
|
||||
messages_sent INTEGER NOT NULL DEFAULT '0',
|
||||
|
||||
quota_used INTEGER NOT NULL DEFAULT '0',
|
||||
quota_used_day TEXT NULL DEFAULT NULL,
|
||||
|
||||
is_pro INTEGER CHECK(is_pro IN (0, 1)) NOT NULL DEFAULT 0,
|
||||
pro_token TEXT NULL DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (user_id)
|
||||
) STRICT;
|
||||
CREATE UNIQUE INDEX "idx_users_protoken" ON users (pro_token) WHERE pro_token IS NOT NULL;
|
||||
|
||||
|
||||
CREATE TABLE keytokens
|
||||
(
|
||||
keytoken_id TEXT NOT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
timestamp_lastused INTEGER NULL DEFAULT NULL,
|
||||
|
||||
name TEXT NOT NULL,
|
||||
|
||||
owner_user_id TEXT NOT NULL,
|
||||
|
||||
all_channels INTEGER CHECK(all_channels IN (0, 1)) NOT NULL,
|
||||
channels TEXT NOT NULL,
|
||||
token TEXT NOT NULL,
|
||||
permissions TEXT NOT NULL,
|
||||
|
||||
messages_sent INTEGER NOT NULL DEFAULT '0',
|
||||
|
||||
PRIMARY KEY (keytoken_id)
|
||||
) STRICT;
|
||||
CREATE UNIQUE INDEX "idx_keytokens_token" ON keytokens (token);
|
||||
|
||||
|
||||
CREATE TABLE clients
|
||||
(
|
||||
client_id TEXT NOT NULL,
|
||||
|
||||
user_id TEXT NOT NULL,
|
||||
type TEXT CHECK(type IN ('ANDROID', 'IOS')) NOT NULL,
|
||||
fcm_token TEXT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
|
||||
agent_model TEXT NOT NULL,
|
||||
agent_version TEXT NOT NULL,
|
||||
|
||||
PRIMARY KEY (client_id)
|
||||
) STRICT;
|
||||
CREATE INDEX "idx_clients_userid" ON clients (user_id);
|
||||
CREATE UNIQUE INDEX "idx_clients_fcmtoken" ON clients (fcm_token);
|
||||
|
||||
|
||||
CREATE TABLE channels
|
||||
(
|
||||
channel_id TEXT NOT NULL,
|
||||
|
||||
owner_user_id TEXT NOT NULL,
|
||||
|
||||
internal_name TEXT NOT NULL,
|
||||
display_name TEXT NOT NULL,
|
||||
description_name TEXT NULL,
|
||||
|
||||
subscribe_key TEXT NOT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
timestamp_lastsent INTEGER NULL DEFAULT NULL,
|
||||
|
||||
messages_sent INTEGER NOT NULL DEFAULT '0',
|
||||
|
||||
PRIMARY KEY (channel_id)
|
||||
) STRICT;
|
||||
CREATE UNIQUE INDEX "idx_channels_identity" ON channels (owner_user_id, internal_name);
|
||||
|
||||
CREATE TABLE subscriptions
|
||||
(
|
||||
subscription_id TEXT NOT NULL,
|
||||
|
||||
subscriber_user_id TEXT NOT NULL,
|
||||
channel_owner_user_id TEXT NOT NULL,
|
||||
channel_internal_name TEXT NOT NULL,
|
||||
channel_id TEXT NOT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
|
||||
confirmed INTEGER CHECK(confirmed IN (0, 1)) NOT NULL,
|
||||
|
||||
PRIMARY KEY (subscription_id)
|
||||
) STRICT;
|
||||
CREATE UNIQUE INDEX "idx_subscriptions_ref" ON subscriptions (subscriber_user_id, channel_owner_user_id, channel_internal_name);
|
||||
CREATE INDEX "idx_subscriptions_chan" ON subscriptions (channel_id);
|
||||
CREATE INDEX "idx_subscriptions_subuser" ON subscriptions (subscriber_user_id);
|
||||
CREATE INDEX "idx_subscriptions_ownuser" ON subscriptions (channel_owner_user_id);
|
||||
CREATE INDEX "idx_subscriptions_tsc" ON subscriptions (timestamp_created);
|
||||
CREATE INDEX "idx_subscriptions_conf" ON subscriptions (confirmed);
|
||||
|
||||
|
||||
CREATE TABLE messages
|
||||
(
|
||||
message_id TEXT NOT NULL,
|
||||
sender_user_id TEXT NOT NULL,
|
||||
owner_user_id TEXT NOT NULL,
|
||||
channel_internal_name TEXT NOT NULL,
|
||||
channel_id TEXT NOT NULL,
|
||||
sender_ip TEXT NOT NULL,
|
||||
sender_name TEXT NULL,
|
||||
|
||||
timestamp_real INTEGER NOT NULL,
|
||||
timestamp_client INTEGER NULL,
|
||||
|
||||
title TEXT NOT NULL,
|
||||
content TEXT NULL,
|
||||
priority INTEGER CHECK(priority IN (0, 1, 2)) NOT NULL,
|
||||
usr_message_id TEXT NULL,
|
||||
|
||||
used_key_id TEXT NOT NULL,
|
||||
|
||||
deleted INTEGER CHECK(deleted IN (0, 1)) NOT NULL DEFAULT '0',
|
||||
|
||||
PRIMARY KEY (message_id)
|
||||
) STRICT;
|
||||
CREATE INDEX "idx_messages_owner_channel" ON messages (owner_user_id, channel_internal_name COLLATE BINARY);
|
||||
CREATE INDEX "idx_messages_owner_channel_nc" ON messages (owner_user_id, channel_internal_name COLLATE NOCASE);
|
||||
CREATE INDEX "idx_messages_channel" ON messages (channel_internal_name COLLATE BINARY);
|
||||
CREATE INDEX "idx_messages_channel_nc" ON messages (channel_internal_name COLLATE NOCASE);
|
||||
CREATE UNIQUE INDEX "idx_messages_idempotency" ON messages (owner_user_id, usr_message_id COLLATE BINARY);
|
||||
CREATE INDEX "idx_messages_senderip" ON messages (sender_ip COLLATE BINARY);
|
||||
CREATE INDEX "idx_messages_sendername" ON messages (sender_name COLLATE BINARY);
|
||||
CREATE INDEX "idx_messages_sendername_nc" ON messages (sender_name COLLATE NOCASE);
|
||||
CREATE INDEX "idx_messages_title" ON messages (title COLLATE BINARY);
|
||||
CREATE INDEX "idx_messages_title_nc" ON messages (title COLLATE NOCASE);
|
||||
CREATE INDEX "idx_messages_usedkey" ON messages (owner_user_id, used_key_id);
|
||||
CREATE INDEX "idx_messages_deleted" ON messages (deleted);
|
||||
|
||||
|
||||
CREATE VIRTUAL TABLE messages_fts USING fts5
|
||||
(
|
||||
channel_internal_name,
|
||||
sender_name,
|
||||
title,
|
||||
content,
|
||||
|
||||
tokenize = unicode61,
|
||||
content = 'messages',
|
||||
content_rowid = 'rowid'
|
||||
);
|
||||
|
||||
CREATE TRIGGER fts_insert AFTER INSERT ON messages BEGIN
|
||||
INSERT INTO messages_fts (rowid, channel_internal_name, sender_name, title, content) VALUES (new.rowid, new.channel_internal_name, new.sender_name, new.title, new.content);
|
||||
END;
|
||||
|
||||
CREATE TRIGGER fts_update AFTER UPDATE ON messages BEGIN
|
||||
INSERT INTO messages_fts (messages_fts, rowid, channel_internal_name, sender_name, title, content) VALUES ('delete', old.rowid, old.channel_internal_name, old.sender_name, old.title, old.content);
|
||||
INSERT INTO messages_fts ( rowid, channel_internal_name, sender_name, title, content) VALUES ( new.rowid, new.channel_internal_name, new.sender_name, new.title, new.content);
|
||||
END;
|
||||
|
||||
CREATE TRIGGER fts_delete AFTER DELETE ON messages BEGIN
|
||||
INSERT INTO messages_fts (messages_fts, rowid, channel_internal_name, sender_name, title, content) VALUES ('delete', old.rowid, old.channel_internal_name, old.sender_name, old.title, old.content);
|
||||
END;
|
||||
|
||||
|
||||
CREATE TABLE deliveries
|
||||
(
|
||||
delivery_id TEXT NOT NULL,
|
||||
|
||||
message_id TEXT NOT NULL,
|
||||
receiver_user_id TEXT NOT NULL,
|
||||
receiver_client_id TEXT NOT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
timestamp_finalized INTEGER NULL,
|
||||
|
||||
|
||||
status TEXT CHECK(status IN ('RETRY','SUCCESS','FAILED')) NOT NULL,
|
||||
retry_count INTEGER NOT NULL DEFAULT 0,
|
||||
next_delivery TEXT NULL DEFAULT NULL,
|
||||
|
||||
fcm_message_id TEXT NULL,
|
||||
|
||||
PRIMARY KEY (delivery_id)
|
||||
) STRICT;
|
||||
CREATE INDEX "idx_deliveries_receiver" ON deliveries (message_id, receiver_client_id);
|
||||
|
||||
|
||||
CREATE TABLE compat_ids
|
||||
(
|
||||
old INTEGER NOT NULL,
|
||||
new TEXT NOT NULL,
|
||||
type TEXT NOT NULL
|
||||
) STRICT;
|
||||
CREATE UNIQUE INDEX "idx_compatids_new" ON compat_ids (new);
|
||||
CREATE UNIQUE INDEX "idx_compatids_old" ON compat_ids (old, type);
|
||||
|
||||
|
||||
CREATE TABLE compat_acks
|
||||
(
|
||||
user_id TEXT NOT NULL,
|
||||
message_id TEXT NOT NULL
|
||||
) STRICT;
|
||||
CREATE INDEX "idx_compatacks_userid" ON compat_acks (user_id);
|
||||
CREATE UNIQUE INDEX "idx_compatacks_messageid" ON compat_acks (message_id);
|
||||
CREATE UNIQUE INDEX "idx_compatacks_userid_messageid" ON compat_acks (user_id, message_id);
|
||||
|
||||
|
||||
CREATE TABLE compat_clients
|
||||
(
|
||||
client_id TEXT NOT NULL
|
||||
) STRICT;
|
||||
CREATE UNIQUE INDEX "idx_compatclient_clientid" ON compat_clients (client_id);
|
||||
|
||||
|
||||
CREATE TABLE `meta`
|
||||
(
|
||||
meta_key TEXT NOT NULL,
|
||||
value_int INTEGER NULL,
|
||||
value_txt TEXT NULL,
|
||||
value_real REAL NULL,
|
||||
value_blob BLOB NULL,
|
||||
|
||||
PRIMARY KEY (meta_key)
|
||||
) STRICT;
|
||||
|
||||
|
||||
INSERT INTO meta (meta_key, value_int) VALUES ('schema', 3)
|
@@ -1,7 +0,0 @@
|
||||
CREATE TABLE sqlite_master (
|
||||
type text,
|
||||
name text,
|
||||
tbl_name text,
|
||||
rootpage integer,
|
||||
sql text
|
||||
);
|
@@ -3,13 +3,14 @@ package requests
|
||||
import (
|
||||
server "blackforestbytes.com/simplecloudnotifier"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/dbtools"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/impl/requests/schema"
|
||||
"blackforestbytes.com/simplecloudnotifier/db/schema"
|
||||
"context"
|
||||
"database/sql"
|
||||
"errors"
|
||||
"fmt"
|
||||
"github.com/jmoiron/sqlx"
|
||||
_ "github.com/mattn/go-sqlite3"
|
||||
"github.com/rs/zerolog/log"
|
||||
"gogs.mikescher.com/BlackForestBytes/goext/langext"
|
||||
"gogs.mikescher.com/BlackForestBytes/goext/sq"
|
||||
"time"
|
||||
@@ -67,9 +68,20 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
defer cancel()
|
||||
|
||||
currschema, err := db.ReadSchema(ctx)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if currschema == 0 {
|
||||
|
||||
_, err = db.db.Exec(ctx, schema.RequestsSchema1, sq.PP{})
|
||||
schemastr := schema.RequestsSchema1
|
||||
|
||||
schemahash, err := sq.HashSqliteSchema(ctx, schemastr)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
_, err = db.db.Exec(ctx, schemastr, sq.PP{})
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@@ -79,7 +91,12 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
return err
|
||||
}
|
||||
|
||||
err = db.pp.Init(ctx)
|
||||
err = db.WriteMetaString(ctx, "schema_hash", schemahash)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
err = db.pp.Init(ctx) // Re-Init
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@@ -87,6 +104,31 @@ func (db *Database) Migrate(ctx context.Context) error {
|
||||
return nil
|
||||
|
||||
} else if currschema == 1 {
|
||||
|
||||
schemHashDB, err := sq.HashSqliteDatabase(ctx, db.db)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
schemaHashMeta, err := db.ReadMetaString(ctx, "schema_hash")
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
schemHashAsset := schema.RequestsHash1
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if schemHashDB != langext.Coalesce(schemaHashMeta, "") || langext.Coalesce(schemaHashMeta, "") != schemHashAsset {
|
||||
log.Debug().Str("schemHashDB", schemHashDB).Msg("Schema (requests db)")
|
||||
log.Debug().Str("schemaHashMeta", langext.Coalesce(schemaHashMeta, "")).Msg("Schema (requests db)")
|
||||
log.Debug().Str("schemHashAsset", schemHashAsset).Msg("Schema (requests db)")
|
||||
return errors.New("database schema does not match (requests db)")
|
||||
} else {
|
||||
log.Debug().Str("schemHash", schemHashDB).Msg("Verified Schema consistency (requests db)")
|
||||
}
|
||||
|
||||
return nil // current
|
||||
} else {
|
||||
return errors.New(fmt.Sprintf("Unknown DB schema: %d", currschema))
|
||||
|
@@ -1,6 +0,0 @@
|
||||
package schema
|
||||
|
||||
import _ "embed"
|
||||
|
||||
//go:embed schema_1.ddl
|
||||
var RequestsSchema1 string
|
@@ -1,48 +0,0 @@
|
||||
|
||||
CREATE TABLE `requests`
|
||||
(
|
||||
request_id TEXT NOT NULL,
|
||||
|
||||
method TEXT NOT NULL,
|
||||
uri TEXT NOT NULL,
|
||||
user_agent TEXT NULL,
|
||||
authentication TEXT NULL,
|
||||
request_body TEXT NULL,
|
||||
request_body_size INTEGER NOT NULL,
|
||||
request_content_type TEXT NOT NULL,
|
||||
remote_ip TEXT NOT NULL,
|
||||
key_id TEXT NULL,
|
||||
|
||||
userid TEXT NULL,
|
||||
permissions TEXT NULL,
|
||||
|
||||
response_statuscode INTEGER NULL,
|
||||
response_body_size INTEGER NULL,
|
||||
response_body TEXT NULL,
|
||||
response_content_type TEXT NOT NULL,
|
||||
processing_time INTEGER NOT NULL,
|
||||
retry_count INTEGER NOT NULL,
|
||||
panicked INTEGER CHECK(panicked IN (0, 1)) NOT NULL,
|
||||
panic_str TEXT NULL,
|
||||
|
||||
timestamp_created INTEGER NOT NULL,
|
||||
timestamp_start INTEGER NOT NULL,
|
||||
timestamp_finish INTEGER NOT NULL,
|
||||
|
||||
PRIMARY KEY (request_id)
|
||||
) STRICT;
|
||||
|
||||
|
||||
CREATE TABLE `meta`
|
||||
(
|
||||
meta_key TEXT NOT NULL,
|
||||
value_int INTEGER NULL,
|
||||
value_txt TEXT NULL,
|
||||
value_real REAL NULL,
|
||||
value_blob BLOB NULL,
|
||||
|
||||
PRIMARY KEY (meta_key)
|
||||
) STRICT;
|
||||
|
||||
|
||||
INSERT INTO meta (meta_key, value_int) VALUES ('schema', 1)
|
@@ -1,7 +0,0 @@
|
||||
CREATE TABLE sqlite_master (
|
||||
type text,
|
||||
name text,
|
||||
tbl_name text,
|
||||
rootpage integer,
|
||||
sql text
|
||||
);
|
Reference in New Issue
Block a user