diff --git a/.config/dotnet-tools.json b/.config/dotnet-tools.json new file mode 100644 index 0000000..03df232 --- /dev/null +++ b/.config/dotnet-tools.json @@ -0,0 +1,13 @@ +{ + "version": 1, + "isRoot": true, + "tools": { + "csharpier": { + "version": "1.2.1", + "commands": [ + "csharpier" + ], + "rollForward": false + } + } +} \ No newline at end of file diff --git a/.vscode/settings.json b/.vscode/settings.json deleted file mode 100644 index 6a8e057..0000000 --- a/.vscode/settings.json +++ /dev/null @@ -1,3 +0,0 @@ -{ - "dotnet.defaultSolution": "SeedDB.sln" -} diff --git a/BusinessLayer/BusinessLayer.csproj b/BusinessLayer/BusinessLayer.csproj index 125f4c9..bf9d3be 100644 --- a/BusinessLayer/BusinessLayer.csproj +++ b/BusinessLayer/BusinessLayer.csproj @@ -1,9 +1,7 @@  - net9.0 enable enable - diff --git a/DataAccessLayer/Class1.cs b/DataAccessLayer/Class1.cs index b3a3edf..338ee50 100644 --- a/DataAccessLayer/Class1.cs +++ b/DataAccessLayer/Class1.cs @@ -1,6 +1,3 @@ namespace DataAccessLayer; -public class Class1 -{ - -} +public class Class1 { } diff --git a/DataAccessLayer/DataAccessLayer.csproj b/DataAccessLayer/DataAccessLayer.csproj index 125f4c9..bf9d3be 100644 --- a/DataAccessLayer/DataAccessLayer.csproj +++ b/DataAccessLayer/DataAccessLayer.csproj @@ -1,9 +1,7 @@  - net9.0 enable enable - diff --git a/DataLayer/schema.sql b/DataLayer/schema.sql index cbf9406..c204ba7 100644 --- a/DataLayer/schema.sql +++ b/DataLayer/schema.sql @@ -7,7 +7,7 @@ IF EXISTS (SELECT name FROM sys.databases WHERE name = N'Biergarten') BEGIN - ALTER DATABASE Biergarten SET SINGLE_USER WITH ROLLBACK IMMEDIATE; + ALTER DATABASE Biergarten SET SINGLE_USER WITH ROLLBACK IMMEDIATE; END GO @@ -24,34 +24,34 @@ USE Biergarten; CREATE TABLE UserAccount ( - UserAccountID UNIQUEIDENTIFIER - CONSTRAINT DF_UserAccountID DEFAULT NEWID(), + UserAccountID UNIQUEIDENTIFIER + CONSTRAINT DF_UserAccountID DEFAULT NEWID(), - Username VARCHAR(64) NOT NULL, + Username VARCHAR(64) NOT NULL, - FirstName NVARCHAR(128) NOT NULL, + FirstName NVARCHAR(128) NOT NULL, - LastName NVARCHAR(128) NOT NULL, + LastName NVARCHAR(128) NOT NULL, - Email VARCHAR(128) NOT NULL, + Email VARCHAR(128) NOT NULL, - CreatedAt DATETIME NOT NULL - CONSTRAINT DF_UserAccount_CreatedAt DEFAULT GETDATE(), + CreatedAt DATETIME NOT NULL + CONSTRAINT DF_UserAccount_CreatedAt DEFAULT GETDATE(), - UpdatedAt DATETIME, + UpdatedAt DATETIME, - DateOfBirth DATETIME NOT NULL, + DateOfBirth DATETIME NOT NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_UserAccount - PRIMARY KEY (UserAccountID), + CONSTRAINT PK_UserAccount + PRIMARY KEY (UserAccountID), - CONSTRAINT AK_Username - UNIQUE (Username), + CONSTRAINT AK_Username + UNIQUE (Username), - CONSTRAINT AK_Email - UNIQUE (Email), + CONSTRAINT AK_Email + UNIQUE (Email) ); @@ -60,167 +60,167 @@ CREATE TABLE UserAccount 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(), + PhotoID UNIQUEIDENTIFIER + CONSTRAINT DF_PhotoID DEFAULT NEWID(), - Hyperlink NVARCHAR(256), - -- storage is handled via filesystem or cloud service + Hyperlink NVARCHAR(256), + -- storage is handled via filesystem or cloud service - UploadedByID UNIQUEIDENTIFIER NOT NULL, + UploadedByID UNIQUEIDENTIFIER NOT NULL, - UploadedAt DATETIME NOT NULL - CONSTRAINT DF_Photo_UploadedAt DEFAULT GETDATE(), + UploadedAt DATETIME NOT NULL + CONSTRAINT DF_Photo_UploadedAt DEFAULT GETDATE(), - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_Photo - PRIMARY KEY (PhotoID), + CONSTRAINT PK_Photo + PRIMARY KEY (PhotoID), - CONSTRAINT FK_Photo_UploadedBy - FOREIGN KEY (UploadedByID) - REFERENCES UserAccount(UserAccountID) - ON DELETE NO ACTION + CONSTRAINT FK_Photo_UploadedBy + FOREIGN KEY (UploadedByID) + REFERENCES UserAccount(UserAccountID) + ON DELETE NO ACTION ); CREATE NONCLUSTERED INDEX IX_Photo_UploadedByID - ON Photo(UploadedByID); + ON Photo(UploadedByID); ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- CREATE TABLE UserAvatar -- delete avatar photo when user account is deleted ( - UserAvatarID UNIQUEIDENTIFIER - CONSTRAINT DF_UserAvatarID DEFAULT NEWID(), + UserAvatarID UNIQUEIDENTIFIER + CONSTRAINT DF_UserAvatarID DEFAULT NEWID(), - UserAccountID UNIQUEIDENTIFIER NOT NULL, + UserAccountID UNIQUEIDENTIFIER NOT NULL, - PhotoID UNIQUEIDENTIFIER NOT NULL, + PhotoID UNIQUEIDENTIFIER NOT NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_UserAvatar PRIMARY KEY (UserAvatarID), + CONSTRAINT PK_UserAvatar PRIMARY KEY (UserAvatarID), - CONSTRAINT FK_UserAvatar_UserAccount - FOREIGN KEY (UserAccountID) - REFERENCES UserAccount(UserAccountID) - ON DELETE CASCADE, + CONSTRAINT FK_UserAvatar_UserAccount + FOREIGN KEY (UserAccountID) + REFERENCES UserAccount(UserAccountID) + ON DELETE CASCADE, - CONSTRAINT FK_UserAvatar_PhotoID - FOREIGN KEY (PhotoID) - REFERENCES Photo(PhotoID), + CONSTRAINT FK_UserAvatar_PhotoID + FOREIGN KEY (PhotoID) + REFERENCES Photo(PhotoID), - CONSTRAINT AK_UserAvatar_UserAccountID - UNIQUE (UserAccountID) + CONSTRAINT AK_UserAvatar_UserAccountID + UNIQUE (UserAccountID) ) CREATE NONCLUSTERED INDEX IX_UserAvatar_UserAccount - ON UserAvatar(UserAccountID); + ON UserAvatar(UserAccountID); ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- CREATE TABLE UserVerification -- delete verification data when user account is deleted ( - UserVerificationID UNIQUEIDENTIFIER - CONSTRAINT DF_UserVerificationID DEFAULT NEWID(), + UserVerificationID UNIQUEIDENTIFIER + CONSTRAINT DF_UserVerificationID DEFAULT NEWID(), - UserAccountID UNIQUEIDENTIFIER NOT NULL, + UserAccountID UNIQUEIDENTIFIER NOT NULL, - VerificationDateTime DATETIME NOT NULL - CONSTRAINT DF_VerificationDateTime - DEFAULT GETDATE(), + VerificationDateTime DATETIME NOT NULL + CONSTRAINT DF_VerificationDateTime + DEFAULT GETDATE(), - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_UserVerification - PRIMARY KEY (UserVerificationID), + CONSTRAINT PK_UserVerification + PRIMARY KEY (UserVerificationID), - CONSTRAINT FK_UserVerification_UserAccount - FOREIGN KEY (UserAccountID) - REFERENCES UserAccount(UserAccountID) - ON DELETE CASCADE, + CONSTRAINT FK_UserVerification_UserAccount + FOREIGN KEY (UserAccountID) + REFERENCES UserAccount(UserAccountID) + ON DELETE CASCADE, - CONSTRAINT AK_UserVerification_UserAccountID - UNIQUE (UserAccountID) + CONSTRAINT AK_UserVerification_UserAccountID + UNIQUE (UserAccountID) ); CREATE NONCLUSTERED INDEX IX_UserVerification_UserAccount - ON UserVerification(UserAccountID); + ON UserVerification(UserAccountID); ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- CREATE TABLE UserCredential -- delete credentials when user account is deleted ( - UserCredentialID UNIQUEIDENTIFIER - CONSTRAINT DF_UserCredentialID DEFAULT NEWID(), + UserCredentialID UNIQUEIDENTIFIER + CONSTRAINT DF_UserCredentialID DEFAULT NEWID(), - UserAccountID UNIQUEIDENTIFIER NOT NULL, + UserAccountID UNIQUEIDENTIFIER NOT NULL, - CreatedAt DATETIME - CONSTRAINT DF_UserCredential_CreatedAt DEFAULT GETDATE() 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, + Expiry DATETIME + CONSTRAINT DF_UserCredential_Expiry DEFAULT DATEADD(DAY, 90, GETDATE()) NOT NULL, - Hash NVARCHAR(MAX) NOT NULL, - -- uses argon2 + Hash NVARCHAR(MAX) NOT NULL, + -- uses argon2 - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_UserCredential - PRIMARY KEY (UserCredentialID), + CONSTRAINT PK_UserCredential + PRIMARY KEY (UserCredentialID), - CONSTRAINT FK_UserCredential_UserAccount - FOREIGN KEY (UserAccountID) - REFERENCES UserAccount(UserAccountID) - ON DELETE CASCADE, + CONSTRAINT FK_UserCredential_UserAccount + FOREIGN KEY (UserAccountID) + REFERENCES UserAccount(UserAccountID) + ON DELETE CASCADE, - CONSTRAINT AK_UserCredential_UserAccountID - UNIQUE (UserAccountID) + CONSTRAINT AK_UserCredential_UserAccountID + UNIQUE (UserAccountID) ); CREATE NONCLUSTERED INDEX IX_UserCredential_UserAccount - ON UserCredential(UserAccountID); + ON UserCredential(UserAccountID); ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- CREATE TABLE UserFollow ( - UserFollowID UNIQUEIDENTIFIER - CONSTRAINT DF_UserFollowID DEFAULT NEWID(), + UserFollowID UNIQUEIDENTIFIER + CONSTRAINT DF_UserFollowID DEFAULT NEWID(), - UserAccountID UNIQUEIDENTIFIER NOT NULL, + UserAccountID UNIQUEIDENTIFIER NOT NULL, - FollowingID UNIQUEIDENTIFIER NOT NULL, + FollowingID UNIQUEIDENTIFIER NOT NULL, - CreatedAt DATETIME - CONSTRAINT DF_UserFollow_CreatedAt DEFAULT GETDATE() NOT NULL, + CreatedAt DATETIME + CONSTRAINT DF_UserFollow_CreatedAt DEFAULT GETDATE() NOT NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_UserFollow - PRIMARY KEY (UserFollowID), + CONSTRAINT PK_UserFollow + PRIMARY KEY (UserFollowID), - CONSTRAINT FK_UserFollow_UserAccount - FOREIGN KEY (UserAccountID) - REFERENCES UserAccount(UserAccountID), + CONSTRAINT FK_UserFollow_UserAccount + FOREIGN KEY (UserAccountID) + REFERENCES UserAccount(UserAccountID), - CONSTRAINT FK_UserFollow_UserAccountFollowing - FOREIGN KEY (FollowingID) - REFERENCES UserAccount(UserAccountID), + CONSTRAINT FK_UserFollow_UserAccountFollowing + FOREIGN KEY (FollowingID) + REFERENCES UserAccount(UserAccountID), - CONSTRAINT CK_CannotFollowOwnAccount - CHECK (UserAccountID != FollowingID) + CONSTRAINT CK_CannotFollowOwnAccount + CHECK (UserAccountID != FollowingID) ); CREATE NONCLUSTERED INDEX IX_UserFollow_UserAccount_FollowingID - ON UserFollow(UserAccountID, FollowingID); + ON UserFollow(UserAccountID, FollowingID); CREATE NONCLUSTERED INDEX IX_UserFollow_FollowingID_UserAccount - ON UserFollow(FollowingID, UserAccountID); + ON UserFollow(FollowingID, UserAccountID); ---------------------------------------------------------------------------- @@ -228,17 +228,20 @@ CREATE NONCLUSTERED INDEX IX_UserFollow_FollowingID_UserAccount CREATE TABLE Country ( - CountryID UNIQUEIDENTIFIER - CONSTRAINT DF_CountryID DEFAULT NEWID(), + CountryID UNIQUEIDENTIFIER + CONSTRAINT DF_CountryID DEFAULT NEWID(), - CountryName NVARCHAR(100) NOT NULL, + CountryName NVARCHAR(100) NOT NULL, - CountryCode CHAR(3) NOT NULL, + ISO3616_1 CHAR(2) NOT NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_Country - PRIMARY KEY (CountryID), + CONSTRAINT PK_Country + PRIMARY KEY (CountryID), + + CONSTRAINT AK_Country_ISO3616_1 + UNIQUE (ISO3616_1) ); ---------------------------------------------------------------------------- @@ -246,107 +249,157 @@ CREATE TABLE Country CREATE TABLE StateProvince ( - StateProvinceID UNIQUEIDENTIFIER - CONSTRAINT DF_StateProvinceID DEFAULT NEWID(), + StateProvinceID UNIQUEIDENTIFIER + CONSTRAINT DF_StateProvinceID DEFAULT NEWID(), - StateProvinceName NVARCHAR(100) NOT NULL, + StateProvinceName NVARCHAR(100) NOT NULL, - CountryID UNIQUEIDENTIFIER NOT NULL, + ISO3616_2 CHAR(6) NOT NULL, + -- eg 'US-CA' for California, 'CA-ON' for Ontario - Timer ROWVERSION, + CountryID UNIQUEIDENTIFIER NOT NULL, - CONSTRAINT PK_StateProvince - PRIMARY KEY (StateProvinceID), + Timer ROWVERSION, - CONSTRAINT FK_StateProvince_Country - FOREIGN KEY (CountryID) - REFERENCES Country(CountryID) + CONSTRAINT PK_StateProvince + PRIMARY KEY (StateProvinceID), + + CONSTRAINT AK_StateProvince_ISO3616_2 + UNIQUE (ISO3616_2), + + CONSTRAINT FK_StateProvince_Country + FOREIGN KEY (CountryID) + REFERENCES Country(CountryID) ); +CREATE NONCLUSTERED INDEX IX_StateProvince_Country + ON StateProvince(CountryID); ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- CREATE TABLE City ( - CityID UNIQUEIDENTIFIER - CONSTRAINT DF_CityID DEFAULT NEWID(), + CityID UNIQUEIDENTIFIER + CONSTRAINT DF_CityID DEFAULT NEWID(), - CityName NVARCHAR(100) NOT NULL, + CityName NVARCHAR(100) NOT NULL, - StateProvinceID UNIQUEIDENTIFIER NOT NULL, + StateProvinceID UNIQUEIDENTIFIER NOT NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_City - PRIMARY KEY (CityID), + CONSTRAINT PK_City + PRIMARY KEY (CityID), + + CONSTRAINT FK_City_StateProvince + FOREIGN KEY (StateProvinceID) + REFERENCES StateProvince(StateProvinceID) ); +CREATE NONCLUSTERED INDEX IX_City_StateProvince + ON City(StateProvinceID); + ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- CREATE TABLE BreweryPost -- A user cannot be deleted if they have a post ( - BreweryPostID UNIQUEIDENTIFIER - CONSTRAINT DF_BreweryPostID DEFAULT NEWID(), + BreweryPostID UNIQUEIDENTIFIER + CONSTRAINT DF_BreweryPostID DEFAULT NEWID(), - PostedByID UNIQUEIDENTIFIER NOT NULL, + PostedByID UNIQUEIDENTIFIER NOT NULL, - Description NVARCHAR(512) NOT NULL, + Description NVARCHAR(512) NOT NULL, - CreatedAt DATETIME NOT NULL - CONSTRAINT DF_BreweryPost_CreatedAt DEFAULT GETDATE(), + CreatedAt DATETIME NOT NULL + CONSTRAINT DF_BreweryPost_CreatedAt DEFAULT GETDATE(), - UpdatedAt DATETIME NULL, + UpdatedAt DATETIME NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CityID UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT PK_BreweryPost + PRIMARY KEY (BreweryPostID), - Coordinates GEOGRAPHY NOT NULL, + CONSTRAINT FK_BreweryPost_UserAccount + FOREIGN KEY (PostedByID) + REFERENCES UserAccount(UserAccountID) + ON DELETE NO ACTION, - 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); + ON BreweryPost(PostedByID); - ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- +---------------------------------------------------------------------------- +CREATE TABLE BreweryPostLocation ( + BreweryPostLocationID UNIQUEIDENTIFIER + CONSTRAINT DF_BreweryPostLocationID DEFAULT NEWID(), + + BreweryPostID UNIQUEIDENTIFIER NOT NULL, + + AddressLine1 NVARCHAR(256) NOT NULL, + + AddressLine2 NVARCHAR(256), + + PostalCode NVARCHAR(20) NOT NULL, + + CityID UNIQUEIDENTIFIER NOT NULL, + + Coordinates GEOGRAPHY NOT NULL, + + Timer ROWVERSION, + + CONSTRAINT PK_BreweryPostLocation + PRIMARY KEY (BreweryPostLocationID), + + CONSTRAINT AK_BreweryPostLocation_BreweryPostID + UNIQUE (BreweryPostID), + + CONSTRAINT FK_BreweryPostLocation_BreweryPost + FOREIGN KEY (BreweryPostID) + REFERENCES BreweryPost(BreweryPostID) + ON DELETE CASCADE +); + +CREATE NONCLUSTERED INDEX IX_BreweryPostLocation_BreweryPost + ON BreweryPostLocation(BreweryPostID); + +CREATE NONCLUSTERED INDEX IX_BreweryPostLocation_City + ON BreweryPostLocation(CityID); + +---------------------------------------------------------------------------- +---------------------------------------------------------------------------- + CREATE TABLE BreweryPostPhoto -- All photos linked to a post are deleted if the post is deleted ( - BreweryPostPhotoID UNIQUEIDENTIFIER - CONSTRAINT DF_BreweryPostPhotoID DEFAULT NEWID(), + BreweryPostPhotoID UNIQUEIDENTIFIER + CONSTRAINT DF_BreweryPostPhotoID DEFAULT NEWID(), - BreweryPostID UNIQUEIDENTIFIER NOT NULL, + BreweryPostID UNIQUEIDENTIFIER NOT NULL, - PhotoID UNIQUEIDENTIFIER NOT NULL, + PhotoID UNIQUEIDENTIFIER NOT NULL, - LinkedAt DATETIME NOT NULL - CONSTRAINT DF_BreweryPostPhoto_LinkedAt DEFAULT GETDATE(), + LinkedAt DATETIME NOT NULL + CONSTRAINT DF_BreweryPostPhoto_LinkedAt DEFAULT GETDATE(), - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_BreweryPostPhoto - PRIMARY KEY (BreweryPostPhotoID), + CONSTRAINT PK_BreweryPostPhoto + PRIMARY KEY (BreweryPostPhotoID), - CONSTRAINT FK_BreweryPostPhoto_BreweryPost - FOREIGN KEY (BreweryPostID) - REFERENCES BreweryPost(BreweryPostID) - ON DELETE CASCADE, + 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 + CONSTRAINT FK_BreweryPostPhoto_Photo + FOREIGN KEY (PhotoID) + REFERENCES Photo(PhotoID) + ON DELETE CASCADE ); CREATE NONCLUSTERED INDEX IX_BreweryPostPhoto_Photo_BreweryPost @@ -359,20 +412,20 @@ ON BreweryPostPhoto(BreweryPostID, PhotoID); ---------------------------------------------------------------------------- CREATE TABLE BeerStyle ( - BeerStyleID UNIQUEIDENTIFIER - CONSTRAINT DF_BeerStyleID DEFAULT NEWID(), + BeerStyleID UNIQUEIDENTIFIER + CONSTRAINT DF_BeerStyleID DEFAULT NEWID(), - StyleName NVARCHAR(100) NOT NULL, + StyleName NVARCHAR(100) NOT NULL, - Description NVARCHAR(MAX), + Description NVARCHAR(MAX), - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_BeerStyle - PRIMARY KEY (BeerStyleID), + CONSTRAINT PK_BeerStyle + PRIMARY KEY (BeerStyleID), - CONSTRAINT AK_BeerStyle_StyleName - UNIQUE (StyleName) + CONSTRAINT AK_BeerStyle_StyleName + UNIQUE (StyleName) ); ---------------------------------------------------------------------------- @@ -380,51 +433,51 @@ CREATE TABLE BeerStyle CREATE TABLE BeerPost ( - BeerPostID UNIQUEIDENTIFIER - CONSTRAINT DF_BeerPostID DEFAULT NEWID(), + BeerPostID UNIQUEIDENTIFIER + CONSTRAINT DF_BeerPostID DEFAULT NEWID(), - Name NVARCHAR(100) NOT NULL, + Name NVARCHAR(100) NOT NULL, - Description NVARCHAR(MAX) NOT NULL, + Description NVARCHAR(MAX) NOT NULL, - ABV DECIMAL(4,2) NOT NULL, - -- Alcohol By Volume (typically 0-67%) + ABV DECIMAL(4,2) NOT NULL, + -- Alcohol By Volume (typically 0-67%) - IBU INT NOT NULL, - -- International Bitterness Units (typically 0-100) + IBU INT NOT NULL, + -- International Bitterness Units (typically 0-100) - PostedByID UNIQUEIDENTIFIER NOT NULL, + PostedByID UNIQUEIDENTIFIER NOT NULL, - BeerStyleID UNIQUEIDENTIFIER NOT NULL, + BeerStyleID UNIQUEIDENTIFIER NOT NULL, - BrewedByID UNIQUEIDENTIFIER NOT NULL, + BrewedByID UNIQUEIDENTIFIER NOT NULL, - CreatedAt DATETIME NOT NULL - CONSTRAINT DF_BeerPost_CreatedAt DEFAULT GETDATE(), + CreatedAt DATETIME NOT NULL + CONSTRAINT DF_BeerPost_CreatedAt DEFAULT GETDATE(), - UpdatedAt DATETIME, + UpdatedAt DATETIME, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_BeerPost + CONSTRAINT PK_BeerPost PRIMARY KEY (BeerPostID), - CONSTRAINT FK_BeerPost_PostedBy + CONSTRAINT FK_BeerPost_PostedBy FOREIGN KEY (PostedByID) REFERENCES UserAccount(UserAccountID), - CONSTRAINT FK_BeerPost_BeerStyle - FOREIGN KEY (BeerStyleID) - REFERENCES BeerStyle(BeerStyleID), + CONSTRAINT FK_BeerPost_BeerStyle + FOREIGN KEY (BeerStyleID) + REFERENCES BeerStyle(BeerStyleID), - CONSTRAINT FK_BeerPost_Brewery - FOREIGN KEY (BrewedByID) - REFERENCES BreweryPost(BreweryPostID), + CONSTRAINT FK_BeerPost_Brewery + FOREIGN KEY (BrewedByID) + REFERENCES BreweryPost(BreweryPostID), - CONSTRAINT CHK_BeerPost_ABV + CONSTRAINT CHK_BeerPost_ABV CHECK (ABV >= 0 AND ABV <= 67), - CONSTRAINT CHK_BeerPost_IBU + CONSTRAINT CHK_BeerPost_IBU CHECK (IBU >= 0 AND IBU <= 120) ); @@ -432,40 +485,40 @@ CREATE NONCLUSTERED INDEX IX_BeerPost_PostedBy ON BeerPost(PostedByID); CREATE NONCLUSTERED INDEX IX_BeerPost_BeerStyle - ON BeerPost(BeerStyleID); + ON BeerPost(BeerStyleID); CREATE NONCLUSTERED INDEX IX_BeerPost_BrewedBy - ON BeerPost(BrewedByID); + 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(), + BeerPostPhotoID UNIQUEIDENTIFIER + CONSTRAINT DF_BeerPostPhotoID DEFAULT NEWID(), - BeerPostID UNIQUEIDENTIFIER NOT NULL, + BeerPostID UNIQUEIDENTIFIER NOT NULL, - PhotoID UNIQUEIDENTIFIER NOT NULL, + PhotoID UNIQUEIDENTIFIER NOT NULL, - LinkedAt DATETIME NOT NULL - CONSTRAINT DF_BeerPostPhoto_LinkedAt DEFAULT GETDATE(), + LinkedAt DATETIME NOT NULL + CONSTRAINT DF_BeerPostPhoto_LinkedAt DEFAULT GETDATE(), - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_BeerPostPhoto - PRIMARY KEY (BeerPostPhotoID), + CONSTRAINT PK_BeerPostPhoto + PRIMARY KEY (BeerPostPhotoID), - CONSTRAINT FK_BeerPostPhoto_BeerPost - FOREIGN KEY (BeerPostID) - REFERENCES BeerPost(BeerPostID) - ON DELETE CASCADE, + 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 + CONSTRAINT FK_BeerPostPhoto_Photo + FOREIGN KEY (PhotoID) + REFERENCES Photo(PhotoID) + ON DELETE CASCADE ); CREATE NONCLUSTERED INDEX IX_BeerPostPhoto_Photo_BeerPost @@ -479,34 +532,27 @@ ON BeerPostPhoto(BeerPostID, PhotoID); CREATE TABLE BeerPostComment ( - BeerPostCommentID UNIQUEIDENTIFIER - CONSTRAINT DF_BeerPostComment DEFAULT NEWID(), + BeerPostCommentID UNIQUEIDENTIFIER + CONSTRAINT DF_BeerPostComment DEFAULT NEWID(), - Comment NVARCHAR(250) NOT NULL, + Comment NVARCHAR(250) NOT NULL, - BeerPostID UNIQUEIDENTIFIER NOT NULL, + BeerPostID UNIQUEIDENTIFIER NOT NULL, - Rating INT NOT NULL, + Rating INT NOT NULL, - Timer ROWVERSION, + Timer ROWVERSION, - CONSTRAINT PK_BeerPostComment + CONSTRAINT PK_BeerPostComment PRIMARY KEY (BeerPostCommentID), - CONSTRAINT FK_BeerPostComment_BeerPost - FOREIGN KEY (BeerPostID) REFERENCES BeerPost(BeerPostID) + CONSTRAINT FK_BeerPostComment_BeerPost + FOREIGN KEY (BeerPostID) REFERENCES BeerPost(BeerPostID) ) CREATE NONCLUSTERED INDEX IX_BeerPostComment_BeerPost - ON BeerPostComment(BeerPostID) + ON BeerPostComment(BeerPostID) ------------------------------------------------------------------------------ ------------------------------------------------------------------------------ - -USE Biergarten; -SELECT * -FROM UserAccount; -SELECT * -FROM UserCredential; -SELECT * -FROM UserVerification; \ No newline at end of file +---------------------------------------------------------------------------- +---------------------------------------------------------------------------- +-- EOF \ No newline at end of file diff --git a/DataLayer/SeedDB.cs b/DataLayer/seed/SeedDB.cs similarity index 73% rename from DataLayer/SeedDB.cs rename to DataLayer/seed/SeedDB.cs index c384b0a..a1af300 100644 --- a/DataLayer/SeedDB.cs +++ b/DataLayer/seed/SeedDB.cs @@ -4,7 +4,9 @@ using System.Text; using Konscious.Security.Cryptography; using Microsoft.Data.SqlClient; -string ConnectionString = Environment.GetEnvironmentVariable("SEEDDB_CONNECTION_STRING")!; +string ConnectionString = Environment.GetEnvironmentVariable( + "DB_CONNECTION_STRING" +)!; static async Task BuildSchema(SqlConnection connection) { @@ -13,13 +15,61 @@ static async Task BuildSchema(SqlConnection connection) Console.WriteLine("Database schema created or updated successfully."); } -static async Task AddStoredProcs(SqlConnection connection) +static async Task AddStoredProcsAndFunctions(SqlConnection connection) { - string sql = await File.ReadAllTextAsync( - GetScriptPath("SeedStoredProcs.sql") + // New approach: load functions first, then procedures, from dedicated folders. + // Fallback to legacy combined file if folders are missing. + string projectRoot = Path.GetFullPath( + Path.Combine(AppContext.BaseDirectory, "..", "..", "..") ); - await ExecuteScriptAsync(connection, sql); - Console.WriteLine("Stored procedures added or updated successfully."); + + string functionsDir = Path.Combine(projectRoot, "seed", "functions"); + string proceduresDir = Path.Combine(projectRoot, "seed", "procedures"); + + if (Directory.Exists(functionsDir)) + { + foreach ( + string file in Directory + .EnumerateFiles( + functionsDir, + "*.sql", + SearchOption.TopDirectoryOnly + ) + .OrderBy(f => f, StringComparer.OrdinalIgnoreCase) + ) + { + string sql = await File.ReadAllTextAsync(file); + await ExecuteScriptAsync(connection, sql); + Console.WriteLine( + $"Executed function script: {Path.GetFileName(file)}" + ); + } + } + + if (Directory.Exists(proceduresDir)) + { + foreach ( + string file in Directory + .EnumerateFiles( + proceduresDir, + "*.sql", + SearchOption.TopDirectoryOnly + ) + .OrderBy(f => f, StringComparer.OrdinalIgnoreCase) + ) + { + string sql = await File.ReadAllTextAsync(file); + await ExecuteScriptAsync(connection, sql); + Console.WriteLine( + $"Executed procedure script: {Path.GetFileName(file)}" + ); + } + } + + Console.WriteLine( + "Functions and stored procedures added or updated successfully." + ); + return; } static async Task RunSeedAsync(SqlConnection connection) @@ -202,7 +252,7 @@ try Console.WriteLine("Connection to database established successfully."); await BuildSchema(connection); - await AddStoredProcs(connection); + await AddStoredProcsAndFunctions(connection); await RunSeedAsync(connection); Console.WriteLine("Seeding complete."); } diff --git a/DataLayer/seed/functions/UDF_GetCountryIdByCode.sql b/DataLayer/seed/functions/UDF_GetCountryIdByCode.sql new file mode 100644 index 0000000..9d9896b --- /dev/null +++ b/DataLayer/seed/functions/UDF_GetCountryIdByCode.sql @@ -0,0 +1,19 @@ +USE Biergarten; +GO + +CREATE OR ALTER FUNCTION dbo.UDF_GetCountryIdByCode +( + @CountryCode NVARCHAR(2) +) +RETURNS UNIQUEIDENTIFIER +AS +BEGIN + DECLARE @CountryId UNIQUEIDENTIFIER; + + SELECT @CountryId = CountryID + FROM dbo.Country + WHERE ISO3616_1 = @CountryCode; + + RETURN @CountryId; +END; +GO diff --git a/DataLayer/seed/functions/UDF_GetStateProvinceIdByCode.sql b/DataLayer/seed/functions/UDF_GetStateProvinceIdByCode.sql new file mode 100644 index 0000000..cd9e64d --- /dev/null +++ b/DataLayer/seed/functions/UDF_GetStateProvinceIdByCode.sql @@ -0,0 +1,17 @@ +USE Biergarten; +GO + +CREATE OR ALTER FUNCTION dbo.UDF_GetStateProvinceIdByCode +( + @StateProvinceCode NVARCHAR(6) +) +RETURNS UNIQUEIDENTIFIER +AS +BEGIN + DECLARE @StateProvinceId UNIQUEIDENTIFIER; + SELECT @StateProvinceId = StateProvinceID + FROM dbo.StateProvince + WHERE ISO3616_2 = @StateProvinceCode; + RETURN @StateProvinceId; +END; +GO diff --git a/DataLayer/seed/procedures/USP_AddLocations.sql b/DataLayer/seed/procedures/USP_AddLocations.sql new file mode 100644 index 0000000..fe3bc3a --- /dev/null +++ b/DataLayer/seed/procedures/USP_AddLocations.sql @@ -0,0 +1,504 @@ +USE Biergarten; +GO + +CREATE OR ALTER PROCEDURE dbo.USP_AddLocations +AS +BEGIN + SET NOCOUNT ON; + SET XACT_ABORT ON; + + BEGIN TRANSACTION; + -- Countries (alpha-2) + WITH + Countries(CountryName, Alpha2) + AS + ( + SELECT 'Canada', 'CA' + UNION ALL + SELECT 'Mexico', 'MX' + UNION ALL + SELECT 'United States', 'US' + ) + INSERT INTO dbo.Country + (CountryName, ISO3616_1) + SELECT c.CountryName, c.Alpha2 + FROM Countries AS c + WHERE NOT EXISTS (SELECT 1 + FROM dbo.Country AS x + WHERE x.ISO3616_1 = c.Alpha2 + ); + + WITH + Regions(StateProvinceName, ISO2, CountryAlpha2) + AS + ( + -- United States (50 + DC + territories) + SELECT 'Alabama', 'US-AL', 'US' + UNION ALL + SELECT 'Alaska', 'US-AK', 'US' + UNION ALL + SELECT 'Arizona', 'US-AZ', 'US' + UNION ALL + SELECT 'Arkansas', 'US-AR', 'US' + UNION ALL + SELECT 'California', 'US-CA', 'US' + UNION ALL + SELECT 'Colorado', 'US-CO', 'US' + UNION ALL + SELECT 'Connecticut', 'US-CT', 'US' + UNION ALL + SELECT 'Delaware', 'US-DE', 'US' + UNION ALL + SELECT 'Florida', 'US-FL', 'US' + UNION ALL + SELECT 'Georgia', 'US-GA', 'US' + UNION ALL + SELECT 'Hawaii', 'US-HI', 'US' + UNION ALL + SELECT 'Idaho', 'US-ID', 'US' + UNION ALL + SELECT 'Illinois', 'US-IL', 'US' + UNION ALL + SELECT 'Indiana', 'US-IN', 'US' + UNION ALL + SELECT 'Iowa', 'US-IA', 'US' + UNION ALL + SELECT 'Kansas', 'US-KS', 'US' + UNION ALL + SELECT 'Kentucky', 'US-KY', 'US' + UNION ALL + SELECT 'Louisiana', 'US-LA', 'US' + UNION ALL + SELECT 'Maine', 'US-ME', 'US' + UNION ALL + SELECT 'Maryland', 'US-MD', 'US' + UNION ALL + SELECT 'Massachusetts', 'US-MA', 'US' + UNION ALL + SELECT 'Michigan', 'US-MI', 'US' + UNION ALL + SELECT 'Minnesota', 'US-MN', 'US' + UNION ALL + SELECT 'Mississippi', 'US-MS', 'US' + UNION ALL + SELECT 'Missouri', 'US-MO', 'US' + UNION ALL + SELECT 'Montana', 'US-MT', 'US' + UNION ALL + SELECT 'Nebraska', 'US-NE', 'US' + UNION ALL + SELECT 'Nevada', 'US-NV', 'US' + UNION ALL + SELECT 'New Hampshire', 'US-NH', 'US' + UNION ALL + SELECT 'New Jersey', 'US-NJ', 'US' + UNION ALL + SELECT 'New Mexico', 'US-NM', 'US' + UNION ALL + SELECT 'New York', 'US-NY', 'US' + UNION ALL + SELECT 'North Carolina', 'US-NC', 'US' + UNION ALL + SELECT 'North Dakota', 'US-ND', 'US' + UNION ALL + SELECT 'Ohio', 'US-OH', 'US' + UNION ALL + SELECT 'Oklahoma', 'US-OK', 'US' + UNION ALL + SELECT 'Oregon', 'US-OR', 'US' + UNION ALL + SELECT 'Pennsylvania', 'US-PA', 'US' + UNION ALL + SELECT 'Rhode Island', 'US-RI', 'US' + UNION ALL + SELECT 'South Carolina', 'US-SC', 'US' + UNION ALL + SELECT 'South Dakota', 'US-SD', 'US' + UNION ALL + SELECT 'Tennessee', 'US-TN', 'US' + UNION ALL + SELECT 'Texas', 'US-TX', 'US' + UNION ALL + SELECT 'Utah', 'US-UT', 'US' + UNION ALL + SELECT 'Vermont', 'US-VT', 'US' + UNION ALL + SELECT 'Virginia', 'US-VA', 'US' + UNION ALL + SELECT 'Washington', 'US-WA', 'US' + UNION ALL + SELECT 'West Virginia', 'US-WV', 'US' + UNION ALL + SELECT 'Wisconsin', 'US-WI', 'US' + UNION ALL + SELECT 'Wyoming', 'US-WY', 'US' + UNION ALL + SELECT 'District of Columbia', 'US-DC', 'US' + UNION ALL + SELECT 'Puerto Rico', 'US-PR', 'US' + UNION ALL + SELECT 'U.S. Virgin Islands', 'US-VI', 'US' + UNION ALL + SELECT 'Guam', 'US-GU', 'US' + UNION ALL + SELECT 'Northern Mariana Islands', 'US-MP', 'US' + UNION ALL + SELECT 'American Samoa', 'US-AS', 'US' + + -- Canada (10 provinces + 3 territories) + UNION ALL + SELECT 'Ontario', 'CA-ON', 'CA' + UNION ALL + SELECT N'Québec', 'CA-QC', 'CA' + UNION ALL + SELECT 'Nova Scotia', 'CA-NS', 'CA' + UNION ALL + SELECT 'New Brunswick', 'CA-NB', 'CA' + UNION ALL + SELECT 'Manitoba', 'CA-MB', 'CA' + UNION ALL + SELECT 'British Columbia', 'CA-BC', 'CA' + UNION ALL + SELECT 'Prince Edward Island', 'CA-PE', 'CA' + UNION ALL + SELECT 'Saskatchewan', 'CA-SK', 'CA' + UNION ALL + SELECT 'Alberta', 'CA-AB', 'CA' + UNION ALL + SELECT 'Newfoundland and Labrador', 'CA-NL', 'CA' + UNION ALL + SELECT 'Northwest Territories', 'CA-NT', 'CA' + UNION ALL + SELECT 'Yukon', 'CA-YT', 'CA' + UNION ALL + SELECT 'Nunavut', 'CA-NU', 'CA' + + -- Mexico (32 states incl. CDMX) + UNION ALL + SELECT 'Aguascalientes', 'MX-AGU', 'MX' + UNION ALL + SELECT 'Baja California', 'MX-BCN', 'MX' + UNION ALL + SELECT 'Baja California Sur', 'MX-BCS', 'MX' + UNION ALL + SELECT 'Campeche', 'MX-CAM', 'MX' + UNION ALL + SELECT 'Chiapas', 'MX-CHP', 'MX' + UNION ALL + SELECT 'Chihuahua', 'MX-CHH', 'MX' + UNION ALL + SELECT 'Coahuila de Zaragoza', 'MX-COA', 'MX' + UNION ALL + SELECT 'Colima', 'MX-COL', 'MX' + UNION ALL + SELECT 'Durango', 'MX-DUR', 'MX' + UNION ALL + SELECT 'Guanajuato', 'MX-GUA', 'MX' + UNION ALL + SELECT 'Guerrero', 'MX-GRO', 'MX' + UNION ALL + SELECT 'Hidalgo', 'MX-HID', 'MX' + UNION ALL + SELECT 'Jalisco', 'MX-JAL', 'MX' + UNION ALL + SELECT N'México State', 'MX-MEX', 'MX' + UNION ALL + SELECT N'Michoacán de Ocampo', 'MX-MIC', 'MX' + UNION ALL + SELECT 'Morelos', 'MX-MOR', 'MX' + UNION ALL + SELECT 'Nayarit', 'MX-NAY', 'MX' + UNION ALL + SELECT N'Nuevo León', 'MX-NLE', 'MX' + UNION ALL + SELECT 'Oaxaca', 'MX-OAX', 'MX' + UNION ALL + SELECT 'Puebla', 'MX-PUE', 'MX' + UNION ALL + SELECT N'Querétaro', 'MX-QUE', 'MX' + UNION ALL + SELECT 'Quintana Roo', 'MX-ROO', 'MX' + UNION ALL + SELECT N'San Luis Potosí', 'MX-SLP', 'MX' + UNION ALL + SELECT 'Sinaloa', 'MX-SIN', 'MX' + UNION ALL + SELECT 'Sonora', 'MX-SON', 'MX' + UNION ALL + SELECT 'Tabasco', 'MX-TAB', 'MX' + UNION ALL + SELECT 'Tamaulipas', 'MX-TAM', 'MX' + UNION ALL + SELECT 'Tlaxcala', 'MX-TLA', 'MX' + UNION ALL + SELECT 'Veracruz de Ignacio de la Llave', 'MX-VER', 'MX' + UNION ALL + SELECT N'Yucatán', 'MX-YUC', 'MX' + UNION ALL + SELECT 'Zacatecas', 'MX-ZAC', 'MX' + UNION ALL + SELECT N'Ciudad de México', 'MX-CMX', 'MX' + ) + INSERT INTO dbo.StateProvince + (StateProvinceName, ISO3616_2, CountryID) + SELECT + r.StateProvinceName, + r.ISO2, + dbo.UDF_GetCountryIdByCode(r.CountryAlpha2) + FROM Regions AS r + WHERE NOT EXISTS ( + SELECT 1 + FROM dbo.StateProvince AS sp + WHERE sp.ISO3616_2 = r.ISO2 + ); + + WITH + Cities(StateProvinceISO2, CityName) + AS + ( + -- USA + SELECT 'US-CA', 'Los Angeles' + UNION ALL + SELECT 'US-CA', 'San Diego' + UNION ALL + SELECT 'US-CA', 'San Francisco' + UNION ALL + SELECT 'US-CA', 'Sacramento' + UNION ALL + SELECT 'US-TX', 'Houston' + UNION ALL + SELECT 'US-TX', 'Dallas' + UNION ALL + SELECT 'US-TX', 'Austin' + UNION ALL + SELECT 'US-TX', 'San Antonio' + UNION ALL + SELECT 'US-FL', 'Miami' + UNION ALL + SELECT 'US-FL', 'Orlando' + UNION ALL + SELECT 'US-FL', 'Tampa' + UNION ALL + SELECT 'US-NY', 'New York' + UNION ALL + SELECT 'US-NY', 'Buffalo' + UNION ALL + SELECT 'US-NY', 'Rochester' + UNION ALL + SELECT 'US-IL', 'Chicago' + UNION ALL + SELECT 'US-IL', 'Springfield' + UNION ALL + SELECT 'US-PA', 'Philadelphia' + UNION ALL + SELECT 'US-PA', 'Pittsburgh' + UNION ALL + SELECT 'US-AZ', 'Phoenix' + UNION ALL + SELECT 'US-AZ', 'Tucson' + UNION ALL + SELECT 'US-CO', 'Denver' + UNION ALL + SELECT 'US-CO', 'Colorado Springs' + UNION ALL + SELECT 'US-MA', 'Boston' + UNION ALL + SELECT 'US-MA', 'Worcester' + UNION ALL + SELECT 'US-WA', 'Seattle' + UNION ALL + SELECT 'US-WA', 'Spokane' + UNION ALL + SELECT 'US-GA', 'Atlanta' + UNION ALL + SELECT 'US-GA', 'Savannah' + UNION ALL + SELECT 'US-NV', 'Las Vegas' + UNION ALL + SELECT 'US-NV', 'Reno' + UNION ALL + SELECT 'US-MI', 'Detroit' + UNION ALL + SELECT 'US-MI', 'Grand Rapids' + UNION ALL + SELECT 'US-MN', 'Minneapolis' + UNION ALL + SELECT 'US-MN', 'Saint Paul' + UNION ALL + SELECT 'US-OH', 'Columbus' + UNION ALL + SELECT 'US-OH', 'Cleveland' + UNION ALL + SELECT 'US-OR', 'Portland' + UNION ALL + SELECT 'US-OR', 'Salem' + UNION ALL + SELECT 'US-TN', 'Nashville' + UNION ALL + SELECT 'US-TN', 'Memphis' + UNION ALL + SELECT 'US-VA', 'Richmond' + UNION ALL + SELECT 'US-VA', 'Virginia Beach' + UNION ALL + SELECT 'US-MD', 'Baltimore' + UNION ALL + SELECT 'US-MD', 'Frederick' + UNION ALL + SELECT 'US-DC', 'Washington' + UNION ALL + SELECT 'US-UT', 'Salt Lake City' + UNION ALL + SELECT 'US-UT', 'Provo' + UNION ALL + SELECT 'US-LA', 'New Orleans' + UNION ALL + SELECT 'US-LA', 'Baton Rouge' + UNION ALL + SELECT 'US-KY', 'Louisville' + UNION ALL + SELECT 'US-KY', 'Lexington' + UNION ALL + SELECT 'US-IA', 'Des Moines' + UNION ALL + SELECT 'US-IA', 'Cedar Rapids' + UNION ALL + SELECT 'US-OK', 'Oklahoma City' + UNION ALL + SELECT 'US-OK', 'Tulsa' + UNION ALL + SELECT 'US-NE', 'Omaha' + UNION ALL + SELECT 'US-NE', 'Lincoln' + UNION ALL + SELECT 'US-MO', 'Kansas City' + UNION ALL + SELECT 'US-MO', 'St. Louis' + UNION ALL + SELECT 'US-NC', 'Charlotte' + UNION ALL + SELECT 'US-NC', 'Raleigh' + UNION ALL + SELECT 'US-SC', 'Columbia' + UNION ALL + SELECT 'US-SC', 'Charleston' + UNION ALL + SELECT 'US-WI', 'Milwaukee' + UNION ALL + SELECT 'US-WI', 'Madison' + UNION ALL + SELECT 'US-MN', 'Duluth' + UNION ALL + SELECT 'US-AK', 'Anchorage' + UNION ALL + SELECT 'US-HI', 'Honolulu' + -- Canada + UNION ALL + SELECT 'CA-ON', 'Toronto' + UNION ALL + SELECT 'CA-ON', 'Ottawa' + UNION ALL + SELECT 'CA-QC', N'Montréal' + UNION ALL + SELECT 'CA-QC', N'Québec City' + UNION ALL + SELECT 'CA-BC', 'Vancouver' + UNION ALL + SELECT 'CA-BC', 'Victoria' + UNION ALL + SELECT 'CA-AB', 'Calgary' + UNION ALL + SELECT 'CA-AB', 'Edmonton' + UNION ALL + SELECT 'CA-MB', 'Winnipeg' + UNION ALL + SELECT 'CA-NS', 'Halifax' + UNION ALL + SELECT 'CA-SK', 'Saskatoon' + UNION ALL + SELECT 'CA-SK', 'Regina' + UNION ALL + SELECT 'CA-NB', 'Moncton' + UNION ALL + SELECT 'CA-NB', 'Saint John' + UNION ALL + SELECT 'CA-PE', 'Charlottetown' + UNION ALL + SELECT 'CA-NL', N'St. John''s' + UNION ALL + SELECT 'CA-ON', 'Hamilton' + UNION ALL + SELECT 'CA-ON', 'London' + UNION ALL + SELECT 'CA-QC', 'Gatineau' + UNION ALL + SELECT 'CA-QC', 'Laval' + UNION ALL + SELECT 'CA-BC', 'Kelowna' + UNION ALL + SELECT 'CA-AB', 'Red Deer' + UNION ALL + SELECT 'CA-MB', 'Brandon' + -- MEXICO + UNION ALL + SELECT 'MX-CMX', N'Ciudad de México' + UNION ALL + SELECT 'MX-JAL', 'Guadalajara' + UNION ALL + SELECT 'MX-NLE', 'Monterrey' + UNION ALL + SELECT 'MX-PUE', 'Puebla' + UNION ALL + SELECT 'MX-ROO', N'Cancún' + UNION ALL + SELECT 'MX-GUA', 'Guanajuato' + UNION ALL + SELECT 'MX-MIC', 'Morelia' + UNION ALL + SELECT 'MX-BCN', 'Tijuana' + UNION ALL + SELECT 'MX-JAL', 'Zapopan' + UNION ALL + SELECT 'MX-NLE', N'San Nicolás' + UNION ALL + SELECT 'MX-CAM', 'Campeche' + UNION ALL + SELECT 'MX-TAB', 'Villahermosa' + UNION ALL + SELECT 'MX-VER', 'Veracruz' + UNION ALL + SELECT 'MX-OAX', 'Oaxaca' + UNION ALL + SELECT 'MX-SLP', N'San Luis Potosí' + UNION ALL + SELECT 'MX-CHH', 'Chihuahua' + UNION ALL + SELECT 'MX-AGU', 'Aguascalientes' + UNION ALL + SELECT 'MX-MEX', 'Toluca' + UNION ALL + SELECT 'MX-COA', 'Saltillo' + UNION ALL + SELECT 'MX-BCS', 'La Paz' + UNION ALL + SELECT 'MX-NAY', 'Tepic' + UNION ALL + SELECT 'MX-ZAC', 'Zacatecas' + ) + INSERT INTO dbo.City + (StateProvinceID, CityName) + SELECT + dbo.UDF_GetStateProvinceIdByCode(c.StateProvinceISO2), + c.CityName + FROM Cities AS c + WHERE NOT EXISTS ( + SELECT 1 + FROM dbo.City AS ci + WHERE ci.CityName = c.CityName + AND ci.StateProvinceID = dbo.UDF_GetStateProvinceIdByCode(c.StateProvinceISO2) + ); + + + COMMIT TRANSACTION; +END; +GO diff --git a/DataLayer/SeedStoredProcs.sql b/DataLayer/seed/procedures/USP_AddTestUsers.sql similarity index 75% rename from DataLayer/SeedStoredProcs.sql rename to DataLayer/seed/procedures/USP_AddTestUsers.sql index 795ff73..ba92ec0 100644 --- a/DataLayer/SeedStoredProcs.sql +++ b/DataLayer/seed/procedures/USP_AddTestUsers.sql @@ -1,5 +1,4 @@ - -USE biergarten; +USE Biergarten; GO CREATE OR ALTER PROCEDURE dbo.USP_AddTestUsers @@ -135,65 +134,3 @@ BEGIN 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 diff --git a/DataLayer/seed/procedures/USP_AddUserCredentials.sql b/DataLayer/seed/procedures/USP_AddUserCredentials.sql new file mode 100644 index 0000000..9f00164 --- /dev/null +++ b/DataLayer/seed/procedures/USP_AddUserCredentials.sql @@ -0,0 +1,33 @@ +USE Biergarten; +GO + +IF TYPE_ID(N'dbo.TblUserHashes') IS NULL + EXEC('CREATE TYPE dbo.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 diff --git a/DataLayer/seed/procedures/USP_CreateUserVerification.sql b/DataLayer/seed/procedures/USP_CreateUserVerification.sql new file mode 100644 index 0000000..7898e1d --- /dev/null +++ b/DataLayer/seed/procedures/USP_CreateUserVerification.sql @@ -0,0 +1,35 @@ +USE Biergarten; +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 diff --git a/WebAPI/Program.cs b/WebAPI/Program.cs index 7ffecff..6758956 100644 --- a/WebAPI/Program.cs +++ b/WebAPI/Program.cs @@ -16,22 +16,34 @@ app.UseHttpsRedirection(); var summaries = new[] { - "Freezing", "Bracing", "Chilly", "Cool", "Mild", "Warm", "Balmy", "Hot", "Sweltering", "Scorching" + "Freezing", + "Bracing", + "Chilly", + "Cool", + "Mild", + "Warm", + "Balmy", + "Hot", + "Sweltering", + "Scorching", }; -app.MapGet("/weatherforecast", () => -{ - var forecast = Enumerable.Range(1, 5).Select(index => - new WeatherForecast - ( - DateOnly.FromDateTime(DateTime.Now.AddDays(index)), - Random.Shared.Next(-20, 55), - summaries[Random.Shared.Next(summaries.Length)] - )) - .ToArray(); - return forecast; -}) -.WithName("GetWeatherForecast"); +app.MapGet( + "/weatherforecast", + () => + { + var forecast = Enumerable + .Range(1, 5) + .Select(index => new WeatherForecast( + DateOnly.FromDateTime(DateTime.Now.AddDays(index)), + Random.Shared.Next(-20, 55), + summaries[Random.Shared.Next(summaries.Length)] + )) + .ToArray(); + return forecast; + } + ) + .WithName("GetWeatherForecast"); app.UseStaticFiles(); app.Run(); diff --git a/WebAPI/WebAPI.csproj b/WebAPI/WebAPI.csproj index 7383e60..dad0e7c 100644 --- a/WebAPI/WebAPI.csproj +++ b/WebAPI/WebAPI.csproj @@ -1,5 +1,4 @@ - net9.0 enable @@ -9,5 +8,4 @@ - diff --git a/docker-compose.yml b/docker-compose.yml index a456e01..b48866d 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -24,7 +24,7 @@ services: tty: true stdin_open: true volumes: - - ./:/home/dev/projects # bind mount your repo for live code edits + - ./:/home/dev/projects - nuget-cache:/home/dev/.nuget/packages - ~/.gitconfig:/home/dev/.gitconfig:ro working_dir: /home/dev/projects @@ -32,7 +32,7 @@ services: DOTNET_CLI_TELEMETRY_OPTOUT: "1" HOME: /home/dev USER: dev - SEEDDB_CONNECTION_STRING: "Server=sqlserver,1433;User Id=sa;Password=YourStrong!Passw0rd;Encrypt=True;TrustServerCertificate=True;Connection Timeout=30;" + DB_CONNECTION_STRING: "Server=sqlserver,1433;User Id=sa;Password=YourStrong!Passw0rd;Encrypt=True;TrustServerCertificate=True;Connection Timeout=30;" user: root networks: - devnet