schema.sql 4.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128
  1. drop table if exists user_choice;
  2. drop table if exists user_choice_buffer_anonymous;
  3. drop table if exists user_vote;
  4. drop table if exists choices;
  5. drop table if exists cardinals;
  6. drop table if exists values_;
  7. drop table if exists attachments;
  8. drop table if exists votes;
  9. drop table if exists user_group;
  10. drop table if exists groups;
  11. drop table if exists users;
  12. PRAGMA foreign_keys = ON;
  13. create table users (
  14. id INTEGER PRIMARY KEY AUTOINCREMENT,
  15. email TEXT UNIQUE NOT NULL,
  16. password TEXT NOT NULL,
  17. openid TEXT NOT NULL,
  18. name TEXT UNIQUE NOT NULL,
  19. organization TEXT,
  20. is_admin BOOLEAN DEFAULT 0 NOT NULL,
  21. key TEXT,
  22. CHECK (is_admin IN (0, 1))
  23. );
  24. create table groups (
  25. id INTEGER PRIMARY KEY AUTOINCREMENT,
  26. name TEXT UNIQUE NOT NULL,
  27. system BOOLEAN DEFAULT 0 NOT NULL,
  28. CHECK (system IN (0, 1))
  29. );
  30. create table user_group (
  31. id_user INTEGER,
  32. id_group INTEGER,
  33. FOREIGN KEY(id_user) REFERENCES users (id) ON DELETE CASCADE,
  34. FOREIGN KEY(id_group) REFERENCES groups (id) ON DELETE CASCADE,
  35. PRIMARY KEY(id_user, id_group)
  36. );
  37. create table cardinals (
  38. id INTEGER UNIQUE NOT NULL PRIMARY KEY,
  39. name TEXT UNIQUE NOT NULL,
  40. first INTEGER
  41. );
  42. create table values_ (
  43. name TEXT NOT NULL,
  44. weight INTEGER NOT NULL,
  45. id_cardinal INTEGER NOT NULL,
  46. FOREIGN KEY(id_cardinal) REFERENCES cardinals (id) ON DELETE CASCADE,
  47. PRIMARY KEY(id_cardinal, weight)
  48. );
  49. create table votes (
  50. id INTEGER PRIMARY KEY AUTOINCREMENT,
  51. title TEXT NOT NULL,
  52. description TEXT,
  53. category TEXT,
  54. date_begin INTEGER DEFAULT CURRENT_TIMESTAMP NOT NULL,
  55. date_end INTEGER NOT NULL,
  56. quorum FLOAT DEFAULT 1,
  57. reminder_last_days INTEGER DEFAULT 3 NOT NULL,
  58. is_transparent BOOLEAN DEFAULT 1 NOT NULL,
  59. is_public BOOLEAN DEFAULT 1 NOT NULL,
  60. is_anonymous BOOLEAN DEFAULT 1 NOT NULL,
  61. is_open BOOLEAN DEFAULT 0 NOT NULL,
  62. is_terminated BOOLEAN DEFAULT 0 NOT NULL,
  63. is_hidden BOOLEAN DEFAULT 0 NOT NULL,
  64. id_author INTEGER DEFAULT 1 NOT NULL,
  65. id_group INTEGER DEFAULT 1 NOT NULL,
  66. id_cardinal INTEGER NOT NULL,
  67. FOREIGN KEY(id_author) REFERENCES users (id) ON DELETE SET DEFAULT,
  68. FOREIGN KEY(id_group) REFERENCES groups (id),
  69. FOREIGN KEY(id_cardinal) REFERENCES cardinals (id),
  70. CHECK (is_transparent IN (0, 1)),
  71. CHECK (is_public IN (0, 1)),
  72. CHECK (is_open IN (0, 1)),
  73. CHECK (is_terminated IN (0, 1)),
  74. CHECK (is_hidden IN (0, 1))
  75. );
  76. create table attachments (
  77. id INTEGER PRIMARY KEY AUTOINCREMENT,
  78. url TEXT NOT NULL,
  79. id_vote INTEGER NOT NULL,
  80. FOREIGN KEY(id_vote) REFERENCES votes (id) ON DELETE CASCADE
  81. );
  82. create table choices (
  83. id INTEGER PRIMARY KEY AUTOINCREMENT,
  84. name TEXT NOT NULL,
  85. id_vote INTEGER NOT NULL,
  86. FOREIGN KEY(id_vote) REFERENCES votes (id) ON DELETE CASCADE
  87. );
  88. create table user_choice (
  89. id_user INTEGER,
  90. id_choice INTEGER NOT NULL,
  91. id_cardinal INTEGER,
  92. weight INTEGER,
  93. FOREIGN KEY(id_user) REFERENCES users (id) ON DELETE CASCADE,
  94. FOREIGN KEY(id_choice) REFERENCES choices (id) ON DELETE CASCADE,
  95. FOREIGN KEY(id_cardinal, weight) REFERENCES values_ (id_cardinal, weight) ON DELETE CASCADE,
  96. PRIMARY KEY(id_user, id_choice)
  97. );
  98. create table user_choice_buffer_anonymous (
  99. -- NOTE: same table structure as user_choice, used to randomize insertion per vote
  100. id_user INTEGER,
  101. id_choice INTEGER NOT NULL,
  102. id_cardinal INTEGER,
  103. weight INTEGER,
  104. FOREIGN KEY(id_user) REFERENCES users (id) ON DELETE CASCADE,
  105. FOREIGN KEY(id_choice) REFERENCES choices (id) ON DELETE CASCADE,
  106. FOREIGN KEY(id_cardinal, weight) REFERENCES values_ (id_cardinal, weight) ON DELETE CASCADE,
  107. PRIMARY KEY(id_user, id_choice)
  108. );
  109. create table user_vote (
  110. date INTEGER DEFAULT CURRENT_TIMESTAMP NOT NULL,
  111. id_user INTEGER NOT NULL,
  112. id_vote INTEGER NOT NULL,
  113. FOREIGN KEY(id_user) REFERENCES users (id) ON DELETE CASCADE,
  114. FOREIGN KEY(id_vote) REFERENCES votes (id) ON DELETE CASCADE,
  115. PRIMARY KEY(id_user, id_vote)
  116. );