mirror of
https://github.com/aaronpo97/the-biergarten-app.git
synced 2026-02-16 20:13:49 +00:00
Repo restructuring
This commit is contained in:
17
src/Core/Database/Database.Core/Database.Core.csproj
Normal file
17
src/Core/Database/Database.Core/Database.Core.csproj
Normal file
@@ -0,0 +1,17 @@
|
||||
<Project Sdk="Microsoft.NET.Sdk">
|
||||
<PropertyGroup>
|
||||
<OutputType>Exe</OutputType>
|
||||
<TargetFramework>net10.0</TargetFramework>
|
||||
<ImplicitUsings>enable</ImplicitUsings>
|
||||
<Nullable>enable</Nullable>
|
||||
<RootNamespace>DataLayer</RootNamespace>
|
||||
</PropertyGroup>
|
||||
|
||||
<ItemGroup>
|
||||
<PackageReference Include="dbup" Version="5.0.41" />
|
||||
<PackageReference Include="Microsoft.Data.SqlClient" Version="6.1.2" />
|
||||
</ItemGroup>
|
||||
<ItemGroup>
|
||||
<EmbeddedResource Include="scripts/**/*.sql" />
|
||||
</ItemGroup>
|
||||
</Project>
|
||||
32
src/Core/Database/Database.Core/Program.cs
Normal file
32
src/Core/Database/Database.Core/Program.cs
Normal file
@@ -0,0 +1,32 @@
|
||||
// Get connection string from environment variable
|
||||
|
||||
using System.Reflection;
|
||||
using DbUp;
|
||||
|
||||
var connectionString = Environment.GetEnvironmentVariable(
|
||||
"DB_CONNECTION_STRING"
|
||||
);
|
||||
|
||||
var upgrader = DeployChanges
|
||||
.To.SqlDatabase(connectionString)
|
||||
.WithScriptsEmbeddedInAssembly(Assembly.GetExecutingAssembly())
|
||||
.LogToConsole()
|
||||
.Build();
|
||||
|
||||
var result = upgrader.PerformUpgrade();
|
||||
|
||||
if (!result.Successful)
|
||||
{
|
||||
Console.ForegroundColor = ConsoleColor.Red;
|
||||
Console.WriteLine(result.Error);
|
||||
Console.ResetColor();
|
||||
#if DEBUG
|
||||
Console.ReadLine();
|
||||
#endif
|
||||
return -1;
|
||||
}
|
||||
|
||||
Console.ForegroundColor = ConsoleColor.Green;
|
||||
Console.WriteLine("Success!");
|
||||
Console.ResetColor();
|
||||
return 0;
|
||||
554
src/Core/Database/Database.Core/scripts/01-schema/schema.sql
Normal file
554
src/Core/Database/Database.Core/scripts/01-schema/schema.sql
Normal file
@@ -0,0 +1,554 @@
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
USE master;
|
||||
|
||||
IF EXISTS (SELECT name
|
||||
FROM sys.databases
|
||||
WHERE name = N'Biergarten')
|
||||
BEGIN
|
||||
ALTER DATABASE Biergarten SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
|
||||
END
|
||||
|
||||
DROP DATABASE IF EXISTS Biergarten;
|
||||
|
||||
CREATE DATABASE Biergarten;
|
||||
|
||||
USE Biergarten;
|
||||
*/
|
||||
-- ----------------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE dbo.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
|
||||
|
||||
IsRevoked BIT NOT NULL
|
||||
CONSTRAINT DF_UserCredential_IsRevoked DEFAULT 0,
|
||||
|
||||
RevokedAt DATETIME NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_UserCredential
|
||||
PRIMARY KEY (UserCredentialID),
|
||||
|
||||
CONSTRAINT FK_UserCredential_UserAccount
|
||||
FOREIGN KEY (UserAccountID)
|
||||
REFERENCES UserAccount(UserAccountID)
|
||||
ON DELETE CASCADE,
|
||||
);
|
||||
|
||||
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,
|
||||
|
||||
ISO3616_1 CHAR(2) NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
CONSTRAINT PK_Country
|
||||
PRIMARY KEY (CountryID),
|
||||
|
||||
CONSTRAINT AK_Country_ISO3616_1
|
||||
UNIQUE (ISO3616_1)
|
||||
);
|
||||
|
||||
----------------------------------------------------------------------------
|
||||
----------------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE StateProvince
|
||||
(
|
||||
StateProvinceID UNIQUEIDENTIFIER
|
||||
CONSTRAINT DF_StateProvinceID DEFAULT NEWID(),
|
||||
|
||||
StateProvinceName NVARCHAR(100) NOT NULL,
|
||||
|
||||
ISO3616_2 CHAR(6) NOT NULL,
|
||||
-- eg 'US-CA' for California, 'CA-ON' for Ontario
|
||||
|
||||
CountryID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
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(),
|
||||
|
||||
CityName NVARCHAR(100) NOT NULL,
|
||||
|
||||
StateProvinceID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
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(),
|
||||
|
||||
PostedByID UNIQUEIDENTIFIER NOT NULL,
|
||||
|
||||
Description NVARCHAR(512) NOT NULL,
|
||||
|
||||
CreatedAt DATETIME NOT NULL
|
||||
CONSTRAINT DF_BreweryPost_CreatedAt DEFAULT GETDATE(),
|
||||
|
||||
UpdatedAt DATETIME NULL,
|
||||
|
||||
Timer ROWVERSION,
|
||||
|
||||
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 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(),
|
||||
|
||||
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)
|
||||
|
||||
@@ -0,0 +1,15 @@
|
||||
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;
|
||||
@@ -0,0 +1,13 @@
|
||||
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;
|
||||
@@ -0,0 +1,33 @@
|
||||
|
||||
CREATE OR ALTER PROCEDURE usp_CreateUserAccount
|
||||
(
|
||||
@UserAccountId UNIQUEIDENTIFIER OUTPUT,
|
||||
@Username VARCHAR(64),
|
||||
@FirstName NVARCHAR(128),
|
||||
@LastName NVARCHAR(128),
|
||||
@DateOfBirth DATETIME,
|
||||
@Email VARCHAR(128)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
INSERT INTO UserAccount
|
||||
(
|
||||
Username,
|
||||
FirstName,
|
||||
LastName,
|
||||
DateOfBirth,
|
||||
Email
|
||||
)
|
||||
VALUES
|
||||
(
|
||||
@Username,
|
||||
@FirstName,
|
||||
@LastName,
|
||||
@DateOfBirth,
|
||||
@Email
|
||||
);
|
||||
|
||||
SELECT @UserAccountId AS UserAccountId;
|
||||
END;
|
||||
@@ -0,0 +1,20 @@
|
||||
|
||||
CREATE OR ALTER PROCEDURE usp_DeleteUserAccount
|
||||
(
|
||||
@UserAccountId UNIQUEIDENTIFIER
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON
|
||||
|
||||
IF NOT EXISTS (SELECT 1 FROM UserAccount WHERE UserAccountId = @UserAccountId)
|
||||
BEGIN
|
||||
RAISERROR('UserAccount with the specified ID does not exist.', 16,
|
||||
1);
|
||||
ROLLBACK TRANSACTION
|
||||
RETURN
|
||||
END
|
||||
|
||||
DELETE FROM UserAccount
|
||||
WHERE UserAccountId = @UserAccountId;
|
||||
END;
|
||||
@@ -0,0 +1,16 @@
|
||||
CREATE OR ALTER PROCEDURE usp_GetAllUserAccounts
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
SELECT UserAccountID,
|
||||
Username,
|
||||
FirstName,
|
||||
LastName,
|
||||
Email,
|
||||
CreatedAt,
|
||||
UpdatedAt,
|
||||
DateOfBirth,
|
||||
Timer
|
||||
FROM dbo.UserAccount;
|
||||
END;
|
||||
@@ -0,0 +1,19 @@
|
||||
CREATE OR ALTER PROCEDURE usp_GetUserAccountByEmail(
|
||||
@Email VARCHAR(128)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
SELECT UserAccountID,
|
||||
Username,
|
||||
FirstName,
|
||||
LastName,
|
||||
Email,
|
||||
CreatedAt,
|
||||
UpdatedAt,
|
||||
DateOfBirth,
|
||||
Timer
|
||||
FROM dbo.UserAccount
|
||||
WHERE Email = @Email;
|
||||
END;
|
||||
@@ -0,0 +1,19 @@
|
||||
CREATE OR ALTER PROCEDURE USP_GetUserAccountById(
|
||||
@UserAccountId UNIQUEIDENTIFIER
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
SELECT UserAccountID,
|
||||
Username,
|
||||
FirstName,
|
||||
LastName,
|
||||
Email,
|
||||
CreatedAt,
|
||||
UpdatedAt,
|
||||
DateOfBirth,
|
||||
Timer
|
||||
FROM dbo.UserAccount
|
||||
WHERE UserAccountID = @UserAccountId;
|
||||
END
|
||||
@@ -0,0 +1,19 @@
|
||||
CREATE OR ALTER PROCEDURE usp_GetUserAccountByUsername(
|
||||
@Username VARCHAR(64)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
SELECT UserAccountID,
|
||||
Username,
|
||||
FirstName,
|
||||
LastName,
|
||||
Email,
|
||||
CreatedAt,
|
||||
UpdatedAt,
|
||||
DateOfBirth,
|
||||
Timer
|
||||
FROM dbo.UserAccount
|
||||
WHERE Username = @Username;
|
||||
END;
|
||||
@@ -0,0 +1,27 @@
|
||||
CREATE OR ALTER PROCEDURE usp_UpdateUserAccount(
|
||||
@Username VARCHAR(64),
|
||||
@FirstName NVARCHAR(128),
|
||||
@LastName NVARCHAR(128),
|
||||
@DateOfBirth DATETIME,
|
||||
@Email VARCHAR(128),
|
||||
@UserAccountId UNIQUEIDENTIFIER
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET
|
||||
NOCOUNT ON;
|
||||
|
||||
UPDATE UserAccount
|
||||
SET Username = @Username,
|
||||
FirstName = @FirstName,
|
||||
LastName = @LastName,
|
||||
DateOfBirth = @DateOfBirth,
|
||||
Email = @Email
|
||||
WHERE UserAccountId = @UserAccountId;
|
||||
|
||||
IF @@ROWCOUNT = 0
|
||||
BEGIN
|
||||
THROW
|
||||
50001, 'UserAccount with the specified ID does not exist.', 1;
|
||||
END
|
||||
END;
|
||||
@@ -0,0 +1,17 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_GetActiveUserCredentialByUserAccountId(
|
||||
@UserAccountId UNIQUEIDENTIFIER
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
SELECT
|
||||
UserCredentialId,
|
||||
UserAccountId,
|
||||
Hash,
|
||||
IsRevoked,
|
||||
CreatedAt,
|
||||
RevokedAt
|
||||
FROM dbo.UserCredential
|
||||
WHERE UserAccountId = @UserAccountId AND IsRevoked = 0;
|
||||
END;
|
||||
@@ -0,0 +1,24 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_InvalidateUserCredential(
|
||||
@UserAccountId_ UNIQUEIDENTIFIER
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
EXEC dbo.USP_GetUserAccountByID @UserAccountId = @UserAccountId_;
|
||||
IF @@ROWCOUNT = 0
|
||||
THROW 50001, 'User account not found', 1;
|
||||
|
||||
-- invalidate all other credentials by setting them to revoked
|
||||
UPDATE dbo.UserCredential
|
||||
SET IsRevoked = 1,
|
||||
RevokedAt = GETDATE()
|
||||
WHERE UserAccountId = @UserAccountId_
|
||||
AND IsRevoked != 1;
|
||||
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
END;
|
||||
@@ -0,0 +1,42 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_RegisterUser(
|
||||
@UserAccountId_ UNIQUEIDENTIFIER OUTPUT,
|
||||
@Username VARCHAR(64),
|
||||
@FirstName NVARCHAR(128),
|
||||
@LastName NVARCHAR(128),
|
||||
@DateOfBirth DATETIME,
|
||||
@Email VARCHAR(128),
|
||||
@Hash NVARCHAR(MAX)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
EXEC usp_CreateUserAccount
|
||||
@UserAccountId = @UserAccountId_ OUTPUT,
|
||||
@Username = @Username,
|
||||
@FirstName = @FirstName,
|
||||
@LastName = @LastName,
|
||||
@DateOfBirth = @DateOfBirth,
|
||||
@Email = @Email;
|
||||
|
||||
IF @UserAccountId_ IS NULL
|
||||
BEGIN
|
||||
THROW 50000, 'Failed to create user account.', 1;
|
||||
END
|
||||
|
||||
|
||||
EXEC dbo.usp_RotateUserCredential
|
||||
@UserAccountId = @UserAccountId_,
|
||||
@Hash = @Hash;
|
||||
|
||||
IF @@ROWCOUNT = 0
|
||||
BEGIN
|
||||
THROW 50002, 'Failed to create user credential.', 1;
|
||||
END
|
||||
COMMIT TRANSACTION;
|
||||
|
||||
|
||||
END
|
||||
@@ -0,0 +1,28 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_RotateUserCredential(
|
||||
@UserAccountId_ UNIQUEIDENTIFIER,
|
||||
@Hash NVARCHAR(MAX)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
EXEC USP_GetUserAccountByID @UserAccountId = @UserAccountId_
|
||||
|
||||
IF @@ROWCOUNT = 0
|
||||
THROW 50001, 'User account not found', 1;
|
||||
|
||||
|
||||
-- invalidate all other credentials -- set them to revoked
|
||||
UPDATE dbo.UserCredential
|
||||
SET IsRevoked = 1,
|
||||
RevokedAt = GETDATE()
|
||||
WHERE UserAccountId = @UserAccountId_;
|
||||
|
||||
INSERT INTO dbo.UserCredential
|
||||
(UserAccountId, Hash)
|
||||
VALUES (@UserAccountId_, @Hash);
|
||||
|
||||
|
||||
END;
|
||||
@@ -0,0 +1,22 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_CreateUserVerification @UserAccountID_ UNIQUEIDENTIFIER,
|
||||
@VerificationDateTime DATETIME = NULL
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
IF @VerificationDateTime IS NULL
|
||||
SET @VerificationDateTime = GETDATE();
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
EXEC USP_GetUserAccountByID @UserAccountId = @UserAccountID_;
|
||||
IF @@ROWCOUNT = 0
|
||||
THROW 50001, 'Could not find a user with that id', 1;
|
||||
|
||||
INSERT INTO dbo.UserVerification
|
||||
(UserAccountId, VerificationDateTime)
|
||||
VALUES (@UserAccountID_, @VerificationDateTime);
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
END
|
||||
@@ -0,0 +1,30 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_CreateCity(
|
||||
@CityName NVARCHAR(100),
|
||||
@StateProvinceCode NVARCHAR(6)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
BEGIN TRANSACTION
|
||||
DECLARE @StateProvinceId UNIQUEIDENTIFIER = dbo.UDF_GetStateProvinceIdByCode(@StateProvinceCode);
|
||||
IF @StateProvinceId IS NULL
|
||||
BEGIN
|
||||
THROW 50001, 'State/province does not exist', 1;
|
||||
END
|
||||
|
||||
IF EXISTS (SELECT 1
|
||||
FROM dbo.City
|
||||
WHERE CityName = @CityName
|
||||
AND StateProvinceID = @StateProvinceId)
|
||||
BEGIN
|
||||
|
||||
THROW 50002, 'City already exists.', 1;
|
||||
END
|
||||
|
||||
INSERT INTO dbo.City
|
||||
(StateProvinceID, CityName)
|
||||
VALUES (@StateProvinceId, @CityName);
|
||||
COMMIT TRANSACTION
|
||||
END;
|
||||
@@ -0,0 +1,20 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_CreateCountry(
|
||||
@CountryName NVARCHAR(100),
|
||||
@ISO3616_1 NVARCHAR(2)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
IF EXISTS (SELECT 1
|
||||
FROM dbo.Country
|
||||
WHERE ISO3616_1 = @ISO3616_1)
|
||||
THROW 50001, 'Country already exists', 1;
|
||||
|
||||
INSERT INTO dbo.Country
|
||||
(CountryName, ISO3616_1)
|
||||
VALUES (@CountryName, @ISO3616_1);
|
||||
COMMIT TRANSACTION;
|
||||
END;
|
||||
@@ -0,0 +1,26 @@
|
||||
CREATE OR ALTER PROCEDURE dbo.USP_CreateStateProvince(
|
||||
@StateProvinceName NVARCHAR(100),
|
||||
@ISO3616_2 NVARCHAR(6),
|
||||
@CountryCode NVARCHAR(2)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
SET XACT_ABORT ON;
|
||||
|
||||
IF EXISTS (SELECT 1
|
||||
FROM dbo.StateProvince
|
||||
WHERE ISO3616_2 = @ISO3616_2)
|
||||
RETURN;
|
||||
|
||||
DECLARE @CountryId UNIQUEIDENTIFIER = dbo.UDF_GetCountryIdByCode(@CountryCode);
|
||||
IF @CountryId IS NULL
|
||||
BEGIN
|
||||
THROW 50001, 'Country does not exist', 1;
|
||||
|
||||
END
|
||||
|
||||
INSERT INTO dbo.StateProvince
|
||||
(StateProvinceName, ISO3616_2, CountryID)
|
||||
VALUES (@StateProvinceName, @ISO3616_2, @CountryId);
|
||||
END;
|
||||
22
src/Core/Database/Database.Seed/Database.Seed.csproj
Normal file
22
src/Core/Database/Database.Seed/Database.Seed.csproj
Normal file
@@ -0,0 +1,22 @@
|
||||
<Project Sdk="Microsoft.NET.Sdk">
|
||||
<PropertyGroup>
|
||||
<OutputType>Exe</OutputType>
|
||||
<TargetFramework>net10.0</TargetFramework>
|
||||
<ImplicitUsings>enable</ImplicitUsings>
|
||||
<Nullable>enable</Nullable>
|
||||
<RootNamespace>DBSeed</RootNamespace>
|
||||
</PropertyGroup>
|
||||
|
||||
<ItemGroup>
|
||||
<PackageReference Include="idunno.Password.Generator" Version="1.0.1" />
|
||||
<PackageReference
|
||||
Include="Konscious.Security.Cryptography.Argon2"
|
||||
Version="1.3.1"
|
||||
/>
|
||||
<PackageReference Include="Microsoft.Data.SqlClient" Version="6.1.3" />
|
||||
</ItemGroup>
|
||||
|
||||
<ItemGroup>
|
||||
<ProjectReference Include="..\..\Repository\Repository.Core\Repository.Core.csproj" />
|
||||
</ItemGroup>
|
||||
</Project>
|
||||
9
src/Core/Database/Database.Seed/ISeeder.cs
Normal file
9
src/Core/Database/Database.Seed/ISeeder.cs
Normal file
@@ -0,0 +1,9 @@
|
||||
using Microsoft.Data.SqlClient;
|
||||
|
||||
namespace DBSeed
|
||||
{
|
||||
internal interface ISeeder
|
||||
{
|
||||
Task SeedAsync(SqlConnection connection);
|
||||
}
|
||||
}
|
||||
328
src/Core/Database/Database.Seed/LocationSeeder.cs
Normal file
328
src/Core/Database/Database.Seed/LocationSeeder.cs
Normal file
@@ -0,0 +1,328 @@
|
||||
using System.Data;
|
||||
using Microsoft.Data.SqlClient;
|
||||
|
||||
namespace DBSeed
|
||||
{
|
||||
|
||||
internal class LocationSeeder : ISeeder
|
||||
{
|
||||
private static readonly IReadOnlyList<(
|
||||
string CountryName,
|
||||
string CountryCode
|
||||
)> Countries =
|
||||
[
|
||||
("Canada", "CA"),
|
||||
("Mexico", "MX"),
|
||||
("United States", "US"),
|
||||
];
|
||||
|
||||
private static IReadOnlyList<(string StateProvinceName, string StateProvinceCode, string CountryCode)> States
|
||||
{
|
||||
get;
|
||||
} =
|
||||
[
|
||||
("Alabama", "US-AL", "US"),
|
||||
("Alaska", "US-AK", "US"),
|
||||
("Arizona", "US-AZ", "US"),
|
||||
("Arkansas", "US-AR", "US"),
|
||||
("California", "US-CA", "US"),
|
||||
("Colorado", "US-CO", "US"),
|
||||
("Connecticut", "US-CT", "US"),
|
||||
("Delaware", "US-DE", "US"),
|
||||
("Florida", "US-FL", "US"),
|
||||
("Georgia", "US-GA", "US"),
|
||||
("Hawaii", "US-HI", "US"),
|
||||
("Idaho", "US-ID", "US"),
|
||||
("Illinois", "US-IL", "US"),
|
||||
("Indiana", "US-IN", "US"),
|
||||
("Iowa", "US-IA", "US"),
|
||||
("Kansas", "US-KS", "US"),
|
||||
("Kentucky", "US-KY", "US"),
|
||||
("Louisiana", "US-LA", "US"),
|
||||
("Maine", "US-ME", "US"),
|
||||
("Maryland", "US-MD", "US"),
|
||||
("Massachusetts", "US-MA", "US"),
|
||||
("Michigan", "US-MI", "US"),
|
||||
("Minnesota", "US-MN", "US"),
|
||||
("Mississippi", "US-MS", "US"),
|
||||
("Missouri", "US-MO", "US"),
|
||||
("Montana", "US-MT", "US"),
|
||||
("Nebraska", "US-NE", "US"),
|
||||
("Nevada", "US-NV", "US"),
|
||||
("New Hampshire", "US-NH", "US"),
|
||||
("New Jersey", "US-NJ", "US"),
|
||||
("New Mexico", "US-NM", "US"),
|
||||
("New York", "US-NY", "US"),
|
||||
("North Carolina", "US-NC", "US"),
|
||||
("North Dakota", "US-ND", "US"),
|
||||
("Ohio", "US-OH", "US"),
|
||||
("Oklahoma", "US-OK", "US"),
|
||||
("Oregon", "US-OR", "US"),
|
||||
("Pennsylvania", "US-PA", "US"),
|
||||
("Rhode Island", "US-RI", "US"),
|
||||
("South Carolina", "US-SC", "US"),
|
||||
("South Dakota", "US-SD", "US"),
|
||||
("Tennessee", "US-TN", "US"),
|
||||
("Texas", "US-TX", "US"),
|
||||
("Utah", "US-UT", "US"),
|
||||
("Vermont", "US-VT", "US"),
|
||||
("Virginia", "US-VA", "US"),
|
||||
("Washington", "US-WA", "US"),
|
||||
("West Virginia", "US-WV", "US"),
|
||||
("Wisconsin", "US-WI", "US"),
|
||||
("Wyoming", "US-WY", "US"),
|
||||
("District of Columbia", "US-DC", "US"),
|
||||
("Puerto Rico", "US-PR", "US"),
|
||||
("U.S. Virgin Islands", "US-VI", "US"),
|
||||
("Guam", "US-GU", "US"),
|
||||
("Northern Mariana Islands", "US-MP", "US"),
|
||||
("American Samoa", "US-AS", "US"),
|
||||
("Ontario", "CA-ON", "CA"),
|
||||
("Québec", "CA-QC", "CA"),
|
||||
("Nova Scotia", "CA-NS", "CA"),
|
||||
("New Brunswick", "CA-NB", "CA"),
|
||||
("Manitoba", "CA-MB", "CA"),
|
||||
("British Columbia", "CA-BC", "CA"),
|
||||
("Prince Edward Island", "CA-PE", "CA"),
|
||||
("Saskatchewan", "CA-SK", "CA"),
|
||||
("Alberta", "CA-AB", "CA"),
|
||||
("Newfoundland and Labrador", "CA-NL", "CA"),
|
||||
("Northwest Territories", "CA-NT", "CA"),
|
||||
("Yukon", "CA-YT", "CA"),
|
||||
("Nunavut", "CA-NU", "CA"),
|
||||
("Aguascalientes", "MX-AGU", "MX"),
|
||||
("Baja California", "MX-BCN", "MX"),
|
||||
("Baja California Sur", "MX-BCS", "MX"),
|
||||
("Campeche", "MX-CAM", "MX"),
|
||||
("Chiapas", "MX-CHP", "MX"),
|
||||
("Chihuahua", "MX-CHH", "MX"),
|
||||
("Coahuila de Zaragoza", "MX-COA", "MX"),
|
||||
("Colima", "MX-COL", "MX"),
|
||||
("Durango", "MX-DUR", "MX"),
|
||||
("Guanajuato", "MX-GUA", "MX"),
|
||||
("Guerrero", "MX-GRO", "MX"),
|
||||
("Hidalgo", "MX-HID", "MX"),
|
||||
("Jalisco", "MX-JAL", "MX"),
|
||||
("México State", "MX-MEX", "MX"),
|
||||
("Michoacán de Ocampo", "MX-MIC", "MX"),
|
||||
("Morelos", "MX-MOR", "MX"),
|
||||
("Nayarit", "MX-NAY", "MX"),
|
||||
("Nuevo León", "MX-NLE", "MX"),
|
||||
("Oaxaca", "MX-OAX", "MX"),
|
||||
("Puebla", "MX-PUE", "MX"),
|
||||
("Querétaro", "MX-QUE", "MX"),
|
||||
("Quintana Roo", "MX-ROO", "MX"),
|
||||
("San Luis Potosí", "MX-SLP", "MX"),
|
||||
("Sinaloa", "MX-SIN", "MX"),
|
||||
("Sonora", "MX-SON", "MX"),
|
||||
("Tabasco", "MX-TAB", "MX"),
|
||||
("Tamaulipas", "MX-TAM", "MX"),
|
||||
("Tlaxcala", "MX-TLA", "MX"),
|
||||
("Veracruz de Ignacio de la Llave", "MX-VER", "MX"),
|
||||
("Yucatán", "MX-YUC", "MX"),
|
||||
("Zacatecas", "MX-ZAC", "MX"),
|
||||
("Ciudad de México", "MX-CMX", "MX"),
|
||||
];
|
||||
|
||||
private static IReadOnlyList<(string StateProvinceCode, string CityName)> Cities { get; } =
|
||||
[
|
||||
("US-CA", "Los Angeles"),
|
||||
("US-CA", "San Diego"),
|
||||
("US-CA", "San Francisco"),
|
||||
("US-CA", "Sacramento"),
|
||||
("US-TX", "Houston"),
|
||||
("US-TX", "Dallas"),
|
||||
("US-TX", "Austin"),
|
||||
("US-TX", "San Antonio"),
|
||||
("US-FL", "Miami"),
|
||||
("US-FL", "Orlando"),
|
||||
("US-FL", "Tampa"),
|
||||
("US-NY", "New York"),
|
||||
("US-NY", "Buffalo"),
|
||||
("US-NY", "Rochester"),
|
||||
("US-IL", "Chicago"),
|
||||
("US-IL", "Springfield"),
|
||||
("US-PA", "Philadelphia"),
|
||||
("US-PA", "Pittsburgh"),
|
||||
("US-AZ", "Phoenix"),
|
||||
("US-AZ", "Tucson"),
|
||||
("US-CO", "Denver"),
|
||||
("US-CO", "Colorado Springs"),
|
||||
("US-MA", "Boston"),
|
||||
("US-MA", "Worcester"),
|
||||
("US-WA", "Seattle"),
|
||||
("US-WA", "Spokane"),
|
||||
("US-GA", "Atlanta"),
|
||||
("US-GA", "Savannah"),
|
||||
("US-NV", "Las Vegas"),
|
||||
("US-NV", "Reno"),
|
||||
("US-MI", "Detroit"),
|
||||
("US-MI", "Grand Rapids"),
|
||||
("US-MN", "Minneapolis"),
|
||||
("US-MN", "Saint Paul"),
|
||||
("US-OH", "Columbus"),
|
||||
("US-OH", "Cleveland"),
|
||||
("US-OR", "Portland"),
|
||||
("US-OR", "Salem"),
|
||||
("US-TN", "Nashville"),
|
||||
("US-TN", "Memphis"),
|
||||
("US-VA", "Richmond"),
|
||||
("US-VA", "Virginia Beach"),
|
||||
("US-MD", "Baltimore"),
|
||||
("US-MD", "Frederick"),
|
||||
("US-DC", "Washington"),
|
||||
("US-UT", "Salt Lake City"),
|
||||
("US-UT", "Provo"),
|
||||
("US-LA", "New Orleans"),
|
||||
("US-LA", "Baton Rouge"),
|
||||
("US-KY", "Louisville"),
|
||||
("US-KY", "Lexington"),
|
||||
("US-IA", "Des Moines"),
|
||||
("US-IA", "Cedar Rapids"),
|
||||
("US-OK", "Oklahoma City"),
|
||||
("US-OK", "Tulsa"),
|
||||
("US-NE", "Omaha"),
|
||||
("US-NE", "Lincoln"),
|
||||
("US-MO", "Kansas City"),
|
||||
("US-MO", "St. Louis"),
|
||||
("US-NC", "Charlotte"),
|
||||
("US-NC", "Raleigh"),
|
||||
("US-SC", "Columbia"),
|
||||
("US-SC", "Charleston"),
|
||||
("US-WI", "Milwaukee"),
|
||||
("US-WI", "Madison"),
|
||||
("US-MN", "Duluth"),
|
||||
("US-AK", "Anchorage"),
|
||||
("US-HI", "Honolulu"),
|
||||
("CA-ON", "Toronto"),
|
||||
("CA-ON", "Ottawa"),
|
||||
("CA-QC", "Montréal"),
|
||||
("CA-QC", "Québec City"),
|
||||
("CA-BC", "Vancouver"),
|
||||
("CA-BC", "Victoria"),
|
||||
("CA-AB", "Calgary"),
|
||||
("CA-AB", "Edmonton"),
|
||||
("CA-MB", "Winnipeg"),
|
||||
("CA-NS", "Halifax"),
|
||||
("CA-SK", "Saskatoon"),
|
||||
("CA-SK", "Regina"),
|
||||
("CA-NB", "Moncton"),
|
||||
("CA-NB", "Saint John"),
|
||||
("CA-PE", "Charlottetown"),
|
||||
("CA-NL", "St. John's"),
|
||||
("CA-ON", "Hamilton"),
|
||||
("CA-ON", "London"),
|
||||
("CA-QC", "Gatineau"),
|
||||
("CA-QC", "Laval"),
|
||||
("CA-BC", "Kelowna"),
|
||||
("CA-AB", "Red Deer"),
|
||||
("CA-MB", "Brandon"),
|
||||
("MX-CMX", "Ciudad de México"),
|
||||
("MX-JAL", "Guadalajara"),
|
||||
("MX-NLE", "Monterrey"),
|
||||
("MX-PUE", "Puebla"),
|
||||
("MX-ROO", "Cancún"),
|
||||
("MX-GUA", "Guanajuato"),
|
||||
("MX-MIC", "Morelia"),
|
||||
("MX-BCN", "Tijuana"),
|
||||
("MX-JAL", "Zapopan"),
|
||||
("MX-NLE", "San Nicolás"),
|
||||
("MX-CAM", "Campeche"),
|
||||
("MX-TAB", "Villahermosa"),
|
||||
("MX-VER", "Veracruz"),
|
||||
("MX-OAX", "Oaxaca"),
|
||||
("MX-SLP", "San Luis Potosí"),
|
||||
("MX-CHH", "Chihuahua"),
|
||||
("MX-AGU", "Aguascalientes"),
|
||||
("MX-MEX", "Toluca"),
|
||||
("MX-COA", "Saltillo"),
|
||||
("MX-BCS", "La Paz"),
|
||||
("MX-NAY", "Tepic"),
|
||||
("MX-ZAC", "Zacatecas"),
|
||||
];
|
||||
|
||||
public async Task SeedAsync(SqlConnection connection)
|
||||
{
|
||||
foreach (var (countryName, countryCode) in Countries)
|
||||
{
|
||||
await CreateCountryAsync(connection, countryName, countryCode);
|
||||
}
|
||||
|
||||
foreach (
|
||||
var (stateProvinceName, stateProvinceCode, countryCode) in States
|
||||
)
|
||||
{
|
||||
await CreateStateProvinceAsync(
|
||||
connection,
|
||||
stateProvinceName,
|
||||
stateProvinceCode,
|
||||
countryCode
|
||||
);
|
||||
}
|
||||
|
||||
foreach (var (stateProvinceCode, cityName) in Cities)
|
||||
{
|
||||
await CreateCityAsync(connection, cityName, stateProvinceCode);
|
||||
}
|
||||
}
|
||||
|
||||
private static async Task CreateCountryAsync(
|
||||
SqlConnection connection,
|
||||
string countryName,
|
||||
string countryCode
|
||||
)
|
||||
{
|
||||
await using var command = new SqlCommand(
|
||||
"dbo.USP_CreateCountry",
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
command.Parameters.AddWithValue("@CountryName", countryName);
|
||||
command.Parameters.AddWithValue("@ISO3616_1", countryCode);
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
private static async Task CreateStateProvinceAsync(
|
||||
SqlConnection connection,
|
||||
string stateProvinceName,
|
||||
string stateProvinceCode,
|
||||
string countryCode
|
||||
)
|
||||
{
|
||||
await using var command = new SqlCommand(
|
||||
"dbo.USP_CreateStateProvince",
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
command.Parameters.AddWithValue(
|
||||
"@StateProvinceName",
|
||||
stateProvinceName
|
||||
);
|
||||
command.Parameters.AddWithValue("@ISO3616_2", stateProvinceCode);
|
||||
command.Parameters.AddWithValue("@CountryCode", countryCode);
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
private static async Task CreateCityAsync(
|
||||
SqlConnection connection,
|
||||
string cityName,
|
||||
string stateProvinceCode
|
||||
)
|
||||
{
|
||||
await using var command = new SqlCommand(
|
||||
"dbo.USP_CreateCity",
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
command.Parameters.AddWithValue("@CityName", cityName);
|
||||
command.Parameters.AddWithValue(
|
||||
"@StateProvinceCode",
|
||||
stateProvinceCode
|
||||
);
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
}
|
||||
}
|
||||
40
src/Core/Database/Database.Seed/Program.cs
Normal file
40
src/Core/Database/Database.Seed/Program.cs
Normal file
@@ -0,0 +1,40 @@
|
||||
using DBSeed;
|
||||
using Microsoft.Data.SqlClient;
|
||||
|
||||
try
|
||||
{
|
||||
var connectionString = Environment.GetEnvironmentVariable(
|
||||
"DB_CONNECTION_STRING"
|
||||
);
|
||||
if (string.IsNullOrWhiteSpace(connectionString))
|
||||
throw new InvalidOperationException(
|
||||
"Environment variable DB_CONNECTION_STRING is not set or is empty."
|
||||
);
|
||||
|
||||
await using var connection = new SqlConnection(connectionString);
|
||||
await connection.OpenAsync();
|
||||
|
||||
Console.WriteLine("Connected to database.");
|
||||
|
||||
ISeeder[] seeders =
|
||||
[
|
||||
new LocationSeeder(),
|
||||
new UserSeeder(),
|
||||
];
|
||||
|
||||
foreach (var seeder in seeders)
|
||||
{
|
||||
Console.WriteLine($"Seeding {seeder.GetType().Name}...");
|
||||
await seeder.SeedAsync(connection);
|
||||
Console.WriteLine($"{seeder.GetType().Name} seeded.");
|
||||
}
|
||||
|
||||
Console.WriteLine("Seed completed successfully.");
|
||||
return 0;
|
||||
}
|
||||
catch (Exception ex)
|
||||
{
|
||||
Console.Error.WriteLine("Seed failed:");
|
||||
Console.Error.WriteLine(ex);
|
||||
return 1;
|
||||
}
|
||||
274
src/Core/Database/Database.Seed/UserSeeder.cs
Normal file
274
src/Core/Database/Database.Seed/UserSeeder.cs
Normal file
@@ -0,0 +1,274 @@
|
||||
using System.Data;
|
||||
using System.Security.Cryptography;
|
||||
using System.Text;
|
||||
using DataAccessLayer.Entities;
|
||||
using DataAccessLayer.Repositories;
|
||||
using idunno.Password;
|
||||
using Konscious.Security.Cryptography;
|
||||
using Microsoft.Data.SqlClient;
|
||||
|
||||
namespace DBSeed
|
||||
{
|
||||
|
||||
internal class UserSeeder : ISeeder
|
||||
{
|
||||
|
||||
|
||||
private static readonly IReadOnlyList<(
|
||||
string FirstName,
|
||||
string LastName
|
||||
)> SeedNames =
|
||||
[
|
||||
("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"),
|
||||
];
|
||||
|
||||
public async Task SeedAsync(SqlConnection connection)
|
||||
{
|
||||
var generator = new PasswordGenerator();
|
||||
var rng = new Random();
|
||||
int createdUsers = 0;
|
||||
int createdCredentials = 0;
|
||||
int createdVerifications = 0;
|
||||
|
||||
foreach (var (firstName, lastName) in SeedNames)
|
||||
{
|
||||
// create the user in the database
|
||||
var userAccountId = Guid.NewGuid();
|
||||
await AddUserAccountAsync(connection, new UserAccount
|
||||
{
|
||||
UserAccountId = userAccountId,
|
||||
FirstName = firstName,
|
||||
LastName = lastName,
|
||||
Email = $"{firstName}.{lastName}@thebiergarten.app",
|
||||
Username = $"{firstName[0]}.{lastName}",
|
||||
DateOfBirth = GenerateDateOfBirth(rng)
|
||||
});
|
||||
createdUsers++;
|
||||
|
||||
// add user credentials
|
||||
if (!await HasUserCredentialAsync(connection, userAccountId))
|
||||
{
|
||||
string pwd = generator.Generate(
|
||||
length: 64,
|
||||
numberOfDigits: 10,
|
||||
numberOfSymbols: 10
|
||||
);
|
||||
string hash = GeneratePasswordHash(pwd);
|
||||
await AddUserCredentialAsync(connection, userAccountId, hash);
|
||||
createdCredentials++;
|
||||
}
|
||||
|
||||
// add user verification
|
||||
if (await HasUserVerificationAsync(connection, userAccountId)) continue;
|
||||
await AddUserVerificationAsync(connection, userAccountId);
|
||||
createdVerifications++;
|
||||
}
|
||||
|
||||
Console.WriteLine($"Created {createdUsers} user accounts.");
|
||||
Console.WriteLine($"Added {createdCredentials} user credentials.");
|
||||
Console.WriteLine($"Added {createdVerifications} user verifications.");
|
||||
}
|
||||
|
||||
private static async Task AddUserAccountAsync(SqlConnection connection, UserAccount ua)
|
||||
{
|
||||
await using var command = new SqlCommand("usp_CreateUserAccount", connection);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
|
||||
command.Parameters.Add("@UserAccountId", SqlDbType.UniqueIdentifier).Value = ua.UserAccountId;
|
||||
command.Parameters.Add("@Username", SqlDbType.NVarChar, 100).Value = ua.Username;
|
||||
command.Parameters.Add("@FirstName", SqlDbType.NVarChar, 100).Value = ua.FirstName;
|
||||
command.Parameters.Add("@LastName", SqlDbType.NVarChar, 100).Value = ua.LastName;
|
||||
command.Parameters.Add("@Email", SqlDbType.NVarChar, 256).Value = ua.Email;
|
||||
command.Parameters.Add("@DateOfBirth", SqlDbType.Date).Value = ua.DateOfBirth;
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
private static string GeneratePasswordHash(string pwd)
|
||||
{
|
||||
byte[] salt = RandomNumberGenerator.GetBytes(16);
|
||||
|
||||
var argon2 = new Argon2id(Encoding.UTF8.GetBytes(pwd))
|
||||
{
|
||||
Salt = salt,
|
||||
DegreeOfParallelism = Math.Max(Environment.ProcessorCount, 1),
|
||||
MemorySize = 65536,
|
||||
Iterations = 4,
|
||||
};
|
||||
|
||||
byte[] hash = argon2.GetBytes(32);
|
||||
return $"{Convert.ToBase64String(salt)}:{Convert.ToBase64String(hash)}";
|
||||
}
|
||||
|
||||
private static async Task<bool> HasUserCredentialAsync(
|
||||
SqlConnection connection,
|
||||
Guid userAccountId
|
||||
)
|
||||
{
|
||||
const string sql = $"""
|
||||
SELECT 1
|
||||
FROM dbo.UserCredential
|
||||
WHERE UserAccountId = @UserAccountId;
|
||||
""";
|
||||
await using var command = new SqlCommand(sql, connection);
|
||||
command.Parameters.AddWithValue("@UserAccountId", userAccountId);
|
||||
object? result = await command.ExecuteScalarAsync();
|
||||
return result is not null;
|
||||
}
|
||||
|
||||
private static async Task AddUserCredentialAsync(
|
||||
SqlConnection connection,
|
||||
Guid userAccountId,
|
||||
string hash
|
||||
)
|
||||
{
|
||||
await using var command = new SqlCommand(
|
||||
"dbo.USP_AddUserCredential",
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
command.Parameters.AddWithValue("@UserAccountId", userAccountId);
|
||||
command.Parameters.AddWithValue("@Hash", hash);
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
private static async Task<bool> HasUserVerificationAsync(
|
||||
SqlConnection connection,
|
||||
Guid userAccountId
|
||||
)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT 1
|
||||
FROM dbo.UserVerification
|
||||
WHERE UserAccountId = @UserAccountId;
|
||||
""";
|
||||
await using var command = new SqlCommand(sql, connection);
|
||||
command.Parameters.AddWithValue("@UserAccountId", userAccountId);
|
||||
var result = await command.ExecuteScalarAsync();
|
||||
return result is not null;
|
||||
}
|
||||
|
||||
private static async Task AddUserVerificationAsync(
|
||||
SqlConnection connection,
|
||||
Guid userAccountId
|
||||
)
|
||||
{
|
||||
await using var command = new SqlCommand(
|
||||
"dbo.USP_CreateUserVerification",
|
||||
connection
|
||||
);
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
command.Parameters.AddWithValue("@UserAccountID", userAccountId);
|
||||
|
||||
await command.ExecuteNonQueryAsync();
|
||||
}
|
||||
|
||||
private static DateTime GenerateDateOfBirth(Random random)
|
||||
{
|
||||
int age = 19 + random.Next(0, 30);
|
||||
DateTime baseDate = DateTime.UtcNow.Date.AddYears(-age);
|
||||
int offsetDays = random.Next(0, 365);
|
||||
return baseDate.AddDays(-offsetDays);
|
||||
}
|
||||
}
|
||||
}
|
||||
Reference in New Issue
Block a user