1
0

init.sql 5.5 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140
  1. CREATE TABLE IF NOT EXISTS role -- 角色表
  2. (
  3. RoleID INT PRIMARY KEY AUTO_INCREMENT,
  4. RoleName char(20) NOT NULL UNIQUE,
  5. WriteBlog bit DEFAULT 0, -- 写博客
  6. WriteComment bit DEFAULT 1, -- 写评论
  7. WriteMsg bit DEFAULT 1, -- 写留言
  8. CreateUser bit DEFAULT 0, -- 创建新用户
  9. ReadBlog bit DEFAULT 1, -- 读博客
  10. ReadComment bit DEFAULT 1, -- 读评论
  11. ReadMsg bit DEFAULT 1, -- 读留言
  12. ReadSecretMsg bit DEFAULT 0, -- 读私密留言
  13. ReadUserInfo bit DEFAULT 0, -- 读取用户信息
  14. DeleteBlog bit DEFAULT 0, -- 删除博客
  15. DeleteComment bit DEFAULT 0, -- 删除评论
  16. DeleteMsg bit DEFAULT 0, -- 删除留言
  17. DeleteUser bit DEFAULT 0, -- 删除用户
  18. ConfigureSystem bit DEFAULT 0, -- 配置系统
  19. ReadSystem bit DEFAULT 0 -- 读系统信息
  20. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  21. CREATE TABLE IF NOT EXISTS user -- 创建用户表
  22. (
  23. ID INT PRIMARY KEY AUTO_INCREMENT,
  24. Email char(32) NOT NULL UNIQUE,
  25. PasswdHash char(128) NOT NULL,
  26. Role INT NOT NULL DEFAULT 3,
  27. FOREIGN KEY (Role) REFERENCES role (RoleID)
  28. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  29. INSERT INTO role (RoleID,
  30. RoleName,
  31. WriteBlog,
  32. WriteComment,
  33. WriteMsg,
  34. CreateUser,
  35. ReadBlog,
  36. ReadComment,
  37. ReadMsg,
  38. ReadSecretMsg,
  39. ReadUserInfo,
  40. DeleteBlog,
  41. DeleteComment,
  42. DeleteMsg,
  43. DeleteUser,
  44. ConfigureSystem,
  45. ReadSystem)
  46. VALUES (1, 'Admin', 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1), -- 管理员用户
  47. (2, 'Coordinator', 0, 1, 1, 1, 1, 1, 1, 1, 1, 0, 1, 1, 0, 0, 1); -- 协管员用户
  48. INSERT INTO role (RoleID, RoleName)
  49. VALUES (3, 'Default'); -- 默认用户
  50. INSERT INTO role (RoleID, RoleName, WriteComment, WriteMsg)
  51. VALUES (4, 'Anonymous', 0, 0); -- 默认用户
  52. CREATE TABLE IF NOT EXISTS blog -- 创建博客表
  53. (
  54. ID INT PRIMARY KEY AUTO_INCREMENT, -- 文章 ID
  55. Auth INT NOT NULL, -- 作者
  56. Title char(20) NOT NULL, -- 标题
  57. SubTitle char(20) NOT NULL, -- 副标题
  58. Content TEXT NOT NULL, -- 内容
  59. CreateTime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建的时间
  60. UpdateTime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建的时间
  61. Top BIT NOT NULL DEFAULT 0, -- 置顶
  62. FOREIGN KEY (Auth) REFERENCES user (ID)
  63. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  64. CREATE TABLE IF NOT EXISTS archive -- 归档表
  65. (
  66. ID INT PRIMARY KEY AUTO_INCREMENT, -- 归档 ID
  67. Name CHAR(30) NOT NULL UNIQUE, -- 归档名称
  68. DescribeText char(100) NOT NULL -- 描述
  69. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  70. CREATE TABLE IF NOT EXISTS blog_archive -- 归档表
  71. (
  72. BlogID INT, -- 文章ID
  73. ArchiveID INT, -- 归档ID
  74. FOREIGN KEY (BlogID) REFERENCES blog (ID),
  75. FOREIGN KEY (ArchiveID) REFERENCES archive (ID)
  76. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  77. CREATE VIEW blog_archive_with_name AS
  78. SELECT BlogID, ArchiveID, archive.Name As ArchiveName, archive.DescribeText AS DescribeText
  79. FROM blog_archive
  80. LEFT JOIN archive on blog_archive.ArchiveID = archive.ID;
  81. CREATE VIEW blog_with_archive AS
  82. SELECT blog.ID AS BlogID,
  83. blog_archive.ArchiveID AS ArchiveID,
  84. Auth,
  85. Title,
  86. SubTitle,
  87. Content,
  88. CreateTime,
  89. UpdateTime,
  90. Top
  91. FROM blog
  92. RIGHT JOIN blog_archive ON blog.ID = blog_archive.BlogID;
  93. CREATE TABLE IF NOT EXISTS comment -- 评论表
  94. (
  95. ID INT PRIMARY KEY AUTO_INCREMENT, -- 评论 ID
  96. BlogID INT NOT NULL, -- 博客 ID
  97. Auth INT NOT NULL, -- 作者
  98. Content TEXT NOT NULL, -- 内容
  99. CreateTime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建的时间
  100. UpdateTime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建的时间
  101. FOREIGN KEY (BlogID) REFERENCES blog (ID),
  102. FOREIGN KEY (Auth) REFERENCES user (ID)
  103. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  104. CREATE VIEW comment_user AS
  105. SELECT comment.ID as CommentID, BlogID, Auth, user.Email as Email, Content, CreateTime, UpdateTime
  106. FROM comment
  107. LEFT JOIN user on user.ID = comment.Auth
  108. ORDER BY UpdateTime DESC;
  109. CREATE TABLE IF NOT EXISTS message -- 留言表
  110. (
  111. ID INT PRIMARY KEY AUTO_INCREMENT, -- 留言 ID
  112. Auth INT NOT NULL, -- 作者
  113. Content TEXT NOT NULL, -- 内容
  114. Secret BIT NOT NULL DEFAULT 0, -- 私密内容
  115. CreateTime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建的时间
  116. UpdateTime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建的时间
  117. FOREIGN KEY (Auth) REFERENCES user (ID)
  118. ) CHARACTER SET utf8 COLLATE utf8_unicode_ci;
  119. CREATE VIEW message_user AS
  120. SELECT message.ID as MsgID, Auth, user.Email as Email, Content, CreateTime, UpdateTime, Secret
  121. FROM message
  122. LEFT JOIN user on user.ID = message.Auth
  123. ORDER BY UpdateTime DESC;