mirror of
https://github.com/aaronpo97/the-biergarten-app.git
synced 2026-02-16 10:42:08 +00:00
Initialize solution structure and add WebAPI project
This commit is contained in:
15
DataLayer/DataLayer.csproj
Normal file
15
DataLayer/DataLayer.csproj
Normal file
@@ -0,0 +1,15 @@
|
||||
<Project Sdk="Microsoft.NET.Sdk">
|
||||
<PropertyGroup>
|
||||
<OutputType>Exe</OutputType>
|
||||
<TargetFramework>net9.0</TargetFramework>
|
||||
<ImplicitUsings>enable</ImplicitUsings>
|
||||
<Nullable>enable</Nullable>
|
||||
</PropertyGroup>
|
||||
<ItemGroup>
|
||||
<PackageReference
|
||||
Include="Konscious.Security.Cryptography.Argon2"
|
||||
Version="1.3.1"
|
||||
/>
|
||||
<PackageReference Include="Microsoft.Data.SqlClient" Version="6.1.2" />
|
||||
</ItemGroup>
|
||||
</Project>
|
||||
213
DataLayer/SeedDB.cs
Normal file
213
DataLayer/SeedDB.cs
Normal file
@@ -0,0 +1,213 @@
|
||||
using System.Data;
|
||||
using System.Security.Cryptography;
|
||||
using System.Text;
|
||||
using Konscious.Security.Cryptography;
|
||||
using Microsoft.Data.SqlClient;
|
||||
|
||||
string ConnectionString = Environment.GetEnvironmentVariable("SEEDDB_CONNECTION_STRING")!;
|
||||
|
||||
static async Task BuildSchema(SqlConnection connection)
|
||||
{
|
||||
string sql = await File.ReadAllTextAsync(GetScriptPath("schema.sql"));
|
||||
await ExecuteScriptAsync(connection, sql);
|
||||
Console.WriteLine("Database schema created or updated successfully.");
|
||||
}
|
||||
|
||||
static async Task AddStoredProcs(SqlConnection connection)
|
||||
{
|
||||
string sql = await File.ReadAllTextAsync(
|
||||
GetScriptPath("SeedStoredProcs.sql")
|
||||
);
|
||||
await ExecuteScriptAsync(connection, sql);
|
||||
Console.WriteLine("Stored procedures added or updated successfully.");
|
||||
}
|
||||
|
||||
static async Task RunSeedAsync(SqlConnection connection)
|
||||
{
|
||||
await ExecuteStoredProcedureAsync(connection, "dbo.USP_AddTestUsers");
|
||||
Console.WriteLine("Inserted or refreshed test users.");
|
||||
|
||||
DataTable credentialRows = await BuildCredentialTableAsync(connection);
|
||||
if (credentialRows.Rows.Count > 0)
|
||||
{
|
||||
await ExecuteCredentialProcedureAsync(connection, credentialRows);
|
||||
Console.WriteLine(
|
||||
$"Generated {credentialRows.Rows.Count} credential hashes."
|
||||
);
|
||||
}
|
||||
else
|
||||
{
|
||||
Console.WriteLine("No new credentials required.");
|
||||
}
|
||||
|
||||
await ExecuteStoredProcedureAsync(
|
||||
connection,
|
||||
"dbo.USP_CreateUserVerification"
|
||||
);
|
||||
Console.WriteLine("Ensured verification rows exist for all users.");
|
||||
}
|
||||
|
||||
static async Task ExecuteStoredProcedureAsync(
|
||||
SqlConnection connection,
|
||||
string storedProcedureName
|
||||
)
|
||||
{
|
||||
await using SqlCommand command = new SqlCommand(
|
||||
storedProcedureName,
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
static async Task ExecuteCredentialProcedureAsync(
|
||||
SqlConnection connection,
|
||||
DataTable credentialTable
|
||||
)
|
||||
{
|
||||
await using SqlCommand command = new SqlCommand(
|
||||
"dbo.USP_AddUserCredentials",
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
|
||||
SqlParameter tvpParameter = command.Parameters.Add(
|
||||
"@Hash",
|
||||
SqlDbType.Structured
|
||||
);
|
||||
tvpParameter.TypeName = "dbo.TblUserHashes";
|
||||
tvpParameter.Value = credentialTable;
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
static async Task<DataTable> BuildCredentialTableAsync(SqlConnection connection)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT ua.UserAccountID,
|
||||
ua.Username
|
||||
FROM dbo.UserAccount AS ua
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM dbo.UserCredential AS uc
|
||||
WHERE uc.UserAccountID = ua.UserAccountID);
|
||||
""";
|
||||
|
||||
await using SqlCommand command = new(sql, connection);
|
||||
await using SqlDataReader reader = await command.ExecuteReaderAsync();
|
||||
|
||||
DataTable table = new();
|
||||
table.Columns.Add("UserAccountId", typeof(Guid));
|
||||
table.Columns.Add("Hash", typeof(string));
|
||||
|
||||
while (await reader.ReadAsync())
|
||||
{
|
||||
Guid userId = reader.GetGuid(0);
|
||||
string username = reader.GetString(1);
|
||||
|
||||
string password = CreatePlainTextPassword(username);
|
||||
string hash = GeneratePasswordHash(password);
|
||||
|
||||
DataRow row = table.NewRow();
|
||||
row["UserAccountId"] = userId;
|
||||
row["Hash"] = hash;
|
||||
table.Rows.Add(row);
|
||||
}
|
||||
|
||||
return table;
|
||||
}
|
||||
|
||||
static string CreatePlainTextPassword(string username) => $"{username}#2025!";
|
||||
|
||||
static string GeneratePasswordHash(string password)
|
||||
{
|
||||
byte[] salt = RandomNumberGenerator.GetBytes(16);
|
||||
|
||||
var argon2 = new Argon2id(Encoding.UTF8.GetBytes(password))
|
||||
{
|
||||
Salt = salt,
|
||||
DegreeOfParallelism = Math.Max(Environment.ProcessorCount, 1),
|
||||
MemorySize = 65536,
|
||||
Iterations = 4,
|
||||
};
|
||||
|
||||
byte[] hash = argon2.GetBytes(32);
|
||||
string saltBase64 = Convert.ToBase64String(salt);
|
||||
string hashBase64 = Convert.ToBase64String(hash);
|
||||
|
||||
// Store salt and hash together so verification can rebuild the key material.
|
||||
return $"{saltBase64}:{hashBase64}";
|
||||
}
|
||||
|
||||
static async Task ExecuteScriptAsync(SqlConnection connection, string sql)
|
||||
{
|
||||
foreach (string batch in SplitSqlBatches(sql))
|
||||
{
|
||||
if (string.IsNullOrWhiteSpace(batch))
|
||||
{
|
||||
continue;
|
||||
}
|
||||
|
||||
await using SqlCommand command = new(batch, connection);
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
}
|
||||
|
||||
static IEnumerable<string> SplitSqlBatches(string sql)
|
||||
{
|
||||
using StringReader reader = new(sql);
|
||||
StringBuilder buffer = new();
|
||||
|
||||
string? line;
|
||||
while ((line = reader.ReadLine()) is not null)
|
||||
{
|
||||
if (line.Trim().Equals("GO", StringComparison.OrdinalIgnoreCase))
|
||||
{
|
||||
yield return buffer.ToString();
|
||||
buffer.Clear();
|
||||
continue;
|
||||
}
|
||||
|
||||
buffer.AppendLine(line);
|
||||
}
|
||||
|
||||
if (buffer.Length > 0)
|
||||
{
|
||||
yield return buffer.ToString();
|
||||
}
|
||||
}
|
||||
|
||||
static string GetScriptPath(string fileName)
|
||||
{
|
||||
string projectRoot = Path.GetFullPath(
|
||||
Path.Combine(AppContext.BaseDirectory, "..", "..", "..")
|
||||
);
|
||||
string candidate = Path.Combine(projectRoot, fileName);
|
||||
|
||||
if (File.Exists(candidate))
|
||||
{
|
||||
return candidate;
|
||||
}
|
||||
|
||||
throw new FileNotFoundException(
|
||||
$"SQL script '{fileName}' was not found.",
|
||||
candidate
|
||||
);
|
||||
}
|
||||
|
||||
try
|
||||
{
|
||||
await using SqlConnection connection = new(ConnectionString);
|
||||
await connection.OpenAsync();
|
||||
Console.WriteLine("Connection to database established successfully.");
|
||||
|
||||
await BuildSchema(connection);
|
||||
await AddStoredProcs(connection);
|
||||
await RunSeedAsync(connection);
|
||||
Console.WriteLine("Seeding complete.");
|
||||
}
|
||||
catch (Exception ex)
|
||||
{
|
||||
Console.Error.WriteLine($"Seeding failed: {ex.Message}");
|
||||
Environment.ExitCode = 1;
|
||||
}
|
||||
199
DataLayer/SeedStoredProcs.sql
Normal file
199
DataLayer/SeedStoredProcs.sql
Normal file
@@ -0,0 +1,199 @@
|
||||
|
||||
USE biergarten;
|
||||
GO
|
||||
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_AddTestUsers
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
DECLARE @FullNames TABLE
|
||||
(FirstName NVARCHAR(128),
|
||||
LastName NVARCHAR(128));
|
||||
|
||||
INSERT INTO @FullNames
|
||||
(FirstName, LastName)
|
||||
VALUES
|
||||
('Aarya', 'Mathews'),
|
||||
('Aiden', 'Wells'),
|
||||
('Aleena', 'Gonzalez'),
|
||||
('Alessandra', 'Nelson'),
|
||||
('Amari', 'Tucker'),
|
||||
('Ameer', 'Huff'),
|
||||
('Amirah', 'Hicks'),
|
||||
('Analia', 'Dominguez'),
|
||||
('Anne', 'Jenkins'),
|
||||
('Apollo', 'Davis'),
|
||||
('Arianna', 'White'),
|
||||
('Aubree', 'Moore'),
|
||||
('Aubrielle', 'Raymond'),
|
||||
('Aydin', 'Odom'),
|
||||
('Bowen', 'Casey'),
|
||||
('Brock', 'Huber'),
|
||||
('Caiden', 'Strong'),
|
||||
('Cecilia', 'Rosales'),
|
||||
('Celeste', 'Barber'),
|
||||
('Chance', 'Small'),
|
||||
('Clara', 'Roberts'),
|
||||
('Collins', 'Brandt'),
|
||||
('Damir', 'Wallace'),
|
||||
('Declan', 'Crawford'),
|
||||
('Dennis', 'Decker'),
|
||||
('Dylan', 'Lang'),
|
||||
('Eliza', 'Kane'),
|
||||
('Elle', 'Poole'),
|
||||
('Elliott', 'Miles'),
|
||||
('Emelia', 'Lucas'),
|
||||
('Emilia', 'Simpson'),
|
||||
('Emmett', 'Lugo'),
|
||||
('Ethan', 'Stephens'),
|
||||
('Etta', 'Woods'),
|
||||
('Gael', 'Moran'),
|
||||
('Grant', 'Benson'),
|
||||
('Gwen', 'James'),
|
||||
('Huxley', 'Chen'),
|
||||
('Isabella', 'Fisher'),
|
||||
('Ivan', 'Mathis'),
|
||||
('Jamir', 'McMillan'),
|
||||
('Jaxson', 'Shields'),
|
||||
('Jimmy', 'Richmond'),
|
||||
('Josiah', 'Flores'),
|
||||
('Kaden', 'Enriquez'),
|
||||
('Kai', 'Lawson'),
|
||||
('Karsyn', 'Adkins'),
|
||||
('Karsyn', 'Proctor'),
|
||||
('Kayden', 'Henson'),
|
||||
('Kaylie', 'Spears'),
|
||||
('Kinslee', 'Jones'),
|
||||
('Kora', 'Guerra'),
|
||||
('Lane', 'Skinner'),
|
||||
('Laylani', 'Christian'),
|
||||
('Ledger', 'Carroll'),
|
||||
('Leilany', 'Small'),
|
||||
('Leland', 'McCall'),
|
||||
('Leonard', 'Calhoun'),
|
||||
('Levi', 'Ochoa'),
|
||||
('Lillie', 'Vang'),
|
||||
('Lola', 'Sheppard'),
|
||||
('Luciana', 'Poole'),
|
||||
('Maddox', 'Hughes'),
|
||||
('Mara', 'Blackwell'),
|
||||
('Marcellus', 'Bartlett'),
|
||||
('Margo', 'Koch'),
|
||||
('Maurice', 'Gibson'),
|
||||
('Maxton', 'Dodson'),
|
||||
('Mia', 'Parrish'),
|
||||
('Millie', 'Fuentes'),
|
||||
('Nellie', 'Villanueva'),
|
||||
('Nicolas', 'Mata'),
|
||||
('Nicolas', 'Miller'),
|
||||
('Oakleigh', 'Foster'),
|
||||
('Octavia', 'Pierce'),
|
||||
('Paisley', 'Allison'),
|
||||
('Quincy', 'Andersen'),
|
||||
('Quincy', 'Frazier'),
|
||||
('Raiden', 'Roberts'),
|
||||
('Raquel', 'Lara'),
|
||||
('Rudy', 'McIntosh'),
|
||||
('Salvador', 'Stein'),
|
||||
('Samantha', 'Dickson'),
|
||||
('Solomon', 'Richards'),
|
||||
('Sylvia', 'Hanna'),
|
||||
('Talia', 'Trujillo'),
|
||||
('Thalia', 'Farrell'),
|
||||
('Trent', 'Mayo'),
|
||||
('Trinity', 'Cummings'),
|
||||
('Ty', 'Perry'),
|
||||
('Tyler', 'Romero'),
|
||||
('Valeria', 'Pierce'),
|
||||
('Vance', 'Neal'),
|
||||
('Whitney', 'Bell'),
|
||||
('Wilder', 'Graves'),
|
||||
('William', 'Logan'),
|
||||
('Zara', 'Wilkinson'),
|
||||
('Zaria', 'Gibson'),
|
||||
('Zion', 'Watkins'),
|
||||
('Zoie', 'Armstrong');
|
||||
|
||||
|
||||
INSERT INTO dbo.UserAccount
|
||||
(Username, FirstName, LastName, Email, DateOfBirth)
|
||||
SELECT
|
||||
LEFT(LOWER(CONCAT(fn.FirstName, '.', fn.LastName)), 64) AS Username,
|
||||
fn.FirstName,
|
||||
fn.LastName,
|
||||
LEFT(LOWER(CONCAT(fn.FirstName, '.', fn.LastName, '@example.com')), 128) AS Email,
|
||||
|
||||
-- date of birth: pick age between 18 and 47 (18 + 0..29)
|
||||
DATEADD(YEAR, -(19 + ABS(CHECKSUM(NEWID())) % 30), CAST(GETDATE() AS DATE))
|
||||
FROM @FullNames AS fn;
|
||||
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
END;
|
||||
GO
|
||||
|
||||
CREATE TYPE TblUserHashes AS TABLE
|
||||
(
|
||||
UserAccountId UNIQUEIDENTIFIER NOT NULL,
|
||||
Hash NVARCHAR(MAX) NOT NULL
|
||||
);
|
||||
GO
|
||||
|
||||
-- Stored procedure to insert Argon2 hashes
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_AddUserCredentials
|
||||
(
|
||||
@Hash dbo.TblUserHashes READONLY
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
INSERT INTO dbo.UserCredential
|
||||
(UserAccountId, Hash)
|
||||
SELECT
|
||||
uah.UserAccountId,
|
||||
uah.Hash
|
||||
FROM @Hash AS uah;
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
END;
|
||||
GO
|
||||
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_CreateUserVerification
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
INSERT INTO dbo.UserVerification
|
||||
(UserAccountId)
|
||||
SELECT
|
||||
ua.UserAccountID
|
||||
FROM dbo.UserAccount AS ua
|
||||
WHERE NOT EXISTS
|
||||
(SELECT 1
|
||||
FROM dbo.UserVerification AS uv
|
||||
WHERE uv.UserAccountId = ua.UserAccountID);
|
||||
|
||||
|
||||
IF (SELECT COUNT(*)
|
||||
FROM dbo.UserVerification) != (SELECT COUNT(*)
|
||||
FROM dbo.UserAccount)
|
||||
BEGIN
|
||||
RAISERROR('UserVerification count does not match UserAccount count after insertion.', 16, 1);
|
||||
ROLLBACK TRANSACTION;
|
||||
RETURN;
|
||||
END
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
END
|
||||
GO
|
||||
512
DataLayer/schema.sql
Normal file
512
DataLayer/schema.sql
Normal file
@@ -0,0 +1,512 @@
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
USE master;
|
||||
|
||||
IF EXISTS (SELECT name
|
||||
FROM sys.databases
|
||||
WHERE name = N'Biergarten')
|
||||
BEGIN
|
||||
ALTER DATABASE Biergarten SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
|
||||
END
|
||||
GO
|
||||
|
||||
DROP DATABASE IF EXISTS Biergarten;
|
||||
GO
|
||||
|
||||
CREATE DATABASE Biergarten;
|
||||
GO
|
||||
|
||||
USE Biergarten;
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE UserAccount
|
||||
(
|
||||
UserAccountID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_UserAccountID DEFAULT NEWID(),
|
||||
|
||||
Username VARCHAR(64) NOT NULL,
|
||||
|
||||
FirstName NVARCHAR(128) NOT NULL,
|
||||
|
||||
LastName NVARCHAR(128) NOT NULL,
|
||||
|
||||
Email VARCHAR(128) NOT NULL,
|
||||
|
||||
CreatedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_UserAccount_CreatedAt DEFAULT GETDATE(),
|
||||
|
||||
UpdatedAt DATETIME,
|
||||
|
||||
DateOfBirth DATETIME NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_UserAccount
|
||||
PRIMARY KEY (UserAccountID),
|
||||
|
||||
CONSTRAINT AK_Username
|
||||
UNIQUE (Username),
|
||||
|
||||
CONSTRAINT AK_Email
|
||||
UNIQUE (Email),
|
||||
|
||||
);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE Photo -- All photos must be linked to a user account, you cannot delete a user account if they have uploaded photos
|
||||
(
|
||||
PhotoID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_PhotoID DEFAULT NEWID(),
|
||||
|
||||
Hyperlink NVARCHAR(256),
|
||||
-- storage is handled via filesystem or cloud service
|
||||
|
||||
UploadedByID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
UploadedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_Photo_UploadedAt DEFAULT GETDATE(),
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_Photo
|
||||
PRIMARY KEY (PhotoID),
|
||||
|
||||
CONSTRAINT FK_Photo_UploadedBy
|
||||
FOREIGN KEY (UploadedByID)
|
||||
REFERENCES UserAccount(UserAccountID)
|
||||
ON DELETE NO ACTION
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_Photo_UploadedByID
|
||||
ON Photo(UploadedByID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE UserAvatar -- delete avatar photo when user account is deleted
|
||||
(
|
||||
UserAvatarID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_UserAvatarID DEFAULT NEWID(),
|
||||
|
||||
UserAccountID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
PhotoID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_UserAvatar PRIMARY KEY (UserAvatarID),
|
||||
|
||||
CONSTRAINT FK_UserAvatar_UserAccount
|
||||
FOREIGN KEY (UserAccountID)
|
||||
REFERENCES UserAccount(UserAccountID)
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT FK_UserAvatar_PhotoID
|
||||
FOREIGN KEY (PhotoID)
|
||||
REFERENCES Photo(PhotoID),
|
||||
|
||||
CONSTRAINT AK_UserAvatar_UserAccountID
|
||||
UNIQUE (UserAccountID)
|
||||
)
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_UserAvatar_UserAccount
|
||||
ON UserAvatar(UserAccountID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE UserVerification -- delete verification data when user account is deleted
|
||||
(
|
||||
UserVerificationID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_UserVerificationID DEFAULT NEWID(),
|
||||
|
||||
UserAccountID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
VerificationDateTime DATETIME NOT NULL
|
||||
CONSTRAINT DF_VerificationDateTime
|
||||
DEFAULT GETDATE(),
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_UserVerification
|
||||
PRIMARY KEY (UserVerificationID),
|
||||
|
||||
CONSTRAINT FK_UserVerification_UserAccount
|
||||
FOREIGN KEY (UserAccountID)
|
||||
REFERENCES UserAccount(UserAccountID)
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT AK_UserVerification_UserAccountID
|
||||
UNIQUE (UserAccountID)
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_UserVerification_UserAccount
|
||||
ON UserVerification(UserAccountID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE UserCredential -- delete credentials when user account is deleted
|
||||
(
|
||||
UserCredentialID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_UserCredentialID DEFAULT NEWID(),
|
||||
|
||||
UserAccountID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
CreatedAt DATETIME
|
||||
CONSTRAINT DF_UserCredential_CreatedAt DEFAULT GETDATE() NOT NULL,
|
||||
|
||||
Expiry DATETIME
|
||||
CONSTRAINT DF_UserCredential_Expiry DEFAULT DATEADD(DAY, 90, GETDATE()) NOT NULL,
|
||||
|
||||
Hash NVARCHAR(MAX) NOT NULL,
|
||||
-- uses argon2
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_UserCredential
|
||||
PRIMARY KEY (UserCredentialID),
|
||||
|
||||
CONSTRAINT FK_UserCredential_UserAccount
|
||||
FOREIGN KEY (UserAccountID)
|
||||
REFERENCES UserAccount(UserAccountID)
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT AK_UserCredential_UserAccountID
|
||||
UNIQUE (UserAccountID)
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_UserCredential_UserAccount
|
||||
ON UserCredential(UserAccountID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE UserFollow
|
||||
(
|
||||
UserFollowID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_UserFollowID DEFAULT NEWID(),
|
||||
|
||||
UserAccountID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
FollowingID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
CreatedAt DATETIME
|
||||
CONSTRAINT DF_UserFollow_CreatedAt DEFAULT GETDATE() NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_UserFollow
|
||||
PRIMARY KEY (UserFollowID),
|
||||
|
||||
CONSTRAINT FK_UserFollow_UserAccount
|
||||
FOREIGN KEY (UserAccountID)
|
||||
REFERENCES UserAccount(UserAccountID),
|
||||
|
||||
CONSTRAINT FK_UserFollow_UserAccountFollowing
|
||||
FOREIGN KEY (FollowingID)
|
||||
REFERENCES UserAccount(UserAccountID),
|
||||
|
||||
CONSTRAINT CK_CannotFollowOwnAccount
|
||||
CHECK (UserAccountID != FollowingID)
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_UserFollow_UserAccount_FollowingID
|
||||
ON UserFollow(UserAccountID, FollowingID);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_UserFollow_FollowingID_UserAccount
|
||||
ON UserFollow(FollowingID, UserAccountID);
|
||||
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE Country
|
||||
(
|
||||
CountryID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_CountryID DEFAULT NEWID(),
|
||||
|
||||
CountryName NVARCHAR(100) NOT NULL,
|
||||
|
||||
CountryCode CHAR(3) NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_Country
|
||||
PRIMARY KEY (CountryID),
|
||||
);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE StateProvince
|
||||
(
|
||||
StateProvinceID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_StateProvinceID DEFAULT NEWID(),
|
||||
|
||||
StateProvinceName NVARCHAR(100) NOT NULL,
|
||||
|
||||
CountryID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_StateProvince
|
||||
PRIMARY KEY (StateProvinceID),
|
||||
|
||||
CONSTRAINT FK_StateProvince_Country
|
||||
FOREIGN KEY (CountryID)
|
||||
REFERENCES Country(CountryID)
|
||||
);
|
||||
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE City
|
||||
(
|
||||
CityID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_CityID DEFAULT NEWID(),
|
||||
|
||||
CityName NVARCHAR(100) NOT NULL,
|
||||
|
||||
StateProvinceID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_City
|
||||
PRIMARY KEY (CityID),
|
||||
);
|
||||
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE BreweryPost -- A user cannot be deleted if they have a post
|
||||
(
|
||||
BreweryPostID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_BreweryPostID DEFAULT NEWID(),
|
||||
|
||||
PostedByID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Description NVARCHAR(512) NOT NULL,
|
||||
|
||||
CreatedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_BreweryPost_CreatedAt DEFAULT GETDATE(),
|
||||
|
||||
UpdatedAt DATETIME NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CityID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Coordinates GEOGRAPHY NOT NULL,
|
||||
|
||||
CONSTRAINT PK_BreweryPost
|
||||
PRIMARY KEY (BreweryPostID),
|
||||
|
||||
CONSTRAINT FK_BreweryPost_UserAccount
|
||||
FOREIGN KEY (PostedByID)
|
||||
REFERENCES UserAccount(UserAccountID)
|
||||
ON DELETE NO ACTION
|
||||
)
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BreweryPost_PostedByID
|
||||
ON BreweryPost(PostedByID);
|
||||
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
CREATE TABLE BreweryPostPhoto -- All photos linked to a post are deleted if the post is deleted
|
||||
(
|
||||
BreweryPostPhotoID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_BreweryPostPhotoID DEFAULT NEWID(),
|
||||
|
||||
BreweryPostID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
PhotoID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
LinkedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_BreweryPostPhoto_LinkedAt DEFAULT GETDATE(),
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_BreweryPostPhoto
|
||||
PRIMARY KEY (BreweryPostPhotoID),
|
||||
|
||||
CONSTRAINT FK_BreweryPostPhoto_BreweryPost
|
||||
FOREIGN KEY (BreweryPostID)
|
||||
REFERENCES BreweryPost(BreweryPostID)
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT FK_BreweryPostPhoto_Photo
|
||||
FOREIGN KEY (PhotoID)
|
||||
REFERENCES Photo(PhotoID)
|
||||
ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BreweryPostPhoto_Photo_BreweryPost
|
||||
ON BreweryPostPhoto(PhotoID, BreweryPostID);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BreweryPostPhoto_BreweryPost_Photo
|
||||
ON BreweryPostPhoto(BreweryPostID, PhotoID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
CREATE TABLE BeerStyle
|
||||
(
|
||||
BeerStyleID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_BeerStyleID DEFAULT NEWID(),
|
||||
|
||||
StyleName NVARCHAR(100) NOT NULL,
|
||||
|
||||
Description NVARCHAR(MAX),
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_BeerStyle
|
||||
PRIMARY KEY (BeerStyleID),
|
||||
|
||||
CONSTRAINT AK_BeerStyle_StyleName
|
||||
UNIQUE (StyleName)
|
||||
);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE BeerPost
|
||||
(
|
||||
BeerPostID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_BeerPostID DEFAULT NEWID(),
|
||||
|
||||
Name NVARCHAR(100) NOT NULL,
|
||||
|
||||
Description NVARCHAR(MAX) NOT NULL,
|
||||
|
||||
ABV DECIMAL(4,2) NOT NULL,
|
||||
-- Alcohol By Volume (typically 0-67%)
|
||||
|
||||
IBU INT NOT NULL,
|
||||
-- International Bitterness Units (typically 0-100)
|
||||
|
||||
PostedByID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
BeerStyleID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
BrewedByID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
CreatedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_BeerPost_CreatedAt DEFAULT GETDATE(),
|
||||
|
||||
UpdatedAt DATETIME,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_BeerPost
|
||||
PRIMARY KEY (BeerPostID),
|
||||
|
||||
CONSTRAINT FK_BeerPost_PostedBy
|
||||
FOREIGN KEY (PostedByID)
|
||||
REFERENCES UserAccount(UserAccountID),
|
||||
|
||||
CONSTRAINT FK_BeerPost_BeerStyle
|
||||
FOREIGN KEY (BeerStyleID)
|
||||
REFERENCES BeerStyle(BeerStyleID),
|
||||
|
||||
CONSTRAINT FK_BeerPost_Brewery
|
||||
FOREIGN KEY (BrewedByID)
|
||||
REFERENCES BreweryPost(BreweryPostID),
|
||||
|
||||
CONSTRAINT CHK_BeerPost_ABV
|
||||
CHECK (ABV >= 0 AND ABV <= 67),
|
||||
|
||||
CONSTRAINT CHK_BeerPost_IBU
|
||||
CHECK (IBU >= 0 AND IBU <= 120)
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BeerPost_PostedBy
|
||||
ON BeerPost(PostedByID);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BeerPost_BeerStyle
|
||||
ON BeerPost(BeerStyleID);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BeerPost_BrewedBy
|
||||
ON BeerPost(BrewedByID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE BeerPostPhoto -- All photos linked to a beer post are deleted if the post is deleted
|
||||
(
|
||||
BeerPostPhotoID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_BeerPostPhotoID DEFAULT NEWID(),
|
||||
|
||||
BeerPostID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
PhotoID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
LinkedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_BeerPostPhoto_LinkedAt DEFAULT GETDATE(),
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_BeerPostPhoto
|
||||
PRIMARY KEY (BeerPostPhotoID),
|
||||
|
||||
CONSTRAINT FK_BeerPostPhoto_BeerPost
|
||||
FOREIGN KEY (BeerPostID)
|
||||
REFERENCES BeerPost(BeerPostID)
|
||||
ON DELETE CASCADE,
|
||||
|
||||
CONSTRAINT FK_BeerPostPhoto_Photo
|
||||
FOREIGN KEY (PhotoID)
|
||||
REFERENCES Photo(PhotoID)
|
||||
ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BeerPostPhoto_Photo_BeerPost
|
||||
ON BeerPostPhoto(PhotoID, BeerPostID);
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BeerPostPhoto_BeerPost_Photo
|
||||
ON BeerPostPhoto(BeerPostID, PhotoID);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE BeerPostComment
|
||||
(
|
||||
BeerPostCommentID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_BeerPostComment DEFAULT NEWID(),
|
||||
|
||||
Comment NVARCHAR(250) NOT NULL,
|
||||
|
||||
BeerPostID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Rating INT NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_BeerPostComment
|
||||
PRIMARY KEY (BeerPostCommentID),
|
||||
|
||||
CONSTRAINT FK_BeerPostComment_BeerPost
|
||||
FOREIGN KEY (BeerPostID) REFERENCES BeerPost(BeerPostID)
|
||||
)
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_BeerPostComment_BeerPost
|
||||
ON BeerPostComment(BeerPostID)
|
||||
|
||||
-----------------------------------------------------------------------------
|
||||
-----------------------------------------------------------------------------
|
||||
|
||||
USE Biergarten;
|
||||
SELECT *
|
||||
FROM UserAccount;
|
||||
SELECT *
|
||||
FROM UserCredential;
|
||||
SELECT *
|
||||
FROM UserVerification;
|
||||
Reference in New Issue
Block a user