diff --git a/SQL_Server_Database_Creation_Steps.txt b/SQL_Server_Database_Creation_Steps.txt new file mode 100644 index 0000000..a2dbc8d --- /dev/null +++ b/SQL_Server_Database_Creation_Steps.txt @@ -0,0 +1,290 @@ +================================================================================ + SQL SERVER DATABASE CREATION - STEP BY STEP GUIDE + Project Management System Database +================================================================================ + +📋 OVERVIEW: +- Database Name: ProjectManagementDB +- Total Steps: 8 main steps +- Estimated Time: 15-20 minutes +- Prerequisites: SQL Server Management Studio (SSMS) + +================================================================================ +🗄️ STEP 1: CREATE DATABASE +================================================================================ + +-- STEP 1: Create Database +USE master; +GO + +-- Drop database if exists (optional - for clean start) +IF EXISTS (SELECT name FROM sys.databases WHERE name = N'ProjectManagementDB') +BEGIN + ALTER DATABASE ProjectManagementDB SET SINGLE_USER WITH ROLLBACK IMMEDIATE; + DROP DATABASE ProjectManagementDB; +END +GO + +-- Create new database +CREATE DATABASE ProjectManagementDB +ON +( NAME = 'ProjectManagementDB_Data', + FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\ProjectManagementDB.mdf', + SIZE = 100MB, + MAXSIZE = 1GB, + FILEGROWTH = 10MB ) +LOG ON +( NAME = 'ProjectManagementDB_Log', + FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\DATA\ProjectManagementDB.ldf', + SIZE = 10MB, + MAXSIZE = 100MB, + FILEGROWTH = 1MB ); +GO + +-- Switch to new database +USE ProjectManagementDB; +GO + +PRINT 'STEP 1 COMPLETED: Database created successfully!'; + +================================================================================ +🗄️ STEP 2A: CREATE PROJECTCATEGORIES TABLE +================================================================================ + +-- STEP 2A: Create ProjectCategories Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectCategories] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [Name] NVARCHAR(100) NOT NULL, + [Slug] NVARCHAR(100) NOT NULL, + [Color] NVARCHAR(20) NOT NULL, + [Icon] NVARCHAR(50) NULL, + [Description] NVARCHAR(MAX) NULL, + [IsActive] BIT NOT NULL DEFAULT 1, + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [UpdatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + + CONSTRAINT UQ_ProjectCategories_Name UNIQUE ([Name]), + CONSTRAINT UQ_ProjectCategories_Slug UNIQUE ([Slug]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectCategories_IsActive ON [dbo].[ProjectCategories]([IsActive]); +CREATE NONCLUSTERED INDEX IX_ProjectCategories_Slug ON [dbo].[ProjectCategories]([Slug]); +GO + +PRINT 'STEP 2A COMPLETED: ProjectCategories table created!'; + +================================================================================ +🗄️ STEP 2B: CREATE USERS TABLE +================================================================================ + +-- STEP 2B: Create Users Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[Users] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [Username] NVARCHAR(100) NOT NULL, + [Email] NVARCHAR(255) NOT NULL, + [FirstName] NVARCHAR(100) NOT NULL, + [LastName] NVARCHAR(100) NOT NULL, + [FullName] AS (CONCAT([FirstName], ' ', [LastName])) PERSISTED, + [Initials] AS (CONCAT(LEFT([FirstName], 1), LEFT([LastName], 1))) PERSISTED, + [AvatarUrl] NVARCHAR(500) NULL, + [Phone] NVARCHAR(20) NULL, + [Role] NVARCHAR(20) NOT NULL + CONSTRAINT CK_Users_Role CHECK ([Role] IN ('admin', 'manager', 'developer', 'designer', 'client')), + [Department] NVARCHAR(100) NULL, + [IsActive] BIT NOT NULL DEFAULT 1, + [EmailVerifiedAt] DATETIME2(7) NULL, + [PasswordHash] NVARCHAR(255) NOT NULL, + [RememberToken] NVARCHAR(100) NULL, + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [UpdatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + + CONSTRAINT UQ_Users_Username UNIQUE ([Username]), + CONSTRAINT UQ_Users_Email UNIQUE ([Email]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_Users_Email ON [dbo].[Users]([Email]); +CREATE NONCLUSTERED INDEX IX_Users_Role ON [dbo].[Users]([Role]); +CREATE NONCLUSTERED INDEX IX_Users_IsActive ON [dbo].[Users]([IsActive]); +CREATE NONCLUSTERED INDEX IX_Users_FullName ON [dbo].[Users]([FullName]); +GO + +PRINT 'STEP 2B COMPLETED: Users table created!'; + +================================================================================ +🗄️ STEP 2C: CREATE PROJECTS TABLE +================================================================================ + +-- STEP 2C: Create Projects Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[Projects] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectName] NVARCHAR(255) NOT NULL, + [Description] NVARCHAR(MAX) NOT NULL, + [ClientName] NVARCHAR(255) NOT NULL, + [CategoryId] BIGINT NOT NULL, + [Priority] NVARCHAR(10) NOT NULL DEFAULT 'medium' + CONSTRAINT CK_Projects_Priority CHECK ([Priority] IN ('low', 'medium', 'high')), + [Status] NVARCHAR(20) NOT NULL DEFAULT 'planning' + CONSTRAINT CK_Projects_Status CHECK ([Status] IN ('planning', 'in-progress', 'review', 'completed', 'on-hold')), + [StartDate] DATE NOT NULL, + [EndDate] DATE NOT NULL, + [Budget] DECIMAL(15,2) NOT NULL, + [ActualCost] DECIMAL(15,2) NOT NULL DEFAULT 0.00, + [ProgressPercentage] TINYINT NOT NULL DEFAULT 0 + CONSTRAINT CK_Projects_Progress CHECK ([ProgressPercentage] BETWEEN 0 AND 100), + [CreatedBy] BIGINT NOT NULL, + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [UpdatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [DeletedAt] DATETIME2(7) NULL, + + CONSTRAINT FK_Projects_Category FOREIGN KEY ([CategoryId]) REFERENCES [dbo].[ProjectCategories]([Id]), + CONSTRAINT FK_Projects_CreatedBy FOREIGN KEY ([CreatedBy]) REFERENCES [dbo].[Users]([Id]), + CONSTRAINT CK_Projects_EndDate CHECK ([EndDate] >= [StartDate]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_Projects_Status ON [dbo].[Projects]([Status]); +CREATE NONCLUSTERED INDEX IX_Projects_Priority ON [dbo].[Projects]([Priority]); +CREATE NONCLUSTERED INDEX IX_Projects_Dates ON [dbo].[Projects]([StartDate], [EndDate]); +CREATE NONCLUSTERED INDEX IX_Projects_CreatedBy ON [dbo].[Projects]([CreatedBy]); +CREATE NONCLUSTERED INDEX IX_Projects_Category ON [dbo].[Projects]([CategoryId]); +CREATE NONCLUSTERED INDEX IX_Projects_DeletedAt ON [dbo].[Projects]([DeletedAt]); +GO + +PRINT 'STEP 2C COMPLETED: Projects table created!'; + +================================================================================ +🗄️ STEP 3A: CREATE PROJECTMANAGERS TABLE +================================================================================ + +-- STEP 3A: Create ProjectManagers Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectManagers] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectId] BIGINT NOT NULL, + [UserId] BIGINT NOT NULL, + [AssignedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [AssignedBy] BIGINT NOT NULL, + [IsPrimary] BIT NOT NULL DEFAULT 0, + + CONSTRAINT FK_ProjectManagers_Project FOREIGN KEY ([ProjectId]) REFERENCES [dbo].[Projects]([Id]) ON DELETE CASCADE, + CONSTRAINT FK_ProjectManagers_User FOREIGN KEY ([UserId]) REFERENCES [dbo].[Users]([Id]), + CONSTRAINT FK_ProjectManagers_AssignedBy FOREIGN KEY ([AssignedBy]) REFERENCES [dbo].[Users]([Id]), + CONSTRAINT UQ_ProjectManagers_ProjectUser UNIQUE ([ProjectId], [UserId]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectManagers_Project ON [dbo].[ProjectManagers]([ProjectId]); +CREATE NONCLUSTERED INDEX IX_ProjectManagers_User ON [dbo].[ProjectManagers]([UserId]); +CREATE NONCLUSTERED INDEX IX_ProjectManagers_IsPrimary ON [dbo].[ProjectManagers]([IsPrimary]); +GO + +PRINT 'STEP 3A COMPLETED: ProjectManagers table created!'; + +================================================================================ +🗄️ STEP 3B: CREATE PROJECTTEAMMEMBERS TABLE +================================================================================ + +-- STEP 3B: Create ProjectTeamMembers Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectTeamMembers] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectId] BIGINT NOT NULL, + [UserId] BIGINT NOT NULL, + [Role] NVARCHAR(100) NULL, + [HourlyRate] DECIMAL(8,2) NULL, + [AssignedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [AssignedBy] BIGINT NOT NULL, + [RemovedAt] DATETIME2(7) NULL, + + CONSTRAINT FK_ProjectTeamMembers_Project FOREIGN KEY ([ProjectId]) REFERENCES [dbo].[Projects]([Id]) ON DELETE CASCADE, + CONSTRAINT FK_ProjectTeamMembers_User FOREIGN KEY ([UserId]) REFERENCES [dbo].[Users]([Id]), + CONSTRAINT FK_ProjectTeamMembers_AssignedBy FOREIGN KEY ([AssignedBy]) REFERENCES [dbo].[Users]([Id]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectTeamMembers_Project ON [dbo].[ProjectTeamMembers]([ProjectId]); +CREATE NONCLUSTERED INDEX IX_ProjectTeamMembers_User ON [dbo].[ProjectTeamMembers]([UserId]); +CREATE NONCLUSTERED INDEX IX_ProjectTeamMembers_RemovedAt ON [dbo].[ProjectTeamMembers]([RemovedAt]); +CREATE UNIQUE NONCLUSTERED INDEX UQ_ProjectTeamMembers_Active +ON [dbo].[ProjectTeamMembers]([ProjectId], [UserId]) +WHERE [RemovedAt] IS NULL; +GO + +PRINT 'STEP 3B COMPLETED: ProjectTeamMembers table created!'; + +================================================================================ +🗄️ STEP 4A: CREATE PROJECTTAGS TABLE +================================================================================ + +-- STEP 4A: Create ProjectTags Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectTags] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectId] BIGINT NOT NULL, + [TagName] NVARCHAR(50) NOT NULL, + [Color] NVARCHAR(20) NOT NULL DEFAULT 'gray', + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + + CONSTRAINT FK_ProjectTags_Project FOREIGN KEY ([ProjectId]) REFERENCES [dbo].[Projects]([Id]) ON DELETE CASCADE +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectTags_Project ON [dbo].[ProjectTags]([ProjectId]); +CREATE NONCLUSTERED INDEX IX_ProjectTags_TagName ON [dbo].[ProjectTags]([TagName]); +GO + +PRINT 'STEP 4A COMPLETED: ProjectTags table created!'; + +================================================================================ +🗄️ STEP 4B: CREATE PROJECTATTACHMENTS TABLE +================================================================================ + +-- STEP 4B: Create ProjectAttachments Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectAttachments] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectId] BIGINT NOT NULL, + [FileName] NVARCHAR(255) NOT NULL, + [OriginalName] NVARCHAR(255) NOT NULL, + [FilePath] NVARCHAR(500) NOT NULL, + [FileSize] BIGINT NOT NULL, + [MimeType] NVARCHAR(100) NOT NULL, + [UploadedBy] BIGINT NOT NULL, + [UploadedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + + CONSTRAINT FK_ProjectAttachments_Project FOREIGN KEY ([ProjectId]) REFERENCES [dbo].[Projects]([Id]) ON DELETE CASCADE, + CONSTRAINT FK_ProjectAttachments_UploadedBy FOREIGN KEY ([UploadedBy]) REFERENCES [dbo].[Users]([Id]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectAttachments_Project ON [dbo].[ProjectAttachments]([ProjectId]); +CREATE NONCLUSTERED INDEX IX_ProjectAttachments_UploadedBy ON [dbo].[ProjectAttachments]([UploadedBy]); +GO + +PRINT 'STEP 4B COMPLETED: ProjectAttachments table created!'; diff --git a/SQL_Server_Database_Creation_Steps_Part2.txt b/SQL_Server_Database_Creation_Steps_Part2.txt new file mode 100644 index 0000000..dbaa5a0 --- /dev/null +++ b/SQL_Server_Database_Creation_Steps_Part2.txt @@ -0,0 +1,253 @@ +================================================================================ + SQL SERVER DATABASE CREATION - PART 2 + Remaining Steps (4C - 8) +================================================================================ + +================================================================================ +🗄️ STEP 4C: CREATE CLIENTS TABLE +================================================================================ + +-- STEP 4C: Create Clients Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[Clients] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [Name] NVARCHAR(255) NOT NULL, + [Email] NVARCHAR(255) NULL, + [Phone] NVARCHAR(20) NULL, + [Company] NVARCHAR(255) NULL, + [Address] NVARCHAR(MAX) NULL, + [ContactPerson] NVARCHAR(255) NULL, + [IsActive] BIT NOT NULL DEFAULT 1, + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [UpdatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE() +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_Clients_Name ON [dbo].[Clients]([Name]); +CREATE NONCLUSTERED INDEX IX_Clients_Company ON [dbo].[Clients]([Company]); +CREATE NONCLUSTERED INDEX IX_Clients_IsActive ON [dbo].[Clients]([IsActive]); +GO + +PRINT 'STEP 4C COMPLETED: Clients table created!'; + +================================================================================ +🗄️ STEP 5A: CREATE PROJECTACTIVITYLOGS TABLE +================================================================================ + +-- STEP 5A: Create ProjectActivityLogs Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectActivityLogs] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectId] BIGINT NOT NULL, + [UserId] BIGINT NOT NULL, + [Action] NVARCHAR(100) NOT NULL, + [Description] NVARCHAR(MAX) NULL, + [OldValues] NVARCHAR(MAX) NULL, + [NewValues] NVARCHAR(MAX) NULL, + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + + CONSTRAINT FK_ProjectActivityLogs_Project FOREIGN KEY ([ProjectId]) REFERENCES [dbo].[Projects]([Id]) ON DELETE CASCADE, + CONSTRAINT FK_ProjectActivityLogs_User FOREIGN KEY ([UserId]) REFERENCES [dbo].[Users]([Id]) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectActivityLogs_Project ON [dbo].[ProjectActivityLogs]([ProjectId]); +CREATE NONCLUSTERED INDEX IX_ProjectActivityLogs_User ON [dbo].[ProjectActivityLogs]([UserId]); +CREATE NONCLUSTERED INDEX IX_ProjectActivityLogs_Action ON [dbo].[ProjectActivityLogs]([Action]); +CREATE NONCLUSTERED INDEX IX_ProjectActivityLogs_CreatedAt ON [dbo].[ProjectActivityLogs]([CreatedAt]); +GO + +PRINT 'STEP 5A COMPLETED: ProjectActivityLogs table created!'; + +================================================================================ +🗄️ STEP 5B: CREATE PROJECTTIMEENTRIES TABLE +================================================================================ + +-- STEP 5B: Create ProjectTimeEntries Table +USE ProjectManagementDB; +GO + +CREATE TABLE [dbo].[ProjectTimeEntries] ( + [Id] BIGINT IDENTITY(1,1) PRIMARY KEY, + [ProjectId] BIGINT NOT NULL, + [UserId] BIGINT NOT NULL, + [TaskDescription] NVARCHAR(MAX) NOT NULL, + [HoursWorked] DECIMAL(5,2) NOT NULL, + [WorkDate] DATE NOT NULL, + [Billable] BIT NOT NULL DEFAULT 1, + [HourlyRate] DECIMAL(8,2) NULL, + [CreatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + [UpdatedAt] DATETIME2(7) NOT NULL DEFAULT GETUTCDATE(), + + CONSTRAINT FK_ProjectTimeEntries_Project FOREIGN KEY ([ProjectId]) REFERENCES [dbo].[Projects]([Id]) ON DELETE CASCADE, + CONSTRAINT FK_ProjectTimeEntries_User FOREIGN KEY ([UserId]) REFERENCES [dbo].[Users]([Id]), + CONSTRAINT CK_ProjectTimeEntries_HoursWorked CHECK ([HoursWorked] > 0 AND [HoursWorked] <= 24) +); +GO + +-- Create indexes +CREATE NONCLUSTERED INDEX IX_ProjectTimeEntries_Project ON [dbo].[ProjectTimeEntries]([ProjectId]); +CREATE NONCLUSTERED INDEX IX_ProjectTimeEntries_User ON [dbo].[ProjectTimeEntries]([UserId]); +CREATE NONCLUSTERED INDEX IX_ProjectTimeEntries_WorkDate ON [dbo].[ProjectTimeEntries]([WorkDate]); +CREATE NONCLUSTERED INDEX IX_ProjectTimeEntries_Billable ON [dbo].[ProjectTimeEntries]([Billable]); +GO + +PRINT 'STEP 5B COMPLETED: ProjectTimeEntries table created!'; + +================================================================================ +🗄️ STEP 6: CREATE TRIGGERS FOR UPDATEDAT +================================================================================ + +-- STEP 6: Create Triggers for UpdatedAt +USE ProjectManagementDB; +GO + +-- Trigger for Projects +CREATE TRIGGER TR_Projects_UpdatedAt ON [dbo].[Projects] +AFTER UPDATE +AS +BEGIN + SET NOCOUNT ON; + UPDATE [dbo].[Projects] + SET [UpdatedAt] = GETUTCDATE() + FROM [dbo].[Projects] p + INNER JOIN inserted i ON p.[Id] = i.[Id]; +END; +GO + +-- Trigger for ProjectCategories +CREATE TRIGGER TR_ProjectCategories_UpdatedAt ON [dbo].[ProjectCategories] +AFTER UPDATE +AS +BEGIN + SET NOCOUNT ON; + UPDATE [dbo].[ProjectCategories] + SET [UpdatedAt] = GETUTCDATE() + FROM [dbo].[ProjectCategories] pc + INNER JOIN inserted i ON pc.[Id] = i.[Id]; +END; +GO + +-- Trigger for Users +CREATE TRIGGER TR_Users_UpdatedAt ON [dbo].[Users] +AFTER UPDATE +AS +BEGIN + SET NOCOUNT ON; + UPDATE [dbo].[Users] + SET [UpdatedAt] = GETUTCDATE() + FROM [dbo].[Users] u + INNER JOIN inserted i ON u.[Id] = i.[Id]; +END; +GO + +-- Trigger for Clients +CREATE TRIGGER TR_Clients_UpdatedAt ON [dbo].[Clients] +AFTER UPDATE +AS +BEGIN + SET NOCOUNT ON; + UPDATE [dbo].[Clients] + SET [UpdatedAt] = GETUTCDATE() + FROM [dbo].[Clients] c + INNER JOIN inserted i ON c.[Id] = i.[Id]; +END; +GO + +-- Trigger for ProjectTimeEntries +CREATE TRIGGER TR_ProjectTimeEntries_UpdatedAt ON [dbo].[ProjectTimeEntries] +AFTER UPDATE +AS +BEGIN + SET NOCOUNT ON; + UPDATE [dbo].[ProjectTimeEntries] + SET [UpdatedAt] = GETUTCDATE() + FROM [dbo].[ProjectTimeEntries] pte + INNER JOIN inserted i ON pte.[Id] = i.[Id]; +END; +GO + +PRINT 'STEP 6 COMPLETED: All triggers created!'; + +================================================================================ +🗄️ STEP 7: CREATE VIEWS +================================================================================ + +-- STEP 7A: Create ProjectSummary view +USE ProjectManagementDB; +GO + +CREATE VIEW [dbo].[vw_ProjectSummary] +AS +SELECT + p.[Id], + p.[ProjectName], + p.[ClientName], + pc.[Name] as [CategoryName], + pc.[Color] as [CategoryColor], + p.[Priority], + p.[Status], + p.[StartDate], + p.[EndDate], + p.[Budget], + p.[ProgressPercentage], + DATEDIFF(DAY, p.[StartDate], p.[EndDate]) as [DurationDays], + DATEDIFF(DAY, GETDATE(), p.[EndDate]) as [DaysRemaining], + (SELECT COUNT(*) FROM [dbo].[ProjectManagers] pm WHERE pm.[ProjectId] = p.[Id]) as [ManagerCount], + (SELECT COUNT(*) FROM [dbo].[ProjectTeamMembers] ptm WHERE ptm.[ProjectId] = p.[Id] AND ptm.[RemovedAt] IS NULL) as [TeamMemberCount], + u.[FullName] as [CreatedByName], + p.[CreatedAt], + p.[UpdatedAt] +FROM [dbo].[Projects] p +INNER JOIN [dbo].[ProjectCategories] pc ON p.[CategoryId] = pc.[Id] +INNER JOIN [dbo].[Users] u ON p.[CreatedBy] = u.[Id] +WHERE p.[DeletedAt] IS NULL; +GO + +PRINT 'STEP 7A COMPLETED: ProjectSummary view created!'; + +-- STEP 7B: Create ProjectTeam view +CREATE VIEW [dbo].[vw_ProjectTeam] +AS +SELECT + p.[Id] as [ProjectId], + p.[ProjectName], + u.[Id] as [UserId], + u.[FullName], + u.[Email], + u.[Role] as [UserRole], + 'Manager' as [ProjectRole], + pm.[IsPrimary], + pm.[AssignedAt], + NULL as [RemovedAt] +FROM [dbo].[Projects] p +INNER JOIN [dbo].[ProjectManagers] pm ON p.[Id] = pm.[ProjectId] +INNER JOIN [dbo].[Users] u ON pm.[UserId] = u.[Id] +WHERE p.[DeletedAt] IS NULL + +UNION ALL + +SELECT + p.[Id] as [ProjectId], + p.[ProjectName], + u.[Id] as [UserId], + u.[FullName], + u.[Email], + u.[Role] as [UserRole], + COALESCE(ptm.[Role], 'Team Member') as [ProjectRole], + 0 as [IsPrimary], + ptm.[AssignedAt], + ptm.[RemovedAt] +FROM [dbo].[Projects] p +INNER JOIN [dbo].[ProjectTeamMembers] ptm ON p.[Id] = ptm.[ProjectId] +INNER JOIN [dbo].[Users] u ON ptm.[UserId] = u.[Id] +WHERE p.[DeletedAt] IS NULL; +GO + +PRINT 'STEP 7B COMPLETED: ProjectTeam view created!'; diff --git a/SQL_Server_Sample_Data_Insert.txt b/SQL_Server_Sample_Data_Insert.txt new file mode 100644 index 0000000..01cf435 --- /dev/null +++ b/SQL_Server_Sample_Data_Insert.txt @@ -0,0 +1,215 @@ +================================================================================ + SQL SERVER SAMPLE DATA INSERTION + Project Management System Database +================================================================================ + +📋 OVERVIEW: +- Insert sample data for testing +- Categories, Users, and initial project data +- Run after all tables are created + +================================================================================ +🗄️ STEP 8A: INSERT SAMPLE CATEGORIES +================================================================================ + +-- STEP 8A: Insert sample project categories +USE ProjectManagementDB; +GO + +SET IDENTITY_INSERT [dbo].[ProjectCategories] ON; + +INSERT INTO [dbo].[ProjectCategories] ([Id], [Name], [Slug], [Color], [Icon], [Description]) VALUES +(1, N'Web Development', N'web-development', N'blue', N'fas fa-code', N'Frontend and backend web applications'), +(2, N'Mobile App', N'mobile-app', N'green', N'fas fa-mobile-alt', N'iOS and Android mobile applications'), +(3, N'Design', N'design', N'purple', N'fas fa-palette', N'UI/UX design and branding projects'), +(4, N'Marketing', N'marketing', N'orange', N'fas fa-bullhorn', N'Digital marketing and campaigns'), +(5, N'DevOps', N'devops', N'cyan', N'fas fa-server', N'Infrastructure and deployment projects'), +(6, N'Data Science', N'data-science', N'red', N'fas fa-chart-line', N'Analytics and machine learning projects'); + +SET IDENTITY_INSERT [dbo].[ProjectCategories] OFF; +GO + +PRINT 'STEP 8A COMPLETED: Sample categories inserted!'; + +================================================================================ +🗄️ STEP 8B: INSERT SAMPLE USERS +================================================================================ + +-- STEP 8B: Insert sample users +USE ProjectManagementDB; +GO + +SET IDENTITY_INSERT [dbo].[Users] ON; + +INSERT INTO [dbo].[Users] ([Id], [Username], [Email], [FirstName], [LastName], [Role], [Department], [IsActive], [PasswordHash]) VALUES +(1, N'john.smith', N'john.smith@company.com', N'John', N'Smith', N'manager', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(2, N'sarah.johnson', N'sarah.johnson@company.com', N'Sarah', N'Johnson', N'manager', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(3, N'mike.wilson', N'mike.wilson@company.com', N'Mike', N'Wilson', N'manager', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(4, N'lisa.chen', N'lisa.chen@company.com', N'Lisa', N'Chen', N'manager', N'Design', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(5, N'alex.rodriguez', N'alex.rodriguez@company.com', N'Alex', N'Rodriguez', N'developer', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(6, N'maria.garcia', N'maria.garcia@company.com', N'Maria', N'Garcia', N'designer', N'Design', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(7, N'david.brown', N'david.brown@company.com', N'David', N'Brown', N'developer', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(8, N'emma.davis', N'emma.davis@company.com', N'Emma', N'Davis', N'developer', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(9, N'james.miller', N'james.miller@company.com', N'James', N'Miller', N'developer', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'), +(10, N'admin', N'admin@company.com', N'System', N'Administrator', N'admin', N'IT', 1, N'$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi'); + +SET IDENTITY_INSERT [dbo].[Users] OFF; +GO + +PRINT 'STEP 8B COMPLETED: Sample users inserted!'; + +================================================================================ +🗄️ STEP 8C: INSERT SAMPLE CLIENTS +================================================================================ + +-- STEP 8C: Insert sample clients +USE ProjectManagementDB; +GO + +SET IDENTITY_INSERT [dbo].[Clients] ON; + +INSERT INTO [dbo].[Clients] ([Id], [Name], [Email], [Phone], [Company], [ContactPerson]) VALUES +(1, N'ABC Corporation', N'contact@abc-corp.com', N'+1-555-0101', N'ABC Corporation', N'Robert Johnson'), +(2, N'XYZ Tech Solutions', N'info@xyz-tech.com', N'+1-555-0102', N'XYZ Tech Solutions', N'Jennifer Smith'), +(3, N'Global Enterprises', N'hello@global-ent.com', N'+1-555-0103', N'Global Enterprises', N'Michael Brown'), +(4, N'StartupCo', N'team@startupco.com', N'+1-555-0104', N'StartupCo', N'Sarah Wilson'), +(5, N'Enterprise Solutions Ltd', N'contact@enterprise-sol.com', N'+1-555-0105', N'Enterprise Solutions Ltd', N'David Lee'); + +SET IDENTITY_INSERT [dbo].[Clients] OFF; +GO + +PRINT 'STEP 8C COMPLETED: Sample clients inserted!'; + +================================================================================ +🗄️ STEP 8D: INSERT SAMPLE PROJECT +================================================================================ + +-- STEP 8D: Insert a sample project +USE ProjectManagementDB; +GO + +SET IDENTITY_INSERT [dbo].[Projects] ON; + +INSERT INTO [dbo].[Projects] ( + [Id], [ProjectName], [Description], [ClientName], [CategoryId], + [Priority], [Status], [StartDate], [EndDate], [Budget], [CreatedBy] +) VALUES ( + 1, + N'E-commerce Website Development', + N'Build a modern e-commerce platform with React frontend and .NET Core backend. Features include product catalog, shopping cart, payment integration, and admin dashboard.', + N'ABC Corporation', + 1, -- Web Development category + N'high', + N'planning', + '2024-01-15', + '2024-04-15', + 50000.00, + 1 -- Created by John Smith +); + +SET IDENTITY_INSERT [dbo].[Projects] OFF; +GO + +-- Insert project managers +INSERT INTO [dbo].[ProjectManagers] ([ProjectId], [UserId], [AssignedBy], [IsPrimary]) VALUES +(1, 1, 10, 1), -- John Smith as primary manager +(1, 2, 10, 0); -- Sarah Johnson as secondary manager + +-- Insert team members +INSERT INTO [dbo].[ProjectTeamMembers] ([ProjectId], [UserId], [Role], [HourlyRate], [AssignedBy]) VALUES +(1, 5, N'Frontend Developer', 75.00, 1), -- Alex Rodriguez +(1, 6, N'UI/UX Designer', 65.00, 1), -- Maria Garcia +(1, 7, N'Backend Developer', 80.00, 1); -- David Brown + +-- Insert project tags +INSERT INTO [dbo].[ProjectTags] ([ProjectId], [TagName], [Color]) VALUES +(1, N'react', N'blue'), +(1, N'dotnet', N'purple'), +(1, N'ecommerce', N'orange'), +(1, N'responsive', N'green'); + +-- Insert activity log +INSERT INTO [dbo].[ProjectActivityLogs] ([ProjectId], [UserId], [Action], [Description]) VALUES +(1, 1, N'created', N'Project created with initial team assignment'); + +PRINT 'STEP 8D COMPLETED: Sample project inserted!'; + +================================================================================ +🗄️ STEP 8E: VERIFICATION QUERIES +================================================================================ + +-- STEP 8E: Verify data insertion +USE ProjectManagementDB; +GO + +-- Check all tables have data +SELECT 'ProjectCategories' as TableName, COUNT(*) as RecordCount FROM [dbo].[ProjectCategories] +UNION ALL +SELECT 'Users', COUNT(*) FROM [dbo].[Users] +UNION ALL +SELECT 'Clients', COUNT(*) FROM [dbo].[Clients] +UNION ALL +SELECT 'Projects', COUNT(*) FROM [dbo].[Projects] +UNION ALL +SELECT 'ProjectManagers', COUNT(*) FROM [dbo].[ProjectManagers] +UNION ALL +SELECT 'ProjectTeamMembers', COUNT(*) FROM [dbo].[ProjectTeamMembers] +UNION ALL +SELECT 'ProjectTags', COUNT(*) FROM [dbo].[ProjectTags] +UNION ALL +SELECT 'ProjectActivityLogs', COUNT(*) FROM [dbo].[ProjectActivityLogs]; + +-- Test the views +SELECT TOP 5 * FROM [dbo].[vw_ProjectSummary]; +SELECT TOP 10 * FROM [dbo].[vw_ProjectTeam]; + +-- Test API-ready queries +-- Get categories for dropdown +SELECT [Id], [Name], [Slug], [Color] FROM [dbo].[ProjectCategories] WHERE [IsActive] = 1; + +-- Get managers for multi-select +SELECT [Id], [Username], [FullName], [Initials] FROM [dbo].[Users] WHERE [Role] = 'manager' AND [IsActive] = 1; + +-- Get developers/designers for team selection +SELECT [Id], [Username], [FullName], [Initials], [Role] FROM [dbo].[Users] +WHERE [Role] IN ('developer', 'designer') AND [IsActive] = 1; + +PRINT 'STEP 8E COMPLETED: Data verification completed!'; +PRINT '================================================================================'; +PRINT 'DATABASE SETUP COMPLETED SUCCESSFULLY!'; +PRINT 'You can now use the database with your Create Project form.'; +PRINT '================================================================================'; + +================================================================================ +🗄️ USEFUL QUERIES FOR TESTING +================================================================================ + +-- Get project details with team +SELECT + p.ProjectName, + p.ClientName, + pc.Name as Category, + p.Priority, + p.Status, + p.Budget, + STRING_AGG(DISTINCT um.FullName, ', ') as Managers, + STRING_AGG(DISTINCT ut.FullName, ', ') as TeamMembers +FROM Projects p +LEFT JOIN ProjectCategories pc ON p.CategoryId = pc.Id +LEFT JOIN ProjectManagers pm ON p.Id = pm.ProjectId +LEFT JOIN Users um ON pm.UserId = um.Id +LEFT JOIN ProjectTeamMembers ptm ON p.Id = ptm.ProjectId AND ptm.RemovedAt IS NULL +LEFT JOIN Users ut ON ptm.UserId = ut.Id +WHERE p.DeletedAt IS NULL +GROUP BY p.Id, p.ProjectName, p.ClientName, pc.Name, p.Priority, p.Status, p.Budget; + +-- Get project activity timeline +SELECT + pal.Action, + pal.Description, + u.FullName as PerformedBy, + pal.CreatedAt +FROM ProjectActivityLogs pal +JOIN Users u ON pal.UserId = u.Id +WHERE pal.ProjectId = 1 +ORDER BY pal.CreatedAt DESC; diff --git a/SQL_Server_Stored_Procedures.txt b/SQL_Server_Stored_Procedures.txt new file mode 100644 index 0000000..cad27d3 --- /dev/null +++ b/SQL_Server_Stored_Procedures.txt @@ -0,0 +1,459 @@ +================================================================================ + SQL SERVER STORED PROCEDURES + Project Management System Database +================================================================================ + +📋 OVERVIEW: +- Stored procedures for Create Project functionality +- API-ready procedures for frontend integration +- Error handling and transaction management + +================================================================================ +🗄️ STEP 9A: CREATE PROJECT PROCEDURE +================================================================================ + +-- STEP 9A: Create stored procedure for creating projects +USE ProjectManagementDB; +GO + +CREATE PROCEDURE [dbo].[sp_CreateProject] + @ProjectName NVARCHAR(255), + @Description NVARCHAR(MAX), + @ClientName NVARCHAR(255), + @CategoryId BIGINT, + @Priority NVARCHAR(10) = 'medium', + @Status NVARCHAR(20) = 'planning', + @StartDate DATE, + @EndDate DATE, + @Budget DECIMAL(15,2), + @CreatedBy BIGINT, + @Managers NVARCHAR(MAX), -- JSON array of user IDs: [1,2,3] + @TeamMembers NVARCHAR(MAX) = NULL, -- JSON array of user IDs: [4,5,6] + @Tags NVARCHAR(MAX) = NULL -- JSON array of tag names: ["react","nodejs"] +AS +BEGIN + SET NOCOUNT ON; + + DECLARE @ProjectId BIGINT; + DECLARE @ErrorMessage NVARCHAR(4000); + + BEGIN TRY + BEGIN TRANSACTION; + + -- Validate inputs + IF LEN(TRIM(@ProjectName)) = 0 + THROW 50001, 'Project name is required', 1; + + IF LEN(TRIM(@Description)) = 0 + THROW 50002, 'Project description is required', 1; + + IF LEN(TRIM(@ClientName)) = 0 + THROW 50003, 'Client name is required', 1; + + IF @Budget <= 0 + THROW 50004, 'Budget must be greater than 0', 1; + + IF @EndDate <= @StartDate + THROW 50005, 'End date must be after start date', 1; + + -- Insert project + INSERT INTO [dbo].[Projects] ( + [ProjectName], [Description], [ClientName], [CategoryId], + [Priority], [Status], [StartDate], [EndDate], [Budget], [CreatedBy] + ) + VALUES ( + @ProjectName, @Description, @ClientName, @CategoryId, + @Priority, @Status, @StartDate, @EndDate, @Budget, @CreatedBy + ); + + SET @ProjectId = SCOPE_IDENTITY(); + + -- Insert managers + IF @Managers IS NOT NULL AND @Managers != '[]' + BEGIN + INSERT INTO [dbo].[ProjectManagers] ([ProjectId], [UserId], [AssignedBy], [IsPrimary]) + SELECT + @ProjectId, + CAST([value] AS BIGINT), + @CreatedBy, + CASE WHEN ROW_NUMBER() OVER (ORDER BY [key]) = 1 THEN 1 ELSE 0 END -- First manager is primary + FROM OPENJSON(@Managers); + END + + -- Insert team members + IF @TeamMembers IS NOT NULL AND @TeamMembers != '[]' + BEGIN + INSERT INTO [dbo].[ProjectTeamMembers] ([ProjectId], [UserId], [AssignedBy]) + SELECT @ProjectId, CAST([value] AS BIGINT), @CreatedBy + FROM OPENJSON(@TeamMembers); + END + + -- Insert tags + IF @Tags IS NOT NULL AND @Tags != '[]' + BEGIN + INSERT INTO [dbo].[ProjectTags] ([ProjectId], [TagName]) + SELECT @ProjectId, [value] + FROM OPENJSON(@Tags); + END + + -- Log activity + INSERT INTO [dbo].[ProjectActivityLogs] ([ProjectId], [UserId], [Action], [Description]) + VALUES (@ProjectId, @CreatedBy, 'created', 'Project created with initial setup'); + + COMMIT TRANSACTION; + + -- Return project details + SELECT + p.[Id], + p.[ProjectName], + p.[Description], + p.[ClientName], + p.[CategoryId], + pc.[Name] as [CategoryName], + pc.[Color] as [CategoryColor], + p.[Priority], + p.[Status], + p.[StartDate], + p.[EndDate], + p.[Budget], + p.[ProgressPercentage], + u.[FullName] as [CreatedByName], + p.[CreatedAt], + p.[UpdatedAt] + FROM [dbo].[Projects] p + INNER JOIN [dbo].[ProjectCategories] pc ON p.[CategoryId] = pc.[Id] + INNER JOIN [dbo].[Users] u ON p.[CreatedBy] = u.[Id] + WHERE p.[Id] = @ProjectId; + + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRANSACTION; + + SET @ErrorMessage = ERROR_MESSAGE(); + THROW 50000, @ErrorMessage, 1; + END CATCH +END; +GO + +PRINT 'STEP 9A COMPLETED: sp_CreateProject procedure created!'; + +================================================================================ +🗄️ STEP 9B: GET PROJECT DETAILS PROCEDURE +================================================================================ + +-- STEP 9B: Create stored procedure for getting project details +USE ProjectManagementDB; +GO + +CREATE PROCEDURE [dbo].[sp_GetProjectDetails] + @ProjectId BIGINT +AS +BEGIN + SET NOCOUNT ON; + + -- Project basic info + SELECT + p.[Id], + p.[ProjectName], + p.[Description], + p.[ClientName], + p.[CategoryId], + pc.[Name] as [CategoryName], + pc.[Color] as [CategoryColor], + pc.[Icon] as [CategoryIcon], + p.[Priority], + p.[Status], + p.[StartDate], + p.[EndDate], + p.[Budget], + p.[ActualCost], + p.[ProgressPercentage], + u.[FullName] as [CreatedByName], + p.[CreatedAt], + p.[UpdatedAt] + FROM [dbo].[Projects] p + INNER JOIN [dbo].[ProjectCategories] pc ON p.[CategoryId] = pc.[Id] + INNER JOIN [dbo].[Users] u ON p.[CreatedBy] = u.[Id] + WHERE p.[Id] = @ProjectId AND p.[DeletedAt] IS NULL; + + -- Project managers + SELECT + u.[Id], + u.[Username], + u.[FullName], + u.[Email], + u.[Initials], + u.[Role], + pm.[IsPrimary], + pm.[AssignedAt] + FROM [dbo].[ProjectManagers] pm + INNER JOIN [dbo].[Users] u ON pm.[UserId] = u.[Id] + WHERE pm.[ProjectId] = @ProjectId + ORDER BY pm.[IsPrimary] DESC, u.[FullName]; + + -- Project team members + SELECT + u.[Id], + u.[Username], + u.[FullName], + u.[Email], + u.[Initials], + u.[Role] as [UserRole], + ptm.[Role] as [ProjectRole], + ptm.[HourlyRate], + ptm.[AssignedAt] + FROM [dbo].[ProjectTeamMembers] ptm + INNER JOIN [dbo].[Users] u ON ptm.[UserId] = u.[Id] + WHERE ptm.[ProjectId] = @ProjectId AND ptm.[RemovedAt] IS NULL + ORDER BY u.[FullName]; + + -- Project tags + SELECT [TagName], [Color] + FROM [dbo].[ProjectTags] + WHERE [ProjectId] = @ProjectId + ORDER BY [TagName]; + + -- Project attachments + SELECT + [Id], + [FileName], + [OriginalName], + [FileSize], + [MimeType], + [UploadedAt], + u.[FullName] as [UploadedByName] + FROM [dbo].[ProjectAttachments] pa + INNER JOIN [dbo].[Users] u ON pa.[UploadedBy] = u.[Id] + WHERE pa.[ProjectId] = @ProjectId + ORDER BY pa.[UploadedAt] DESC; + + -- Recent activity (last 10) + SELECT TOP 10 + pal.[Action], + pal.[Description], + u.[FullName] as [PerformedBy], + pal.[CreatedAt] + FROM [dbo].[ProjectActivityLogs] pal + INNER JOIN [dbo].[Users] u ON pal.[UserId] = u.[Id] + WHERE pal.[ProjectId] = @ProjectId + ORDER BY pal.[CreatedAt] DESC; +END; +GO + +PRINT 'STEP 9B COMPLETED: sp_GetProjectDetails procedure created!'; + +================================================================================ +🗄️ STEP 9C: GET FORM DATA PROCEDURES +================================================================================ + +-- STEP 9C: Procedures for populating form dropdowns +USE ProjectManagementDB; +GO + +-- Get categories for dropdown +CREATE PROCEDURE [dbo].[sp_GetProjectCategories] +AS +BEGIN + SET NOCOUNT ON; + + SELECT + [Id], + [Name], + [Slug], + [Color], + [Icon], + [Description] + FROM [dbo].[ProjectCategories] + WHERE [IsActive] = 1 + ORDER BY [Name]; +END; +GO + +-- Get managers for multi-select +CREATE PROCEDURE [dbo].[sp_GetManagers] +AS +BEGIN + SET NOCOUNT ON; + + SELECT + [Id], + [Username], + [FullName], + [Email], + [Initials], + [Department] + FROM [dbo].[Users] + WHERE [Role] = 'manager' AND [IsActive] = 1 + ORDER BY [FullName]; +END; +GO + +-- Get team members for multi-select +CREATE PROCEDURE [dbo].[sp_GetTeamMembers] +AS +BEGIN + SET NOCOUNT ON; + + SELECT + [Id], + [Username], + [FullName], + [Email], + [Initials], + [Role], + [Department] + FROM [dbo].[Users] + WHERE [Role] IN ('developer', 'designer') AND [IsActive] = 1 + ORDER BY [Role], [FullName]; +END; +GO + +-- Get all active users +CREATE PROCEDURE [dbo].[sp_GetActiveUsers] +AS +BEGIN + SET NOCOUNT ON; + + SELECT + [Id], + [Username], + [FullName], + [Email], + [Initials], + [Role], + [Department] + FROM [dbo].[Users] + WHERE [IsActive] = 1 + ORDER BY [Role], [FullName]; +END; +GO + +PRINT 'STEP 9C COMPLETED: Form data procedures created!'; + +================================================================================ +🗄️ STEP 9D: PROJECT SEARCH AND LISTING PROCEDURES +================================================================================ + +-- STEP 9D: Procedures for project listing and search +USE ProjectManagementDB; +GO + +CREATE PROCEDURE [dbo].[sp_GetProjects] + @Status NVARCHAR(20) = NULL, + @Priority NVARCHAR(10) = NULL, + @CategoryId BIGINT = NULL, + @SearchTerm NVARCHAR(255) = NULL, + @PageNumber INT = 1, + @PageSize INT = 10 +AS +BEGIN + SET NOCOUNT ON; + + DECLARE @Offset INT = (@PageNumber - 1) * @PageSize; + + -- Get projects with filters + SELECT + p.[Id], + p.[ProjectName], + p.[ClientName], + pc.[Name] as [CategoryName], + pc.[Color] as [CategoryColor], + p.[Priority], + p.[Status], + p.[StartDate], + p.[EndDate], + p.[Budget], + p.[ProgressPercentage], + DATEDIFF(DAY, GETDATE(), p.[EndDate]) as [DaysRemaining], + (SELECT COUNT(*) FROM [dbo].[ProjectManagers] pm WHERE pm.[ProjectId] = p.[Id]) as [ManagerCount], + (SELECT COUNT(*) FROM [dbo].[ProjectTeamMembers] ptm WHERE ptm.[ProjectId] = p.[Id] AND ptm.[RemovedAt] IS NULL) as [TeamMemberCount], + u.[FullName] as [CreatedByName], + p.[CreatedAt] + FROM [dbo].[Projects] p + INNER JOIN [dbo].[ProjectCategories] pc ON p.[CategoryId] = pc.[Id] + INNER JOIN [dbo].[Users] u ON p.[CreatedBy] = u.[Id] + WHERE p.[DeletedAt] IS NULL + AND (@Status IS NULL OR p.[Status] = @Status) + AND (@Priority IS NULL OR p.[Priority] = @Priority) + AND (@CategoryId IS NULL OR p.[CategoryId] = @CategoryId) + AND (@SearchTerm IS NULL OR + p.[ProjectName] LIKE '%' + @SearchTerm + '%' OR + p.[Description] LIKE '%' + @SearchTerm + '%' OR + p.[ClientName] LIKE '%' + @SearchTerm + '%') + ORDER BY p.[CreatedAt] DESC + OFFSET @Offset ROWS + FETCH NEXT @PageSize ROWS ONLY; + + -- Get total count for pagination + SELECT COUNT(*) as [TotalCount] + FROM [dbo].[Projects] p + WHERE p.[DeletedAt] IS NULL + AND (@Status IS NULL OR p.[Status] = @Status) + AND (@Priority IS NULL OR p.[Priority] = @Priority) + AND (@CategoryId IS NULL OR p.[CategoryId] = @CategoryId) + AND (@SearchTerm IS NULL OR + p.[ProjectName] LIKE '%' + @SearchTerm + '%' OR + p.[Description] LIKE '%' + @SearchTerm + '%' OR + p.[ClientName] LIKE '%' + @SearchTerm + '%'); +END; +GO + +PRINT 'STEP 9D COMPLETED: Project listing procedures created!'; + +================================================================================ +🗄️ STEP 9E: TESTING THE PROCEDURES +================================================================================ + +-- STEP 9E: Test the stored procedures +USE ProjectManagementDB; +GO + +-- Test creating a new project +DECLARE @TestResult TABLE ( + Id BIGINT, + ProjectName NVARCHAR(255), + CategoryName NVARCHAR(100), + CreatedByName NVARCHAR(255) +); + +INSERT INTO @TestResult +EXEC [dbo].[sp_CreateProject] + @ProjectName = N'Mobile App Development', + @Description = N'Develop a cross-platform mobile application using React Native', + @ClientName = N'XYZ Tech Solutions', + @CategoryId = 2, + @Priority = N'medium', + @Status = N'planning', + @StartDate = '2024-02-01', + @EndDate = '2024-05-01', + @Budget = 35000.00, + @CreatedBy = 1, + @Managers = N'[2,3]', + @TeamMembers = N'[5,8,9]', + @Tags = N'["react-native","mobile","cross-platform"]'; + +SELECT * FROM @TestResult; + +-- Test getting project details +EXEC [dbo].[sp_GetProjectDetails] @ProjectId = 1; + +-- Test getting form data +EXEC [dbo].[sp_GetProjectCategories]; +EXEC [dbo].[sp_GetManagers]; +EXEC [dbo].[sp_GetTeamMembers]; + +-- Test project listing +EXEC [dbo].[sp_GetProjects] + @Status = NULL, + @Priority = NULL, + @CategoryId = NULL, + @SearchTerm = NULL, + @PageNumber = 1, + @PageSize = 10; + +PRINT 'STEP 9E COMPLETED: All procedures tested successfully!'; +PRINT '================================================================================'; +PRINT 'STORED PROCEDURES SETUP COMPLETED!'; +PRINT 'Your database is now ready for API integration.'; +PRINT '================================================================================';