CREATE TABLE users ( ID INTEGER PRIMARY KEY AUTOINCREMENT, Username TEXT UNIQUE NOT NULL ); CREATE TABLE userlogin_provider ( ID INTEGER PRIMARY KEY AUTOINCREMENT, user_ID INTEGER NOT NULL, login_stub TEXT UNIQUE NOT NULL, FOREIGN KEY (user_ID) REFERENCES users (ID) ); CREATE TABLE user_sessions ( ID INTEGER PRIMARY KEY AUTOINCREMENT, user_ID INTEGER NOT NULL, session_token TEXT UNIQUE NOT NULL, created_at TEXT NOT NULL, valid_until TEXT NOT NULL, name TEXT, FOREIGN KEY (user_ID) REFERENCES users (ID) ); CREATE TABLE storagespace ( ID INTEGER PRIMARY KEY AUTOINCREMENT, Parent INTEGER, Location TEXT, Name TEXT NOT NULL, FOREIGN KEY (Parent) REFERENCES storagespace (ID) ); CREATE TABLE objects ( ID INTEGER PRIMARY KEY AUTOINCREMENT, storagespace_ID INTEGER NOT NULL, Name TEXT NOT NULL, Description TEXT, Serialnumber TEXT UNIQUE, created DATETIME DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (storagespace_ID) REFERENCES storagespace (ID) ); CREATE TABLE events ( ID INTEGER PRIMARY KEY AUTOINCREMENT, user_ID INTEGER NOT NULL, Name TEXT NOT NULL, Description TEXT, Location TEXT, Start_Date TEXT NOT NULL, End_Date TEXT NOT NULL, FOREIGN KEY (user_ID) REFERENCES users (ID) ); CREATE TABLE pictures ( ID INTEGER PRIMARY KEY AUTOINCREMENT, user_ID INTEGER NOT NULL, storagespace_ID INTEGER, object_ID INTEGER, event_ID INTEGER, check_in_ID INTEGER, Path TEXT NOT NULL, Description TEXT, datetime TEXT NOT NULL, FOREIGN KEY (user_ID) REFERENCES users (ID), FOREIGN KEY (storagespace_ID) REFERENCES storagespace (ID), FOREIGN KEY (object_ID) REFERENCES objects (ID), FOREIGN KEY (event_ID) REFERENCES events (ID), FOREIGN KEY (check_in_ID) REFERENCES check_in (ID) ); CREATE TABLE events_objects ( ID INTEGER PRIMARY KEY AUTOINCREMENT, event_ID INTEGER NOT NULL, object_ID INTEGER NOT NULL, FOREIGN KEY (event_ID) REFERENCES events (ID), FOREIGN KEY (object_ID) REFERENCES objects (ID) ); CREATE TABLE checkin_events ( ID INTEGER PRIMARY KEY AUTOINCREMENT, Name TEXT NOT NULL ); CREATE TABLE checkin_states ( ID INTEGER PRIMARY KEY AUTOINCREMENT, Name TEXT NOT NULL ); CREATE TABLE check_in ( ID INTEGER PRIMARY KEY AUTOINCREMENT, user_ID INTEGER NOT NULL, checkin_event_ID INTEGER NOT NULL, event_ID INTEGER, object_ID INTEGER, checkin_state_ID INTEGER NOT NULL, datetime TEXT NOT NULL, FOREIGN KEY (user_ID) REFERENCES users (ID), FOREIGN KEY (checkin_event_ID) REFERENCES checkin_events (ID), FOREIGN KEY (event_ID) REFERENCES events (ID), FOREIGN KEY (object_ID) REFERENCES objects (ID), FOREIGN KEY (checkin_state_ID) REFERENCES checkin_states (ID) ); CREATE TABLE annotations ( ID INTEGER PRIMARY KEY AUTOINCREMENT, user_ID INTEGER NOT NULL, object_ID INTEGER, event_ID INTEGER, check_in_ID INTEGER, events_object_ID INTEGER, text TEXT NOT NULL, datetime TEXT NOT NULL, FOREIGN KEY (user_ID) REFERENCES users (ID), FOREIGN KEY (object_ID) REFERENCES objects (ID), FOREIGN KEY (event_ID) REFERENCES events (ID), FOREIGN KEY (check_in_ID) REFERENCES check_in (ID), FOREIGN KEY (events_object_ID) REFERENCES events_objects (ID) ); CREATE TABLE object_class ( ID INTEGER PRIMARY KEY AUTOINCREMENT, object_class_parent_ID INTEGER, Name TEXT NOT NULL, FOREIGN KEY (object_class_parent_ID) REFERENCES object_class (ID) ); CREATE TABLE object_class_fields ( ID INTEGER PRIMARY KEY AUTOINCREMENT, object_class_ID INTEGER NOT NULL, Name TEXT NOT NULL, Type TEXT NOT NULL, FOREIGN KEY (object_class_ID) REFERENCES object_class (ID) ); CREATE TABLE object_fields_content ( ID INTEGER PRIMARY KEY AUTOINCREMENT, object_class_field_ID INTEGER NOT NULL, Content TEXT NOT NULL, FOREIGN KEY (object_class_field_ID) REFERENCES object_class_fields (ID) ); -- Views for useful relations CREATE VIEW user_sessions_view AS SELECT users.ID AS user_ID, users.Username, user_sessions.session_token, user_sessions.created_at, user_sessions.valid_until FROM users JOIN user_sessions ON users.ID = user_sessions.user_ID; CREATE VIEW event_details AS SELECT events.ID AS event_ID, events.Name AS event_name, events.Description, events.Location, events.Start_Date, events.End_Date, users.Username AS organizer FROM events JOIN users ON events.user_ID = users.ID; CREATE VIEW object_storage AS SELECT objects.ID AS object_ID, objects.Name AS object_name, storagespace.Location AS storage_location FROM objects JOIN storagespace ON objects.storagespace_ID = storagespace.ID; CREATE VIEW check_in_log AS SELECT check_in.ID AS check_in_ID, users.Username, events.Name AS event_name, objects.Name AS object_name, check_in.datetime, checkin_states.Name AS checkin_state FROM check_in JOIN users ON check_in.user_ID = users.ID JOIN events ON check_in.event_ID = events.ID JOIN objects ON check_in.object_ID = objects.ID JOIN checkin_states ON check_in.checkin_state_ID = checkin_states.ID;