Naming conventions I'll be using: UpperCamelCase tables and columns Plural table names (less likely to conflict with reserved words) Singular column names Associative table names: The names the other two tables joined by an underscore: either can be singular or plural as the relationship dictates. Primary keys are named [SingularTableName]ID, and identically when appearing as a foreign key. When needed, add a prefix: SourceWarehouseID and DestinationWarehouseID Some SQLite specific commands .open CampusVisit.db .tables PRAGMA table_info(TableName); PRAGMA foreign_keys = ON; /* Need this one to define and use foreign key contraints. */ CREATE TABLE Users( UserID INTEGER PRIMARY KEY, Name VARCHAR(100) UNIQUE NOT NULL, Email VARCHAR(20) UNIQUE NOT NULL, PasswordHash VARCHAR(64) NOT NULL, IsAdmin BOOLEAN NOT NULL, IsFaculty BOOLEAN NOT NULL, IsCoordinator BOOLEAN NOT NULL, Availability INTEGER DEFAULT -9223372036854775808 /* 64 bits. LSB is Sunday 8am, then 9am, 10, ... Monday 8am, 9am, .... Sign bit is "other time" category. */ ); CREATE TABLE Visits( VisitID INTEGER PRIMARY KEY, UserID INTEGER, /* DEFAULT NULL is implicit in SQLite. NULL values are allowed with the foreign key. */ StudentInfo VARCHAR(100) NOT NULL DEFAULT '', OtherVisitors VARCHAR(100) NOT NULL DEFAULT '', Hometown VARCHAR(50) NOT NULL DEFAULT '', Day VARCHAR(10) NOT NULL, /* YYYY-MM-DD */ Availability INTEGER NOT NULL DEFAULT 0, /* Same format as Users.Availability */ DecidedTime INTEGER, /* Same format as Users.Availability */ Status VARCHAR(9) CHECK(Status IN ('proposed','assigned','confirmed','completed','canceled')) NOT NULL DEFAULT 'proposed', Notes VARCHAR(500) NOT NULL DEFAULT '', NotificationFrequency INTEGER NOT NULL DEFAULT 2, FOREIGN KEY(UserID) REFERENCES Users(UserID) ); CREATE TABLE Visits_Users ( VisitID INTEGER NOT NULL, UserID INTEGER NOT NULL, Willingness VARCHAR(10) CHECK(Willingness IN ('cannot', 'prefer not', 'can do')) NOT NULL, /* unknown if pair is missing from the table */ PRIMARY KEY (VisitID, UserID), FOREIGN KEY(VisitID) REFERENCES Visits(VisitID), FOREIGN KEY(UserID) REFERENCES Users(UserID) ); CREATE TABLE Settings( Key VARCHAR(100) PRIMARY KEY, Value VARCHAR(100) NOT NULL DEFAULT '' ); Initialization: Initial values for global settings (hyperlink lifetime and notification frequency) INSERT INTO Settings VALUES ('HyperlinkLifetime','7'); INSERT INTO Settings VALUES ('CoordinatorNotificationFrequency','3'); Login screen: Check username/password SELECT COUNT() FROM Users WHERE Email='mkowalcz@nmu.edu' AND PasswordHash='secret'; Visits tab: Create new visit INSERT INTO Visits (StudentInfo,Day,Availability) VALUES ('Sam Bloggs, Major: CS', '2025-04-15',-9223372036854775808); INSERT INTO Visits (StudentInfo,Day,Availability) VALUES ('Joe Bloggs, Major: CS', '2025-04-16', 28); INSERT INTO Visits (StudentInfo,Day,Availability) VALUES ('Mary Bloggs, Major: CS', '2025-04-17', 256); Get list of all visits, joined with faculty guides SELECT Visits.VisitID,Visits.StudentInfo,Users.name FROM Visits LEFT JOIN Users ON Visits.UserID=Users.UserID; Delete a visit DELETE FROM Visits WHERE VisitID='1'; Visit detail window: Get committment levels for all faculty for a given visit SELECT VisitID, Users.UserID, Name, Email FROM Visits_Users INNER JOIN Users ON Visits_Users.UserID=Users.UserID WHERE VisitID=2; Find intersection of visit availability with each faculty availability SELECT Visits.VisitID, Users.UserID, Name, Visits.Availability & Users.Availability FROM Visits INNER JOIN Users WHERE VisitID=1; /* Note that this is using the bitwise and operator "&" because of the way we are storing availability. */ Set email frequency for a particular visit UPDATE Visits SET NotificationFrequency=4 WHERE VisitID=2; Set committment level for a given faculty member INSERT INTO Visits_Users VALUES (1,1,'prefer not'); INSERT INTO Visits_Users VALUES (1,2,'can do'); INSERT INTO Visits_Users VALUES (2,1,'can do'); INSERT INTO Visits_Users VALUES (2,2,'prefer not'); INSERT INTO Visits_Users VALUES (3,1,'can do'); INSERT INTO Visits_Users VALUES (3,2,'cannot'); Claim a visit and a time UPDATE Visits SET DecidedTime=4, Status='assigned', UserId=1 WHERE VisitID=2 AND Status='proposed'; INSERT INTO Visits_Users VALUES (1,1,'can do') ON CONFLICT (VisitID,UserID) DO UPDATE SET Willingness='can do' WHERE (VisitID,UserID)=(2,1); Update visit details UPDATE Visits SET UserID=1 WHERE VisitID=2; User tab: Get list of users, including faculty availability SELECT * FROM Users; Create new user INSERT INTO Users(Name,Email,PasswordHash,IsAdmin,IsFaculty,IsCoordinator) VALUES ('DrKow', 'mkowalcz@nmu.edu', 'secret', TRUE, TRUE, TRUE); INSERT INTO Users(Name,Email,PasswordHash,IsAdmin,IsFaculty,IsCoordinator) VALUES ('Randy', 'rappleto@nmu.edu', 'secret', FALSE, TRUE, FALSE); Update user attributes UPDATE Users SET PasswordHash='secret',IsAdmin=TRUE WHERE Name='DrKow'; Update faculty availability UPDATE Users SET Availability=-9223372036854775808 WHERE Email='rappleto@nmu.edu'; Delete user DELETE FROM Users WHERE UserID=2; Update global settings UPDATE Settings SET Value='5' WHERE Key='HyperlinkLifetime'; UPDATE Settings SET Value='5' WHERE Key='CoordinatorNotificationFrequency'; References: https://stackoverflow.com/questions/7662/database-table-and-column-naming-conventions https://dev.to/ovid/database-naming-standards-2061 https://stackoverflow.com/questions/3037188/naming-of-boolean-column-in-database-table https://stackoverflow.com/questions/2300356/using-a-single-row-configuration-table-in-sql-server-database-bad-idea https://www.sqlite.org/foreignkeys.html https://www.sqlite.org/lang.html