├── .gitignore ├── LICENSE ├── README.md ├── blog_with_likes └── blog_with_likes.postgres.sql ├── blog_with_tags └── blog_with_tags.postgres.sql ├── hangman └── hangman.postgres.sql ├── manifest.json ├── photo_gallery └── photo_gallery.postgres.sql ├── question_answer └── question_answer.postgres.sql ├── reddit └── reddit.postgres.sql ├── surveys └── surveys.postgres.sql └── tic_tac_toe └── tic_tac_toe.postgres.sql /.gitignore: -------------------------------------------------------------------------------- 1 | ## Specific to this project: 2 | .env 3 | *.db 4 | *.sqlite3 5 | 6 | ## Specific to Mac OS X: 7 | .DS_Store 8 | .AppleDouble 9 | .LSOverride 10 | 11 | # OS X thumbnails 12 | ._* 13 | 14 | ## Specific to Windows: 15 | # Windows image file caches 16 | Thumbs.db 17 | ehthumbs.db 18 | 19 | # Folder config file 20 | Desktop.ini 21 | 22 | ## Specific to Ruby: 23 | *.gem 24 | *.rbc 25 | /.config 26 | /coverage/ 27 | /InstalledFiles 28 | /pkg/ 29 | /spec/reports/ 30 | /test/tmp/ 31 | /test/version_tmp/ 32 | /tmp/ 33 | 34 | ## Ruby documentation cache and generated files: 35 | /.yardoc/ 36 | /_yardoc/ 37 | /doc/ 38 | /rdoc/ 39 | 40 | ## Ruby environment normalisation: 41 | /.bundle/ 42 | /lib/bundler/man/ 43 | .rvmrc 44 | 45 | ## Specific to Cloud9 IDE: 46 | .c9revisions 47 | .c9 48 | 49 | ## Specific to Vim: 50 | [._]*.s[a-w][a-z] 51 | [._]s[a-w][a-z] 52 | *.un~ 53 | Session.vim 54 | .netrwhist 55 | *~ 56 | 57 | ## Specific to Sublime Text: 58 | # Cache files for sublime text 59 | *.tmlanguage.cache 60 | *.tmPreferences.cache 61 | *.stTheme.cache 62 | 63 | # Workspace files are user-specific 64 | *.sublime-workspace 65 | 66 | # sftp configuration file 67 | sftp-config.json 68 | 69 | ## Specific to RubyMotion: 70 | .dat* 71 | .repl_history 72 | build/ 73 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2014 CodeUnion, Inc. 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Example Database Schemas 2 | 3 | This repository contains a handful of example database schemas. We want this 4 | repository to do two things: 5 | 6 | 1. Serve as a reference for common schema design patterns 7 | 2. Give students more exposure to schema-level SQL, e.g., 8 | `CREATE TABLE`, `CREATE UNIQUE INDEX`, and so on. 9 | 10 | ## Format of This Repository 11 | 12 | Every schema is contained in its own directory. For example, the 13 | [blog_with_tags](blog_with_tags) directory contains a schema for a very basic 14 | blog with support for tagging blog posts. In this example, the schema itself is 15 | contained in a file named 16 | 17 | ```text 18 | blog_with_tags.postgres.sql 19 | ``` 20 | 21 | which contains raw SQL `CREATE TABLE` statements that define the various tables, 22 | indexes, and associations that make up the database schema. 23 | 24 | The file is named `.postgres.sql` because the SQL statements contained inside 25 | follow PostgreSQL's dialect of SQL. Every database engine has its own "dialect" 26 | of SQL, whether the engine MySQL, SQLite3, Microsoft SQL Server, or Oracle. 27 | 28 | We'll be adding examples in other dialects as time goes on. If you want to 29 | help the process along, [we welcome pull requests][pull-request-url] 30 | 31 | ## Schemas in This Repository 32 | 33 | ### Blog With Tags 34 | 35 | The [blog_with_tags](blog_with_tags) schema models a basic blog where users can 36 | publish articles and tag them with arbitrary tags. It defines users, articles, 37 | and tags. 38 | 39 | ### Blog With Likes 40 | 41 | The [blog_with_likes](blog_with_likes) schema models a basic blog where users 42 | can publish new articles or like already-published articles. It defines users, 43 | articles, and likes. 44 | 45 | ### Question and Answer 46 | 47 | The [question_and_answer](question_and_answer) schema models a basic Q&A site 48 | a la Stack Overflow or Yahoo! Answers. It defines users, questions, answers, 49 | and voting. 50 | 51 | ### Surveys 52 | 53 | The [surveys](surveys) schema models a website where users can create surveys 54 | for other users to fill out. It defines users, surveys, survey choices, and 55 | survey responses. 56 | 57 | ### Reddit 58 | 59 | The [reddit](reddit) schema models a Reddit-like site where users submit links 60 | for other to vote and comment on. It defines users, link submissions, voting, 61 | and nested commenting. 62 | 63 | ### Photo Gallery 64 | 65 | The [photo_gallery](photo_gallery) schema models a basic photo gallery. Users 66 | can create albums and upload photos to a specific album. 67 | 68 | ### Hangman 69 | 70 | The [hangman](hangman) schema models a player vs. computer version of 71 | [letter-guessing game Hangman](http://en.wikipedia.org/wiki/Hangman_%28game%29). 72 | It defines users, games, turns, and phrases. 73 | 74 | ### Tic Tac Toe 75 | 76 | The [tic_tac_toe](tic_tac_toe) schema models a collection of tic-tac-toe games. 77 | It defines users, games, and turns. 78 | 79 | [pull-request-url]: https://github.com/codeunion/examples-schema/pulls 80 | -------------------------------------------------------------------------------- /blog_with_likes/blog_with_likes.postgres.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE users ( 2 | id SERIAL PRIMARY KEY, 3 | email TEXT NOT NULL, 4 | password_digest TEXT NOT NULL, 5 | created_at TIMESTAMP NOT NULL, 6 | updated_at TIMESTAMP NOT NULL 7 | ); 8 | 9 | ALTER TABLE users ADD UNIQUE (email); 10 | 11 | CREATE TABLE articles ( 12 | id SERIAL PRIMARY KEY, 13 | author_id INTEGER NOT NULL, 14 | title TEXT NOT NULL, 15 | body TEXT NOT NULL, 16 | created_at TIMESTAMP NOT NULL, 17 | updated_at TIMESTAMP NOT NULL, 18 | FOREIGN KEY (author_id) REFERENCES users(id) 19 | ); 20 | 21 | CREATE INDEX ON articles(author_id); 22 | 23 | CREATE TABLE likes ( 24 | id SERIAL PRIMARY KEY, 25 | article_id INTEGER NOT NULL, 26 | user_id INTEGER NOT NULL, 27 | created_at TIMESTAMP NOT NULL, 28 | updated_at TIMESTAMP NOT NULL, 29 | FOREIGN KEY (article_id) REFERENCES articles(id), 30 | FOREIGN KEY (user_id) REFERENCES users(id) 31 | ); 32 | 33 | ALTER TABLE likes ADD UNIQUE (article_id, user_id); 34 | CREATE INDEX ON likes(user_id); 35 | -------------------------------------------------------------------------------- /blog_with_tags/blog_with_tags.postgres.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE users ( 2 | id SERIAL PRIMARY KEY, 3 | email TEXT NOT NULL, 4 | password_digest TEXT NOT NULL, 5 | created_at TIMESTAMP NOT NULL, 6 | updated_at TIMESTAMP NOT NULL 7 | ); 8 | 9 | ALTER TABLE users ADD UNIQUE (email); 10 | 11 | CREATE TABLE articles ( 12 | id SERIAL PRIMARY KEY, 13 | author_id INTEGER NOT NULL, 14 | title TEXT NOT NULL, 15 | body TEXT NOT NULL, 16 | created_at TIMESTAMP NOT NULL, 17 | updated_at TIMESTAMP NOT NULL, 18 | FOREIGN KEY (author_id) REFERENCES users(id) 19 | ); 20 | 21 | CREATE INDEX ON articles(author_id); 22 | 23 | CREATE TABLE tags ( 24 | id SERIAL PRIMARY KEY, 25 | name TEXT NOT NULL, 26 | created_at TIMESTAMP NOT NULL, 27 | updated_at TIMESTAMP NOT NULL 28 | ); 29 | 30 | ALTER TABLE tags ADD UNIQUE (name); 31 | 32 | CREATE TABLE taggings ( 33 | id SERIAL PRIMARY KEY, 34 | article_id INTEGER NOT NULL, 35 | tag_id INTEGER NOT NULL, 36 | created_at TIMESTAMP NOT NULL, 37 | updated_at TIMESTAMP NOT NULL, 38 | FOREIGN KEY (article_id) REFERENCES articles(id), 39 | FOREIGN KEY (tag_id) REFERENCES tags(id) 40 | ); 41 | 42 | ALTER TABLE taggings ADD UNIQUE (article_id, tag_id); 43 | CREATE INDEX ON taggings(tag_id); 44 | -------------------------------------------------------------------------------- /hangman/hangman.postgres.sql: -------------------------------------------------------------------------------- 1 | -- In this schema, when a player initiates a new game, the computer would 2 | -- pick one of the entries from the `phrases` table as the phrase-to-guess. 3 | -- 4 | -- Every turn or guess would result in a new entry in the `turns` table, 5 | -- containing the letter the player guessed for that turn. 6 | 7 | CREATE TABLE users ( 8 | id SERIAL PRIMARY KEY, 9 | email TEXT NOT NULL, 10 | password_digest TEXT NOT NULL, 11 | created_at TIMESTAMP NOT NULL, 12 | updated_at TIMESTAMP NOT NULL 13 | ); 14 | 15 | ALTER TABLE users ADD UNIQUE (email); 16 | 17 | CREATE TABLE phrases ( 18 | id SERIAL PRIMARY KEY, 19 | body TEXT NOT NULL 20 | ); 21 | 22 | CREATE TABLE games ( 23 | id SERIAL PRIMARY KEY, 24 | player_id INTEGER NOT NULL, 25 | phrase_id INTEGER NOT NULL, 26 | guess_limit INTEGER NOT NULL, 27 | completed_at TIMESTAMP, 28 | created_at TIMESTAMP NOT NULL, 29 | updated_at TIMESTAMP NOT NULL, 30 | FOREIGN KEY (player_id) REFERENCES users(id), 31 | FOREIGN KEY (phrase_id) REFERENCES phrases(id), 32 | CHECK(guess_limit > 0) 33 | ); 34 | 35 | CREATE INDEX ON games(player_id); 36 | 37 | CREATE TABLE turns ( 38 | id SERIAL PRIMARY KEY, 39 | game_id INTEGER NOT NULL, 40 | letter_guessed CHAR(1) NOT NULL, 41 | created_at TIMESTAMP NOT NULL, 42 | FOREIGN KEY (game_id) REFERENCES games(id) 43 | ); 44 | 45 | -- For a given game, a player can't guess the same letter twice. 46 | ALTER TABLE turns ADD UNIQUE (game_id, letter_guessed); 47 | -------------------------------------------------------------------------------- /manifest.json: -------------------------------------------------------------------------------- 1 | { 2 | "category": "example", 3 | "tags": [ 4 | "sql", 5 | "databases", 6 | "schema", 7 | "tables", 8 | "constraints", 9 | "foreign-keys" 10 | ], 11 | "notes": "Half project, half example." 12 | } 13 | -------------------------------------------------------------------------------- /photo_gallery/photo_gallery.postgres.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE users ( 2 | id SERIAL PRIMARY KEY, 3 | email TEXT NOT NULL, 4 | password_digest TEXT NOT NULL, 5 | created_at TIMESTAMP NOT NULL, 6 | updated_at TIMESTAMP NOT NULL 7 | ); 8 | 9 | ALTER TABLE users ADD UNIQUE (email); 10 | 11 | CREATE TABLE albums ( 12 | id SERIAL PRIMARY KEY, 13 | user_id INTEGER NOT NULL, 14 | name TEXT NOT NULL, 15 | created_at TIMESTAMP NOT NULL, 16 | updated_at TIMESTAMP NOT NULL, 17 | FOREIGN KEY (user_id) REFERENCES users(id) 18 | ); 19 | 20 | CREATE INDEX ON albums(user_id); 21 | 22 | CREATE TABLE photos ( 23 | id SERIAL PRIMARY KEY, 24 | album_id INTEGER NOT NULL, 25 | filename TEXT NOT NULL, 26 | created_at TIMESTAMP NOT NULL, 27 | updated_at TIMESTAMP NOT NULL, 28 | FOREIGN KEY (album_id) REFERENCES albums(id) 29 | ); 30 | 31 | CREATE INDEX ON photos(album_id); 32 | -------------------------------------------------------------------------------- /question_answer/question_answer.postgres.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE users ( 2 | id SERIAL PRIMARY KEY, 3 | email TEXT NOT NULL, 4 | username TEXT NOT NULL, 5 | password_digest TEXT NOT NULL, 6 | created_at TIMESTAMP NOT NULL, 7 | updated_at TIMESTAMP NOT NULL 8 | ); 9 | 10 | ALTER TABLE users ADD UNIQUE (email); 11 | ALTER TABLE users ADD UNIQUE (username); 12 | 13 | CREATE TABLE questions ( 14 | id SERIAL PRIMARY KEY, 15 | author_id INTEGER NOT NULL, 16 | best_answer_id INTEGER, 17 | title TEXT NOT NULL, 18 | body TEXT NOT NULL, 19 | created_at TIMESTAMP NOT NULL, 20 | updated_at TIMESTAMP NOT NULL, 21 | FOREIGN KEY (author_id) REFERENCES users(id) 22 | ); 23 | 24 | CREATE INDEX ON questions(author_id); 25 | 26 | CREATE TABLE answers ( 27 | id SERIAL PRIMARY KEY, 28 | author_id INTEGER NOT NULL, 29 | question_id INTEGER NOT NULL, 30 | body TEXT NOT NULL, 31 | created_at TIMESTAMP NOT NULL, 32 | updated_at TIMESTAMP NOT NULL, 33 | FOREIGN KEY (author_id) REFERENCES users(id) 34 | ); 35 | 36 | ALTER TABLE answers ADD FOREIGN KEY (question_id) REFERENCES questions(id); 37 | ALTER TABLE questions ADD FOREIGN KEY (best_answer_id) REFERENCES answers(id); 38 | 39 | ALTER TABLE answers ADD UNIQUE (author_id, question_id); 40 | CREATE INDEX ON answers(question_id); 41 | 42 | CREATE TABLE answer_votes ( 43 | id SERIAL PRIMARY KEY, 44 | answer_id INTEGER NOT NULL, 45 | voter_id INTEGER NOT NULL, 46 | score INTEGER NOT NULL, 47 | created_at TIMESTAMP NOT NULL, 48 | updated_at TIMESTAMP NOT NULL, 49 | FOREIGN KEY (answer_id) REFERENCES answers(id), 50 | FOREIGN KEY (voter_id) REFERENCES users(id), 51 | CHECK(score IN (-1, 1)) 52 | ); 53 | 54 | ALTER TABLE answer_votes ADD UNIQUE (answer_id, voter_id); 55 | CREATE INDEX ON answer_votes(voter_id); 56 | -------------------------------------------------------------------------------- /reddit/reddit.postgres.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE users ( 2 | id SERIAL PRIMARY KEY, 3 | email TEXT NOT NULL, 4 | username TEXT NOT NULL, 5 | password_digest TEXT NOT NULL, 6 | created_at TIMESTAMP NOT NULL, 7 | updated_at TIMESTAMP NOT NULL 8 | ); 9 | 10 | ALTER TABLE users ADD UNIQUE (username); 11 | ALTER TABLE users ADD UNIQUE (email); 12 | 13 | CREATE TABLE submissions ( 14 | id SERIAL PRIMARY KEY, 15 | author_id INTEGER NOT NULL, 16 | url TEXT NOT NULL, 17 | created_at TIMESTAMP NOT NULL, 18 | updated_at TIMESTAMP NOT NULL, 19 | FOREIGN KEY (author_id) REFERENCES users(id) 20 | ); 21 | 22 | CREATE INDEX ON submissions(author_id); 23 | 24 | CREATE TABLE submission_votes ( 25 | id SERIAL PRIMARY KEY, 26 | submission_id INTEGER NOT NULL, 27 | voter_id INTEGER NOT NULL, 28 | score INTEGER NOT NULL, 29 | created_at TIMESTAMP NOT NULL, 30 | updated_at TIMESTAMP NOT NULL, 31 | FOREIGN KEY (submission_id) REFERENCES submissions(id), 32 | FOREIGN KEY (voter_id) REFERENCES users(id), 33 | CHECK(SCORE IN (-1,1)) 34 | ); 35 | 36 | ALTER TABLE submission_votes ADD UNIQUE (submission_id, voter_id); 37 | CREATE INDEX ON submission_votes(voter_id); 38 | 39 | CREATE TABLE comments ( 40 | id SERIAL PRIMARY KEY, 41 | author_id INTEGER NOT NULL, 42 | submission_id INTEGER NOT NULL, 43 | parent_id INTEGER, 44 | body TEXT NOT NULL, 45 | created_at TIMESTAMP NOT NULL, 46 | updated_at TIMESTAMP NOT NULL, 47 | FOREIGN KEY (author_id) REFERENCES users(id), 48 | FOREIGN KEY (submission_id) REFERENCES submissions(id), 49 | FOREIGN KEY (parent_id) REFERENCES comments(id) 50 | ); 51 | 52 | CREATE INDEX ON comments(author_id); 53 | CREATE INDEX ON comments(submission_id); 54 | CREATE INDEX ON comments(parent_id); 55 | 56 | CREATE TABLE comment_votes ( 57 | id SERIAL PRIMARY KEY, 58 | comment_id INTEGER NOT NULL, 59 | voter_id INTEGER NOT NULL, 60 | score INTEGER NOT NULL, 61 | created_at TIMESTAMP NOT NULL, 62 | updated_at TIMESTAMP NOT NULL, 63 | FOREIGN KEY (comment_id) REFERENCES comments(id), 64 | FOREIGN KEY (voter_id) REFERENCES users(id), 65 | CHECK(score IN (-1, 1)) 66 | ); 67 | 68 | ALTER TABLE comment_votes ADD UNIQUE (comment_id, voter_id); 69 | CREATE INDEX ON comment_votes(voter_id); 70 | -------------------------------------------------------------------------------- /surveys/surveys.postgres.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE users ( 2 | id SERIAL PRIMARY KEY, 3 | email TEXT NOT NULL, 4 | password_digest TEXT NOT NULL, 5 | created_at TIMESTAMP NOT NULL, 6 | updated_at TIMESTAMP NOT NULL 7 | ); 8 | 9 | ALTER TABLE users ADD UNIQUE (email); 10 | 11 | CREATE TABLE surveys ( 12 | id SERIAL PRIMARY KEY, 13 | author_id INTEGER NOT NULL, 14 | title TEXT NOT NULL, 15 | created_at TIMESTAMP NOT NULL, 16 | updated_at TIMESTAMP NOT NULL, 17 | FOREIGN KEY (author_id) REFERENCES users(id) 18 | ); 19 | 20 | CREATE INDEX ON surveys(author_id); 21 | 22 | CREATE TABLE survey_choices ( 23 | id SERIAL PRIMARY KEY, 24 | survey_id INTEGER NOT NULL, 25 | description TEXT NOT NULL, 26 | FOREIGN KEY (survey_id) REFERENCES surveys(id) 27 | ); 28 | 29 | CREATE INDEX ON survey_choices(survey_id); 30 | 31 | CREATE TABLE survey_responses ( 32 | id SERIAL PRIMARY KEY, 33 | survey_id INTEGER NOT NULL, 34 | respondent_id INTEGER NOT NULL, 35 | created_at TIMESTAMP NOT NULL, 36 | updated_at TIMESTAMP NOT NULL, 37 | FOREIGN KEY (survey_id) REFERENCES surveys(id), 38 | FOREIGN KEY (respondent_id) REFERENCES users(id) 39 | ); 40 | 41 | ALTER TABLE survey_responses ADD UNIQUE (survey_id, respondent_id); 42 | CREATE INDEX ON survey_responses(respondent_id); 43 | 44 | CREATE TABLE survey_response_choices ( 45 | id SERIAL PRIMARY KEY, 46 | survey_choice_id iNTEGER NOT NULL, 47 | survey_response_id INTEGER NOT NULL, 48 | created_at TIMESTAMP NOT NULL, 49 | updated_at TIMESTAMP NOT NULL, 50 | FOREIGN KEY (survey_choice_id) REFERENCES survey_choices(id), 51 | FOREIGN KEY (survey_response_id) REFERENCES survey_responses(id) 52 | ); 53 | 54 | ALTER TABLE survey_response_choices ADD UNIQUE (survey_choice_id, survey_response_id); 55 | CREATE INDEX ON survey_response_choices(survey_response_id); 56 | -------------------------------------------------------------------------------- /tic_tac_toe/tic_tac_toe.postgres.sql: -------------------------------------------------------------------------------- 1 | -- In this schema, when a player initiates a new game, the computer would 2 | -- pick one of the entries from the `phrases` table as the phrase-to-guess. 3 | -- 4 | -- Every turn or guess would result in a new entry in the `turns` table, 5 | -- containing the letter the player guessed for that turn. 6 | 7 | 8 | CREATE TABLE users ( 9 | id SERIAL PRIMARY KEY, 10 | email TEXT NOT NULL, 11 | password_digest TEXT NOT NULL, 12 | created_at TIMESTAMP NOT NULL, 13 | updated_at TIMESTAMP NOT NULL 14 | ); 15 | 16 | ALTER TABLE users ADD UNIQUE (email); 17 | 18 | CREATE TABLE games ( 19 | id SERIAL PRIMARY KEY, 20 | winner_id INTEGER, 21 | completed_at TIMESTAMP, 22 | created_at TIMESTAMP NOT NULL, 23 | updated_at TIMESTAMP NOT NULL, 24 | FOREIGN KEY (winner_id) REFERENCES users(id) 25 | ); 26 | 27 | CREATE INDEX ON games(winner_id); 28 | 29 | CREATE TABLE games_players ( 30 | id SERIAL PRIMARY KEY, 31 | game_id INTEGER NOT NULL, 32 | player_id INTEGER NOT NULL, 33 | token CHAR(1) NOT NULL, 34 | FOREIGN KEY (game_id) REFERENCES games(id), 35 | FOREIGN KEY (player_id) REFERENCES users(id) 36 | ); 37 | 38 | ALTER TABLE games_players ADD UNIQUE (game_id, token); 39 | 40 | ALTER TABLE games_players ADD UNIQUE (game_id, player_id); 41 | CREATE INDEX ON games_players(player_id); 42 | 43 | CREATE TABLE turns ( 44 | id SERIAL PRIMARY KEY, 45 | game_id INTEGER NOT NULL, 46 | player_id INTEGER NOT NULL, 47 | position INTEGER NOT NULL, 48 | created_at TIMESTAMP NOT NULL, 49 | FOREIGN KEY (game_id) REFERENCES games(id), 50 | FOREIGN KEY (player_id) REFERENCES users(id), 51 | CHECK(position BETWEEN 1 AND 9) 52 | ); 53 | 54 | ALTER TABLE turns ADD UNIQUE (game_id, position); 55 | CREATE INDEX ON turns(game_id, player_id); 56 | CREATE INDEX ON turns(player_id); 57 | 58 | ALTER TABLE turns ADD UNIQUE (game_id, position); 59 | ALTER TABLE turns ADD UNIQUE (game_id); 60 | --------------------------------------------------------------------------------