add init-db

This commit is contained in:
ridethepig 2022-12-12 23:24:00 +08:00
parent 773175b904
commit ef95becfd0
7 changed files with 307 additions and 8 deletions

5
MANIFEST.in Normal file
View File

@ -0,0 +1,5 @@
include src/sql/db_create.sql
include src/sql/trigger.sql
graft src/static
graft src/templates
global-exclude *.pyc

11
setup.py Normal file
View File

@ -0,0 +1,11 @@
from setuptools import find_packages, setup
setup(
name='ebookman',
version='1.0.0',
packages=find_packages(),
include_package_data=True,
install_requires=[
'flask',
],
)

View File

@ -13,7 +13,7 @@ def create_app(test_config=None):
# app.config['UPLOADDIR'] = os.path.join(app.instance_path, )
if not os.path.exists(app.config['UPLOADDIR']):
os.mkdir(app.config['UPLOADDIR'])
print(app.config.keys())
# print(app.config.keys())
print(app.instance_path)
try:
os.makedirs(app.instance_path)

View File

@ -26,20 +26,54 @@ def close_db(e=None):
if db is not None:
db.close()
def parse_sql(filename):
data = open(filename, 'r').readlines()
stmts = []
DELIMITER = ';'
stmt = ''
for lineno, line in enumerate(data):
if not line.strip():
continue
if line.startswith('--'):
continue
if 'DELIMITER' in line:
DELIMITER = line.split()[1]
continue
if (DELIMITER not in line):
stmt += line.replace(DELIMITER, ';')
continue
if stmt:
stmt += line
stmts.append(stmt.strip())
stmt = ''
else:
stmts.append(line.strip())
return stmts
@click.command('init-db')
def init_db():
db = get_db()
cur = db.cursor()
click.echo("PyMySQL do not support script execution...")
# click.echo("Initializing database schema...")
click.echo("Initializing database schema...")
sqls = parse_sql("sql/db_create.sql")
for sql in sqls:
cur.execute(sql)
db.commit()
# with current_app.open_resource('sql/db_create_sqlite.sql') as f:
# db.executescript(f.read().decode('utf8'))
# click.echo("Initializing database triggers...")
click.echo("Initializing database triggers...")
sqls = parse_sql("sql/trigger.sql")
for sql in sqls:
cur.execute(sql)
db.commit()
# with current_app.open_resource('sql/trigger_sqlite.sql') as f:
# db.executescript(f.read().decode('utf8'))
click.echo("Initializing admin passwd...")
print(len(generate_password_hash("lolicon")))
db.cursor().execute("insert into admin (passwd) values (%s)", (generate_password_hash(current_app.config["ADMIN_PASS"])))
cur.execute("insert into admin (passwd) values (%s)", (generate_password_hash(current_app.config["ADMIN_PASS"])))
db.commit()
cur.close()
click.echo("Initialized database.")
def init_app(app):

133
src/sql/db_create.sql Normal file
View File

@ -0,0 +1,133 @@
drop table if exists `admin`;
drop table if exists user_stat;
drop table if exists book_type;
drop table if exists book_author;
drop table if exists author;
drop table if exists typetable;
drop table if exists record;
drop table if exists note;
drop table if exists document;
drop table if exists book;
drop table if exists user;
create table `admin`
(
passwd varchar(200) NOT NULL
);
-- insert into `admin` (`passwd`) values('');
create table user
(
user_id int PRIMARY KEY AUTO_INCREMENT,
user_name varchar(100) NOT NULL UNIQUE,
user_mail varchar(100) NOT NULL UNIQUE,
user_passwd varchar(200) NOT NULL,
user_limit int NOT NULL,
user_regtime timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create table book
(
book_id int PRIMARY KEY AUTO_INCREMENT,
book_name varchar(100) NOT NULL,
book_isbn varchar(100) DEFAULT NULL,
book_publisher varchar(100) DEFAULT NULL,
book_pubdate datetime DEFAULT NULL,
book_lang varchar(100) DEFAULT NULL,
book_author varchar(100) DEFAULT NULL,
user_id int NOT NULL,
CONSTRAINT `fk_book_user_id` FOREIGN KEY (`user_id`) REFERENCES user(`user_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create table document
(
doc_id int PRIMARY KEY AUTO_INCREMENT,
doc_name varchar(100) NOT NULL,
doc_url varchar(100) NOT NULL,
doc_size int NOT NULL,
doc_date timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
doc_type varchar(100) NOT NULL,
book_id int NOT NULL,
user_id int NOT NULL,
CONSTRAINT `fk_document_user_id` FOREIGN KEY (`user_id`) REFERENCES user(`user_id`) ON DELETE RESTRICT,
CONSTRAINT `fk_document_book_id` FOREIGN KEY (`book_id`) REFERENCES book(`book_id`) ON DELETE RESTRICT
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create index `idx_doc_name` on document(doc_name);
create table note
(
note_id int PRIMARY KEY AUTO_INCREMENT,
note_name varchar(100) NOT NULL,
note_date datetime NOT NULL DEFAULT CURRENT_TIMESTAMP,
note_content text NOT NULL,
book_id int NOT NULL,
user_id int NOT NULL,
CONSTRAINT `fk_note_user_id` FOREIGN KEY (`user_id`) REFERENCES user(`user_id`) ON DELETE CASCADE,
CONSTRAINT `fk_note_book_id` FOREIGN KEY (`book_id`) REFERENCES book(`book_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create index `idx_note_name` on note(note_name);
create table record
(
record_time timestamp PRIMARY KEY DEFAULT CURRENT_TIMESTAMP,
record_type varchar(10) NOT NULL,
doc_URL varchar(100) NOT NULL,
user_id int NOT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create table typetable
(
type_id int PRIMARY KEY AUTO_INCREMENT,
type_name varchar(20) NOT NULL UNIQUE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create table author
(
author_id int PRIMARY KEY AUTO_INCREMENT,
author_name varchar(50) NOT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create index `idx_author_name` on author(author_name);
create table book_author
(
author_id int NOT NULL,
book_id int NOT NULL,
PRIMARY KEY (`author_id`, `book_id`),
CONSTRAINT `fk_ba_book_id` FOREIGN KEY (`book_id`) REFERENCES book(`book_id`) ON DELETE RESTRICT,
CONSTRAINT `fk_ba_author_id` FOREIGN KEY (`author_id`) REFERENCES author(`author_id`) ON DELETE RESTRICT
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create table book_type
(
type_id int NOT NULL,
book_id int NOT NULL,
PRIMARY KEY (`type_id`, `book_id`),
CONSTRAINT `fk_bt_book_id` FOREIGN KEY (`book_id`) REFERENCES book(`book_id`) ON DELETE CASCADE,
CONSTRAINT `fk_bt_type_id` FOREIGN KEY (`type_id`) REFERENCES typetable(`type_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
create table user_stat
(
user_id int PRIMARY KEY,
user_limit int NOT NULL,
user_usedspace int NOT NULL DEFAULT 0,
user_bookcount int NOT NULL DEFAULT 0,
user_doccount int NOT NULL DEFAULT 0,
user_notecount int NOT NULL DEFAULT 0,
CONSTRAINT `fk_user_stat_user` FOREIGN KEY (`user_id`) REFERENCES user(`user_id`) ON DELETE CASCADE,
CONSTRAINT `ck_usedspace` CHECK (user_usedspace <= user_limit)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
drop view if exists `v_book_to_types`;
create view `v_book_to_types` as
select book_id, typetable.type_id as type_id, type_name from book_type natural join typetable;
drop view if exists `v_type_to_book`;
create view `v_type_to_book` as
select book_id,
book_name,
book_isbn,
book_publisher,
book_lang,
book_author,
user_id,
type_id,
type_name
from book natural join book_type natural join typetable;

114
src/sql/trigger.sql Normal file
View File

@ -0,0 +1,114 @@
drop trigger if exists `trig_create_user_stat`;
DELIMITER ##
create trigger `trig_create_user_stat`
after insert on user
for each row begin
insert into user_stat (`user_id`, `user_limit`) values(NEW.user_id, NEW.user_limit);
end ##
DELIMITER ;
drop trigger if exists `trig_delete_user_stat`;
DELIMITER ##
create trigger `trig_delete_user_stat`
after delete on user
for each row begin
delete from user_stat where user_id=OLD.user_id;
end ##
DELIMITER ;
drop trigger if exists `trig_update_stat_book_ins`;
DELIMITER ##
create trigger `trig_update_stat_book_ins`
after insert on book
for each row begin
update user_stat set user_bookcount=user_bookcount+1 where user_stat.user_id=NEW.user_id;
end ##
DELIMITER ;
drop trigger if exists `trig_update_stat_book_del`;
DELIMITER ##
create trigger `trig_update_stat_book_del`
after delete on book
for each row begin
update user_stat set user_bookcount=user_bookcount-1 where user_stat.user_id=OLD.user_id;
end ##
DELIMITER ;
drop trigger if exists `trig_update_stat_doc_ins`;
DELIMITER ##
create trigger `trig_update_stat_doc_ins`
after insert on document
for each row begin
update user_stat set user_doccount=user_doccount+1 where user_stat.user_id=NEW.user_id;
update user_stat set user_usedspace=user_usedspace+NEW.doc_size where user_stat.user_id=NEW.user_id;
end ##
DELIMITER ;
drop trigger if exists `trig_update_stat_doc_del`;
DELIMITER ##
create trigger `trig_update_stat_doc_del`
after delete on document
for each row begin
update user_stat set user_doccount=user_doccount-1 where user_stat.user_id=OLD.user_id;
update user_stat set user_usedspace=user_usedspace-OLD.doc_size where user_stat.user_id=OLD.user_id;
end ##
DELIMITER ;
drop trigger if exists `trig_update_stat_note_ins`;
DELIMITER ##
create trigger `trig_update_stat_note_ins`
after insert on note
for each row begin
update user_stat set user_notecount=user_notecount+1 where user_stat.user_id=NEW.user_id;
end ##
DELIMITER ;
drop trigger if exists `trig_update_stat_note_del`;
DELIMITER ##
create trigger `trig_update_stat_note_del`
after delete on note
for each row begin
update user_stat set user_notecount=user_notecount-1 where user_stat.user_id=OLD.user_id;
end ##
DELIMITER ;
drop procedure if exists `clean_up_type_author`;
DELIMITER ##
create procedure `clean_up_type_author`(in uid_in int) begin
declare done boolean default false;
declare v_bookid int;
declare cur cursor for select distinct book_id from book where book.user_id = uid_in;
declare continue handler for not found set done=true;
open cur;
mainloop: loop
fetch cur into v_bookid;
if done then
leave mainloop;
end if;
delete from typetable where type_id in (select type_id from book_type where book_id=v_bookid);
delete from book_type where book_id = v_bookid;
end loop;
close cur;
end ##
DELIMITER ;
drop procedure if exists `add_new_book_type`;
DELIMITER ##
create procedure `add_new_book_type`(in bookid_in int, in typename_in varchar(200)) begin
declare isnewtype int default 0;
declare isduplicated int default 0;
declare v_typeid int;
select count(type_name) into isnewtype from typetable where type_name=typename_in;
if isnewtype=0 then
insert into typetable (`type_name`) values (typename_in);
end if;
select type_id into v_typeid from typetable where type_name = typename_in;
select count(book_id) into isduplicated from book_type where type_id=v_typeid and book_id=bookid_in;
if isduplicated=0 then
insert into book_type (`type_id`,`book_id`) values (v_typeid, bookid_in);
end if;
end ##
DELIMITER ;

View File

@ -536,10 +536,12 @@ end ##
1. SQLite3语法和MySQL不完全兼容在数据类型、默认值关键字、存储过程、索引和约束等方面均和MySQL有一定的区别需要对比两者文档来迁移。
2. pymysql库的接口不完全遵循Python的数据库驱动规范存在部分功能缺失、相同接口语义不同的问题需要重新编写这部分的代码
3. pymysql没用SQL脚本执行功能不能直接用python代码直接初始化数据库需要手工导入
3. pymysql没有SQL脚本执行功能且无法一次执行多条SQL语句因此难以直接用python代码初始化数据库需要手工导入或编写专用的读取代码
2. 打包部署
2. 数据库自动初始化
3. 数据库自动初始化
我希望能够实现不需要用户手动导入SQL脚本就可以完成数据初始化。经过搜索各种博客我发现Flask框架可以编写单独的命令用于初始化同时我还结合网上的资料编写了解析MySQL格式的SQL脚本的代码用于将SQL脚本转换为pymysql可以执行的语句。这样只需要用户在完成安装后执行初始化命令就可以自动完成数据库表和触发器的导入。
4. 用户登陆
3. 用户登陆
经过搜索文档之后发现Flask框架自带了一个简单的登陆验证框架可以直接使用。