diff --git a/Websites/SharePrices/.vs/SharePrices/v17/.suo b/Websites/SharePrices/.vs/SharePrices/v17/.suo index a35604e..d26668a 100644 Binary files a/Websites/SharePrices/.vs/SharePrices/v17/.suo and b/Websites/SharePrices/.vs/SharePrices/v17/.suo differ diff --git a/Websites/SharePrices/.vs/SharePrices/v17/DocumentLayout.backup.json b/Websites/SharePrices/.vs/SharePrices/v17/DocumentLayout.backup.json index 7176f60..c1073ec 100644 --- a/Websites/SharePrices/.vs/SharePrices/v17/DocumentLayout.backup.json +++ b/Websites/SharePrices/.vs/SharePrices/v17/DocumentLayout.backup.json @@ -1,6 +1,6 @@ { "Version": 1, - "WorkspaceRootPath": "C:\\Users\\Steve.OZDOMAIN\\source\\repos\\Steves_Code\\Websites\\SharePrices\\", + "WorkspaceRootPath": "\\\\OZHOST1\\d$\\Documents\\Visual Studio Projects\\SharePrices\\", "Documents": [], "DocumentGroupContainers": [ { diff --git a/Websites/SharePrices/SharePrices.v12.suo b/Websites/SharePrices/SharePrices.v12.suo index 01a0154..3847ce3 100644 Binary files a/Websites/SharePrices/SharePrices.v12.suo and b/Websites/SharePrices/SharePrices.v12.suo differ diff --git a/Websites/SharePrices/SharePrices/App_Code/DataAccessLayer.vb b/Websites/SharePrices/SharePrices/App_Code/DataAccessLayer.vb index 6394bb4..d75d361 100644 --- a/Websites/SharePrices/SharePrices/App_Code/DataAccessLayer.vb +++ b/Websites/SharePrices/SharePrices/App_Code/DataAccessLayer.vb @@ -47,13 +47,15 @@ Public Class DataAccessLayer DisposeSQLCommand(c) End Sub - Public Shared Function AddHolding(AccountName As String, Symbol As String, NoUnits As Double, PurchasePricePerUnit As Double, PurchaseDate As Int64) As String + Public Shared Function AddHolding(AccountName As String, Symbol As String, NoUnits As Double, PurchasePricePerUnit As Double, PurchaseDate As Int64, PurchaseCurrency As String, BookCostInPurchaseCurrency As Double) As String Dim c As SqlCommand = GetSQLCommand("usp_InsertHolding") c.Parameters.AddWithValue("Account", AccountName) c.Parameters.AddWithValue("Symbol", Symbol) c.Parameters.AddWithValue("NoUnits", NoUnits) c.Parameters.AddWithValue("PurchasePricePerUnit", PurchasePricePerUnit) c.Parameters.AddWithValue("PurchaseDate", FromEpochTime(PurchaseDate)) + c.Parameters.AddWithValue("PurchaseCurrency", PurchaseCurrency) + c.Parameters.AddWithValue("BookCostInPurchaseCurrency", BookCostInPurchaseCurrency) AddHolding = DataReaderToJSONString(c.ExecuteReader()) DisposeSQLCommand(c) End Function @@ -221,7 +223,8 @@ Public Class DataAccessLayer End Function Private Shared Function GetSQLConnection() As SqlConnection - Dim c As New SqlConnection("Server=OZHOST1\SQL2008;Database=SharePrices;Trusted_Connection=True;Application Name=Share Prices Web;") + 'Dim c As New SqlConnection("Server=OZHOST1\SQL2008;Database=SharePrices;Trusted_Connection=True;Application Name=Share Prices Web;") + Dim c As New SqlConnection("Server=WinSrv1\INSTANCE1;Database=SharePrices;Trusted_Connection=True;Application Name=Share Prices Web;") c.Open() Return c End Function diff --git a/Websites/SharePrices/SharePrices/CreateDBSchema.sql b/Websites/SharePrices/SharePrices/CreateDBSchema.sql index bb0e965..ac2f758 100644 --- a/Websites/SharePrices/SharePrices/CreateDBSchema.sql +++ b/Websites/SharePrices/SharePrices/CreateDBSchema.sql @@ -2,9 +2,11 @@ USE SharePrices GO /* +DROP VIEW vHoldingValueHistory DROP VIEW vErroneousPrices_Intraday DROP VIEW vErroneousPrices_Daily DROP VIEW vHolding +DROP VIEW vCashBalances DROP FUNCTION dbo.fn_GetExchangeRate DROP FUNCTION dbo.fn_GetPriceAtDate DROP PROCEDURE usp_SwapDisplayOrder @@ -24,10 +26,12 @@ DROP PROCEDURE usp_GetInstruments DROP TYPE PriceDataType DROP TABLE Holding DROP TABLE Account +DROP TABLE AccountHolder DROP TABLE InstrumentHistory_Daily DROP TABLE InstrumentHistory_Intraday DROP TABLE Instrument DROP TABLE TotalHoldingsHistory_Daily +DROP TABLE AllDays --DROP TABLE Exchange */ GO @@ -56,6 +60,24 @@ INSERT Exchange (ShortName, FullName) GO */ +CREATE TABLE AllDays ( + DT date NOT NULL, + CONSTRAINT PK_AllDays PRIMARY KEY CLUSTERED (DT) +) +GO + +CREATE TABLE PriceSource ( + PriceSourceID tinyint IDENTITY NOT NULL, + PriceSourceName varchar(30) NOT NULL, + CONSTRAINT PK_PriceSource PRIMARY KEY CLUSTERED (PriceSourceID), + CONSTRAINT UC_PriceSource UNIQUE NONCLUSTERED (PriceSourceName) +) +GO +INSERT PriceSource (PriceSourceName) VALUES + ('Yahoo Finance UK'), + ('London Stock Exchange') +GO + CREATE TABLE Instrument ( InstrumentID smallint IDENTITY NOT NULL, --ExchangeID tinyint NOT NULL, @@ -66,6 +88,8 @@ CREATE TABLE Instrument ( PostPandemicDilution money NOT NULL, GMTOffset INT NULL, Currency VARCHAR(3) NULL, + TrackPriceHistory BIT NOT NULL, + PriceSourceID tinyint NOT NULL, --CurrentPrice money NULL, CurrentPrice real NULL, InstrumentType VARCHAR(15) NULL, @@ -76,9 +100,11 @@ CREATE TABLE Instrument ( LastUpdated datetime NULL, CONSTRAINT PK_Instrument PRIMARY KEY CLUSTERED (InstrumentID), CONSTRAINT UC_Instrument_Symbol UNIQUE NONCLUSTERED (Symbol), + CONSTRAINT FK_Instrument_PriceSource FOREIGN KEY (PriceSourceID) REFERENCES PriceSource (PriceSourceID), --CONSTRAINT FK_Instrument_Exchange FOREIGN KEY (ExchangeID) REFERENCES Exchange (ExchangeID) ) GO + --CREATE NONCLUSTERED INDEX IDX_Instrument_ExchangeID_Symbol ON Instrument (ExchangeID, Symbol) --CREATE NONCLUSTERED INDEX IDX_Instrument_Symbol ON Instrument (Symbol) CREATE NONCLUSTERED INDEX IDX_Instrument_DisplayOrder ON Instrument (DisplayOrder) @@ -118,11 +144,24 @@ CREATE TABLE InstrumentHistory_Intraday ( ) GO +CREATE TABLE AccountHolder ( + AccountHolderID tinyint IDENTITY NOT NULL, + Name varchar(10) NOT NULL, + CONSTRAINT PK_AccountHolder PRIMARY KEY CLUSTERED (AccountHolderID), + CONSTRAINT UC_AccountHolder UNIQUE NONCLUSTERED (Name) +) +GO +INSERT AccountHolder (Name) VALUES ('Steve'), ('Steph') +GO + CREATE TABLE Account ( AccountID tinyint IDENTITY NOT NULL, + AccountHolderID tinyint NOT NULL, ShortName varchar(20) NOT NULL, + IsTaxable bit NOT NULL, CONSTRAINT PK_Account PRIMARY KEY CLUSTERED (AccountID), - CONSTRAINT UC_Account_ShortName UNIQUE NONCLUSTERED (ShortName) + CONSTRAINT UC_Account_ShortName UNIQUE NONCLUSTERED (ShortName), + CONSTRAINT FK_Account_AccountHolder FOREIGN KEY (AccountHolderID) REFERENCES AccountHolder (AccountHolderID) ) GO INSERT Account (ShortName) VALUES @@ -151,6 +190,8 @@ CREATE TABLE Holding ( --ActualExchangeRate real NULL, ActualExchangeRate numeric(36, 12) NULL, PurchaseDate datetime NOT NULL, + PurchaseCurrencyID smallint NULL, + BookCostInPurchaseCurrency numeric(36, 12) NULL, SoldDate datetime NULL, SoldCurrencyID smallint NULL, SoldProceeds numeric(36, 12) NULL, @@ -161,6 +202,128 @@ CREATE TABLE Holding ( ) GO +CREATE TABLE TradeActionType ( + ActionType VARCHAR(10) NOT NULL, + CONSTRAINT PK_TradeActionType PRIMARY KEY CLUSTERED (ActionType) +) +GO +INSERT TradeActionType VALUES ('Buy'), ('Sell'), ('Transfer'), ('Split') +GO + +CREATE TABLE TradeLedger ( + TradeLedgerID INT IDENTITY NOT NULL, + InstrumentID SMALLINT NOT NULL, + AccountID TINYINT NOT NULL, + TradeDT datetime NOT NULL, + ActionType VARCHAR(10) NOT NULL, + NoUnits NUMERIC(36, 12) NOT NULL, + TradeCurrencyID SMALLINT NOT NULL, + ActualExchangeRate NUMERIC(36, 12) NULL, + EstimatedExchangeRate NUMERIC(36, 12) NULL, + TradeValue MONEY NOT NULL, + TradeValueGBP MONEY NOT NULL, + --NewPoolNoUnits NUMERIC(36, 12) NOT NULL, + --NewPoolCostBaseGBP MONEY NOT NULL, + Notes VARCHAR(1000) NULL, + CONSTRAINT PK_TradeLedger PRIMARY KEY CLUSTERED (TradeLedgerID), + CONSTRAINT FK_TradeLedger_Instrument FOREIGN KEY (InstrumentID) REFERENCES Instrument (InstrumentID), + CONSTRAINT FK_TradeLedger_TradeActionType FOREIGN KEY (ActionType) REFERENCES TradeActionType (ActionType), + CONSTRAINT FK_TradeLedger_TradeCurrency FOREIGN KEY (TradeCurrencyID) REFERENCES Instrument (InstrumentID), + CONSTRAINT UC_TradeLedger UNIQUE NONCLUSTERED (InstrumentID, AccountID, TradeDT) +) +GO + +/* +UPDATE ShareTrades_Steph_XLS SET Account = CASE Account WHEN 'AJ Bell' THEN 'Steph AJB' +WHEN 'AJ Bell - ISA' THEN 'Steph AJB ISA' +WHEN 'Hargreaves Lansdown' THEN 'Steph HL Trd' +WHEN 'Interactive Investor - ISA' THEN 'Steph ii ISA' +WHEN 'Interactive Investor - Trading Account' THEN 'Steph ii Trd' +ELSE Account END + +UPDATE ShareTrades_Steve_XLS SET Account = CASE Account WHEN 'AJ Bell' THEN 'Steve AJB' +WHEN 'AJ Bell - ISA' THEN 'Steve AJB ISA' +WHEN 'Hargreaves Lansdown - Trading Account' THEN 'Steve HL Trd' +WHEN 'Hargreaves Lansdown - ISA' THEN 'Steve HL ISA' +WHEN 'Interactive Investor - ISA' THEN 'Steve ii ISA' +WHEN 'Interactive Investor - Trading Account' THEN 'Steve ii Trd' +ELSE Account END + +INSERT TradeLedger ( + [InstrumentID], + [AccountID], + [TradeDT], + [ActionType], + [NoUnits], + [TradeCurrencyID], + [ActualExchangeRate], + [EstimatedExchangeRate], + [TradeValue], + [TradeValueGBP], + [Notes] +) +SELECT + InstrumentID, + a.AccountID, + [Transaction Date (UK time)], + [Buy or Sell], + [No Units], + (SELECT InstrumentID FROM Instrument WHERE Currency = [Settlement Currency] AND InstrumentType = 'CURRENCY'), + CASE WHEN [Settlement Currency] = 'GBP' THEN 1 ELSE NULL END, + CASE WHEN [Settlement Currency] = 'GBP' THEN NULL ELSE dbo.fn_GetExchangeRate([Settlement Currency], [Transaction Date (UK time)]) END, + [Transaction Total], + ROUND([Transaction Total] / CASE WHEN [Settlement Currency] = 'GBP' THEN 1 ELSE dbo.fn_GetExchangeRate([Settlement Currency], [Transaction Date (UK time)]) END, 2), + Notes + ISNULL(' - [' + F9 + ']', '') +FROM + ShareTrades_Steph_XLS x + LEFT OUTER JOIN Account a + ON a.ShortName = x.Account +WHERE + [Buy or Sell] IN ('Buy', 'Sell') +ORDER BY [Transaction Date (UK time)] + +INSERT TradeLedger ( + [InstrumentID], + [AccountID], + [TradeDT], + [ActionType], + [NoUnits], + [TradeCurrencyID], + [ActualExchangeRate], + [EstimatedExchangeRate], + [TradeValue], + [TradeValueGBP], + [Notes] +) +SELECT + InstrumentID, + a.AccountID, + [Transaction Date (UK time)], + [Buy or Sell], + [No Units], + (SELECT InstrumentID FROM Instrument WHERE Currency = [Settlement Currency] AND InstrumentType = 'CURRENCY'), + CASE WHEN [Settlement Currency] = 'GBP' THEN 1 ELSE NULL END, + CASE WHEN [Settlement Currency] = 'GBP' THEN NULL ELSE dbo.fn_GetExchangeRate([Settlement Currency], [Transaction Date (UK time)]) END, + [Transaction Total], + ROUND([Transaction Total] / CASE WHEN [Settlement Currency] = 'GBP' THEN 1 ELSE dbo.fn_GetExchangeRate([Settlement Currency], [Transaction Date (UK time)]) END, 2), + Notes + ISNULL(' - [' + F9 + ']', '') +FROM + ShareTrades_Steve_XLS x + LEFT OUTER JOIN Account a + ON a.ShortName = x.Account +WHERE + [Buy or Sell] IN ('Buy', 'Sell') +ORDER BY [Transaction Date (UK time)] +GO +*/ + +/* +SELECT * FROM Account +SELECT * FROM Instrument WHERE symbol IN ('LMI3.L', '2BRK.L') +87 LMI3.L +93 2BRK.L +*/ + CREATE TABLE TotalHoldingsHistory_Daily ( HistoryDate date NOT NULL, [Open] int NOT NULL, @@ -188,18 +351,18 @@ GO GRANT EXECUTE ON TYPE::PriceDataType TO WebApp_Role GO -CREATE FUNCTION dbo.fn_GetExchangeRate(@Currency VARCHAR(3), @DT DATETIME) +CREATE OR ALTER FUNCTION dbo.fn_GetExchangeRate(@Currency VARCHAR(3), @DT DATETIME) RETURNS REAL AS BEGIN DECLARE @Rate REAL - IF @Currency = 'GBp' COLLATE Latin1_General_CS_AS + IF @Currency COLLATE Latin1_General_CS_AS = 'GBp' COLLATE Latin1_General_CS_AS BEGIN SET @Rate = 100 END ELSE BEGIN - IF @Currency = 'GBP' COLLATE Latin1_General_CS_AS + IF @Currency COLLATE Latin1_General_CS_AS = 'GBP' COLLATE Latin1_General_CS_AS BEGIN SET @Rate = 1 END @@ -247,7 +410,7 @@ BEGIN END GO -CREATE FUNCTION dbo.fn_GetPriceAtDate(@InstrumentID INT, @DT DATETIME) +CREATE OR ALTER FUNCTION dbo.fn_GetPriceAtDate(@InstrumentID INT, @DT DATETIME) RETURNS REAL AS BEGIN @@ -289,7 +452,7 @@ END GO --CREATE PROCEDURE usp_InsertInstrument (@ExchangeShortName varchar(10), @Symbol varchar(7), @FullName varchar(100)) -CREATE PROCEDURE usp_InsertInstrument (@Symbol varchar(8), @FullName varchar(100)) +CREATE OR ALTER PROCEDURE usp_InsertInstrument (@Symbol varchar(8), @FullName varchar(100)) AS BEGIN SET NOCOUNT ON @@ -301,8 +464,9 @@ BEGIN SELECT @DisplayOrder = ISNULL(@DisplayOrder, 1) --INSERT Instrument (ExchangeID, Symbol, FullName, DisplayOrder) SELECT @ExchangeID, @Symbol, @FullName, @DisplayOrder WHERE NOT EXISTS (SELECT NULL FROM Instrument WHERE ExchangeID = @ExchangeID AND Symbol = @Symbol) - INSERT Instrument (Symbol, FullName, DisplayOrder, PostPandemicDilution) SELECT @Symbol, @FullName, @DisplayOrder, 1 - SELECT + INSERT Instrument (Symbol, FullName, DisplayOrder, PostPandemicDilution, PriceSourceID, TrackPriceHistory) SELECT @Symbol, @FullName, @DisplayOrder, 1, 1, 1 + + SELECT i.DisplayOrder, i.FullName as [InstrumentName], i.Symbol as [Symbol], @@ -363,7 +527,7 @@ delete Instrument where InstrumentID>31 */ --CREATE PROCEDURE usp_UpdateInstrument (@Symbol varchar(8), @GMTOffset int, @Currency varchar(3), @CurrentPrice money, @InstrumentType varchar(15), @TradeDayStart datetime, @TradeDayEnd datetime) -CREATE PROCEDURE usp_UpdateInstrument (@Symbol varchar(8), @GMTOffset int, @Currency varchar(3), @CurrentPrice real, @InstrumentType varchar(15), @TradeDayStart datetime, @TradeDayEnd datetime) +CREATE OR ALTER PROCEDURE usp_UpdateInstrument (@Symbol varchar(8), @GMTOffset int, @Currency varchar(3), @CurrentPrice real, @InstrumentType varchar(15), @TradeDayStart datetime, @TradeDayEnd datetime) AS BEGIN SET NOCOUNT ON @@ -389,7 +553,7 @@ GO GRANT EXECUTE ON usp_UpdateInstrument TO WebApp_Role GO -CREATE PROCEDURE usp_GetAccounts +CREATE OR ALTER PROCEDURE usp_GetAccounts AS BEGIN SET NOCOUNT ON @@ -405,7 +569,7 @@ GO GRANT EXECUTE ON usp_GetAccounts TO WebApp_Role GO -CREATE PROCEDURE usp_GetInstruments +CREATE OR ALTER PROCEDURE usp_GetInstruments AS BEGIN SET NOCOUNT ON @@ -418,6 +582,8 @@ BEGIN [PostPandemicDilution], [GMTOffset], [Currency], + CASE [TrackPriceHistory] WHEN 1 THEN 1 ELSE 0 END as [TrackPriceHistory], --Javascript doesn't like True/False + [PriceSourceName] as [PriceSource], [CurrentPrice], [InstrumentType], [ShowInMarquee], @@ -440,6 +606,8 @@ BEGIN i.PostPandemicDilution as [PostPandemicDilution], i.GMTOffset as [GMTOffset], i.Currency as [Currency], + i.TrackPriceHistory as [TrackPriceHistory], + ps.PriceSourceName as [PriceSourceName], i.CurrentPrice as [CurrentPrice], i.InstrumentType as [InstrumentType], i.ShowInMarquee as [ShowInMarquee], @@ -452,7 +620,9 @@ BEGIN ISNULL((SELECT MAX(id.HistoryDT) FROM InstrumentHistory_Intraday id WHERE id.InstrumentID = i.InstrumentID), CONVERT(DATETIME, '1970-01-01')) as [MaxIntradayDate], (SELECT MAX(h.SoldDate) FROM Holding h WHERE h.InstrumentID = i.InstrumentID AND h.SoldDate IS NOT NULL) as [LastSoldDate] FROM - Instrument i) as dt + Instrument i + INNER JOIN PriceSource ps + ON ps.PriceSourceID = i.PriceSourceID) as dt ORDER BY DisplayOrder END @@ -460,7 +630,7 @@ GO GRANT EXECUTE ON usp_GetInstruments TO WebApp_Role GO -CREATE PROCEDURE usp_GetDailyData (@Symbol varchar(8), @StartDate datetime, @EndDate datetime) +CREATE OR ALTER PROCEDURE usp_GetDailyData (@Symbol varchar(8), @StartDate datetime, @EndDate datetime) AS BEGIN SELECT @@ -485,7 +655,7 @@ GO GRANT EXECUTE ON usp_GetDailyData TO WebApp_Role GO -CREATE PROCEDURE usp_GetIntradayData (@Symbol varchar(8), @StartDate datetime, @EndDate datetime) +CREATE OR ALTER PROCEDURE usp_GetIntradayData (@Symbol varchar(8), @StartDate datetime, @EndDate datetime) AS BEGIN DECLARE @MAX_DAYS INT = 30 @@ -517,7 +687,7 @@ GO GRANT EXECUTE ON usp_GetIntradayData TO WebApp_Role GO -CREATE PROCEDURE usp_InsertDailyData (@Symbol varchar(8), @PriceData PriceDataType READONLY) +CREATE OR ALTER PROCEDURE usp_InsertDailyData (@Symbol varchar(8), @PriceData PriceDataType READONLY) AS BEGIN SET NOCOUNT ON @@ -581,7 +751,7 @@ GO GRANT EXECUTE ON usp_InsertDailyData TO WebApp_Role GO -CREATE PROCEDURE usp_InsertIntradayData (@Symbol varchar(8), @PriceData PriceDataType READONLY) +CREATE OR ALTER PROCEDURE usp_InsertIntradayData (@Symbol varchar(8), @PriceData PriceDataType READONLY) AS BEGIN SET NOCOUNT ON @@ -644,7 +814,7 @@ GRANT EXECUTE ON usp_InsertIntradayData TO WebApp_Role GO --CREATE PROCEDURE usp_InsertHolding (@Account varchar(20), @Symbol varchar(8), @NoUnits int, @PurchasePricePerUnit money, @PurchaseDate datetime, @Solddate datetime = NULL) -CREATE PROCEDURE usp_InsertHolding (@Account varchar(20), @Symbol varchar(8), @NoUnits real, @PurchasePricePerUnit real, @PurchaseDate datetime, @Solddate datetime = NULL) +CREATE OR ALTER PROCEDURE usp_InsertHolding (@Account varchar(20), @Symbol varchar(8), @NoUnits real, @PurchasePricePerUnit real, @PurchaseDate datetime, @PurchaseCurrency varchar(8), @BookCostInPurchaseCurrency numeric(36, 12), @Solddate datetime = NULL) AS BEGIN DECLARE @AccountID tinyint @@ -660,6 +830,8 @@ BEGIN NoUnits, PurchasePricePerUnit, PurchaseDate, + PurchaseCurrencyID, + BookCostInPurchaseCurrency, SoldDate) SELECT @AccountID, @@ -667,6 +839,8 @@ BEGIN @NoUnits, @PurchasePricePerUnit, @PurchaseDate, + (SELECT InstrumentID FROM Instrument WHERE Symbol = @PurchaseCurrency), + @BookCostInPurchaseCurrency, @SoldDate SELECT @@ -760,7 +934,7 @@ GO -- EXEC usp_InsertHolding 'Steve ii Trd', 'ARB.L', 11459, 261.7805, '2021-03-01 11:25', NULL GO -CREATE PROCEDURE usp_GetHoldings +CREATE OR ALTER PROCEDURE usp_GetHoldings AS BEGIN SELECT @@ -791,7 +965,7 @@ GO GRANT EXECUTE ON usp_GetHoldings TO WebApp_Role GO -CREATE PROCEDURE usp_GetHoldingsHistory +CREATE OR ALTER PROCEDURE usp_GetHoldingsHistory AS BEGIN DECLARE @Dates TABLE (InstrumentID int, DT datetime) @@ -843,7 +1017,7 @@ GO GRANT EXECUTE ON usp_DeleteHolding TO WebApp_Role GO */ -CREATE PROCEDURE usp_SoldHolding (@HoldingID int, @SoldDate datetime, @SoldCurrency varchar(8), @SoldProceeds numeric(36, 12)) +CREATE OR ALTER PROCEDURE usp_SoldHolding (@HoldingID int, @SoldDate datetime, @SoldCurrency varchar(8), @SoldProceeds numeric(36, 12)) AS BEGIN UPDATE @@ -861,7 +1035,7 @@ GO GRANT EXECUTE ON usp_SoldHolding TO WebApp_Role GO -CREATE PROCEDURE usp_SetAccountCashValue (@AccountName varchar(20), @Currency varchar(8), @Value numeric(36, 12)) +CREATE OR ALTER PROCEDURE usp_SetAccountCashValue (@AccountName varchar(20), @Currency varchar(8), @Value numeric(36, 12)) AS BEGIN DECLARE @AccountID int @@ -921,7 +1095,7 @@ GO GRANT EXECUTE ON usp_SetAccountCashValue TO WebApp_Role GO -CREATE PROCEDURE usp_SwapDisplayOrder (@Symbol1 varchar(8), @Symbol2 varchar(8)) +CREATE OR ALTER PROCEDURE usp_SwapDisplayOrder (@Symbol1 varchar(8), @Symbol2 varchar(8)) AS BEGIN DECLARE @OldDisplayOrder1 TINYINT @@ -950,13 +1124,24 @@ GO GRANT EXECUTE ON usp_SwapDisplayOrder TO WebApp_Role GO -CREATE PROCEDURE usp_SetTotalHoldingsValue (@TotalValueGBP money) +CREATE OR ALTER PROCEDURE usp_SetTotalHoldingsValue (@TotalValueGBP money) AS BEGIN DECLARE @Rounded INT = CONVERT(int, FLOOR(@TotalValueGBP)) DECLARE @EndOfPreviousWeek DATE = DATEADD(day, 1 - DATEPART(weekday, CURRENT_TIMESTAMP), convert(date, CURRENT_TIMESTAMP)) DECLARE @PreviousDay DATE = DATEADD(day, -1, CONVERT(DATE, CURRENT_TIMESTAMP)) + --Maintain the AllDays table + ;WITH cteAllDays AS + (SELECT CONVERT(datetime, CONVERT(date, MIN(PurchaseDate))) as DT FROM Holding + UNION ALL + SELECT DATEADD(day, 1, DT) + FROM cteAllDays + WHERE DATEADD(day, 1, DT) <= CONVERT(date, CURRENT_TIMESTAMP) + ) + INSERT AllDays (DT) SELECT DT FROM cteAllDays c WHERE c.DT > (SELECT MAX(DT) FROM AllDays) AND c.DT <= CURRENT_TIMESTAMP OPTION (MAXRECURSION 20000) + + IF DATENAME(WEEKDAY, CURRENT_TIMESTAMP) NOT IN ('Saturday', 'Sunday') BEGIN IF EXISTS (SELECT NULL FROM TotalHoldingsHistory_Daily WHERE HistoryDate = CONVERT(date, CURRENT_TIMESTAMP)) @@ -1003,7 +1188,7 @@ GO GRANT EXECUTE ON usp_SetTotalHoldingsValue TO WebApp_Role GO -CREATE PROCEDURE usp_GetTotalHoldingsHistory +CREATE OR ALTER PROCEDURE usp_GetTotalHoldingsHistory AS BEGIN SELECT @@ -1021,7 +1206,7 @@ GO GRANT EXECUTE ON usp_GetTotalHoldingsHistory TO WebApp_Role GO -CREATE VIEW vHolding +CREATE OR ALTER VIEW vHolding AS SELECT h.HoldingID, @@ -1042,7 +1227,30 @@ AS ON a.AccountID = h.AccountID GO -CREATE VIEW vErroneousPrices_Daily +CREATE OR ALTER VIEW vCashBalances +AS +SELECT + a.AccountID, + h.HoldingID, + a.ShortName as [AccoutName], + i.Symbol, + h.NoUnits, + --i.DisplayName as [InstrumentName], + --i.CurrentPrice, + --h.NoUnits, + h.NoUnits * i.CurrentPrice as [Balance] +FROM + Holding h + INNER JOIN Instrument i + ON i.InstrumentID = h.InstrumentID + INNER JOIN Account a + ON a.AccountID = h.AccountID +WHERE + i.InstrumentType = 'CURRENCY' + AND h.SoldDate IS NULL +GO + +CREATE OR ALTER VIEW vErroneousPrices_Daily AS SELECT i.InstrumentID, @@ -1080,7 +1288,7 @@ WHERE OR (p.ClosePrice/CASE WHEN d1.ClosePrice = 0 THEN 0.0000001 ELSE d1.ClosePrice END > 90 AND n.ClosePrice/CASE WHEN d1.ClosePrice = 0 THEN 0.0000001 ELSE d1.ClosePrice END > 90) GO -CREATE VIEW vErroneousPrices_Intraday +CREATE OR ALTER VIEW vErroneousPrices_Intraday AS SELECT i.InstrumentID, @@ -1118,7 +1326,7 @@ WHERE OR (p.ClosePrice/CASE WHEN d1.ClosePrice = 0 THEN 0.0000001 ELSE d1.ClosePrice END > 90 AND n.ClosePrice/CASE WHEN d1.ClosePrice = 0 THEN 0.0000001 ELSE d1.ClosePrice END > 90) GO -CREATE VIEW vDataQuality_Prices +CREATE OR ALTER VIEW vDataQuality_Prices AS SELECT i.InstrumentID, @@ -1151,7 +1359,169 @@ FROM AND n.HistoryDT = (SELECT MIN(HistoryDT) FROM InstrumentHistory_Daily WHERE InstrumentID = d1.InstrumentID AND HistoryDT > d1.HistoryDT) GO +CREATE OR ALTER VIEW vHoldingValueHistory +AS +SELECT + hist.HoldingID, + a.ShortName as [AccountName], + i.Symbol, + i.Currency, + i.FullName as [InstrumentName], + h.PurchaseDate, + h.PurchasePricePerUnit * h.NoUnits as [CostBase], + (h.PurchasePricePerUnit * h.NoUnits) / dbo.fn_GetExchangeRate(Currency, DT) as [CostBaseGBP], + h.SoldDate, + DT as [ValuationDate], + h.NoUnits * dbo.fn_GetPriceAtDate(h.InstrumentID, DT) as [Value], + (h.NoUnits * dbo.fn_GetPriceAtDate(h.InstrumentID, DT) / dbo.fn_GetExchangeRate(Currency, DT)) as [ValueGBP], + h.NoUnits * dbo.fn_GetPriceAtDate(h.InstrumentID, DT) - (h.PurchasePricePerUnit * h.NoUnits) as [Gain], + (h.NoUnits * dbo.fn_GetPriceAtDate(h.InstrumentID, DT) - (h.PurchasePricePerUnit * h.NoUnits)) / dbo.fn_GetExchangeRate(Currency, DT) as [GainGBP] +FROM ( + SELECT + HoldingID, + PurchaseDate as DT + FROM + Holding + UNION + SELECT + HoldingID, + ISNULL(SoldDate, CURRENT_TIMESTAMP) as DT + FROM + Holding + UNION + SELECT + HoldingID, + DT + FROM + Holding h + INNER JOIN allDays d + ON d.DT >= h.PurchaseDate + AND d.DT <= ISNULL(h.SoldDate, CURRENT_TIMESTAMP)) as hist + INNER JOIN Holding h + ON h.HoldingID = hist.HoldingID + INNER JOIN Account a + ON a.AccountID = h.AccountID + INNER JOIN Instrument i + ON i.InstrumentID = h.InstrumentID +GO + +CREATE OR ALTER VIEW vTradeLedger +AS +SELECT + ah.Name + ' - ' + CASE WHEN a.IsTaxable = 0 THEN 'Non-' ELSE '' END + 'Taxable' as [TaxBucket], + a.ShortName as [AccountName], + a.IsTaxable, + i.Symbol, + --ah.Name + ' - ' + CASE WHEN a.IsTaxable = 0 THEN 'Non-' ELSE '' END + 'Taxable' + '|' + i.Symbol as [InvestmentGroup], + DENSE_RANK() OVER (PARTITION BY a.AccountHolderID, a.IsTaxable, l.InstrumentID ORDER BY TradeDT) as [InvestmentPoolOrder], + i.FullName as [Instrument], + i.DisplayName as [InstrumentDisplayName], + i.Currency as [InstrumentCurrency], + --l.[TradeLedgerID], + l.[InstrumentID], + --l.[AccountID], + l.[TradeDT], + l.[ActionType], + l.[NoUnits], + --l.[TradeCurrencyID], + --l.[ActualExchangeRate], + --l.[EstimatedExchangeRate], + --l.[TradeValue], + l.[TradeValueGBP], + l.[Notes] +FROM + TradeLedger l + INNER JOIN Account a + ON a.AccountID = l.AccountID + INNER JOIN AccountHolder ah + ON ah.AccountHolderID = a.AccountHolderID + INNER JOIN Instrument i + ON i.InstrumentID = l.InstrumentID + INNER JOIN Instrument tc + ON tc.InstrumentID = l.TradeCurrencyID +GO + +CREATE OR ALTER VIEW vTradeHistory +AS +WITH cteInvestmentPoolHistory AS ( + SELECT + l.*, + l.NoUnits as [NewPoolTotalUnits], + l.TradeValueGBP as [NewPoolBaseCostGBP], + CAST(0 as MONEY) as [RealisedGainGBP] + FROM + vTradeLedger l + WHERE + InvestmentPoolOrder = 1 + UNION ALL + SELECT + l.*, + CAST(IIF(l.ActionType = 'Sell', c.NewPoolTotalUnits - l.NoUnits, c.NewPoolTotalUnits + l.NoUnits) as NUMERIC(36, 12)) as [NewPoolTotalUnits], + CASE l.ActionType + WHEN 'Sell' THEN CAST((1 - (l.NoUnits / c.NewPoolTotalUnits)) * c.NewPoolBaseCostGBP as MONEY) --The proportion of units remaining * previous avg cost base + WHEN 'Transfer' THEN IIF(l.NoUnits < 0, c.NewPoolBaseCostGBP - l.TradeValueGBP, c.NewPoolBaseCostGBP + l.TradeValueGBP) --Invert TradeValueGBP for transfers OUT + ELSE c.NewPoolBaseCostGBP + l.TradeValueGBP + END as [NewPoolBaseCostGBP], + CASE + WHEN l.ActionType = 'Sell' THEN CAST(l.TradeValueGBP - ((l.NoUnits / c.NewPoolTotalUnits) * c.NewPoolBaseCostGBP) as MONEY) --Trade Value - (The proportion of units sold * previous avg cost base) + ELSE 0 + END as [RealisedGainGBP] + FROM + vTradeLedger l + INNER JOIN cteInvestmentPoolHistory c + ON c.TaxBucket = l.TaxBucket + AND c.Symbol = l.Symbol + AND c.InvestmentPoolOrder = l.InvestmentPoolOrder - 1 + ) +SELECT + *, + CAST(IIF(EXISTS (SELECT 1 FROM cteInvestmentPoolHistory n WHERE n.TaxBucket = c.TaxBucket AND n.Instrument = c.Instrument AND n.InvestmentPoolOrder > c.InvestmentPoolOrder), 0, 1) as BIT) as [IsFinalPosition] +FROM + cteInvestmentPoolHistory c +GO + /* +SELECT + Symbol, + Currency, + ValuationDate, + SUM(CostBase) as [TotalCostBase], + SUM(Value) as [TotalValue], + SUM(Gain) as [Gain] +FROM vHoldingValueHistory +--WHERE HoldingID = 169 +WHERE Symbol = 'LMI3.L' +GROUP BY + Symbol, + Currency, + ValuationDate +ORDER BY Symbol, ValuationDate + +SELECT + ValuationDate, + SUM(CostBaseGBP) as CostBase, + SUM(ValueGBP) as Value, + SUM(GainGBP) as Gain +FROM vHoldingValueHistory +WHERE ValuationDate >= '2024-02-01' +AND CONVERT(varchar(30), ValuationDate, 120) LIKE '%00:00:00%' +GROUP BY + ValuationDate +ORDER BY ValuationDate + +SELECT + --Currency COLLATE Latin1_General_CS_AS, + ValuationDate, + --dbo.fn_GetExchangeRate(Currency, ValuationDate), + --CostBase / dbo.fn_GetExchangeRate(Currency, ValuationDate) as CostBaseGBP, + SUM(CostBase) as [TotalCostBase], + SUM(CostBase) / dbo.fn_GetExchangeRate(Currency, ValuationDate) as [TotalCostBaseGBP], + SUM(Value) as [TotalValue], + SUM(Value) / dbo.fn_GetExchangeRate(Currency, ValuationDate) as [TotalValueGBP], + SUM(Gain) / dbo.fn_GetExchangeRate(Currency, ValuationDate) as [Gain] +FROM vHoldingValueHistory +WHERE ValuationDate = '2024-02-24 00:00:00' +GROUP BY ValuationDate select * from Instrument diff --git a/Websites/SharePrices/SharePrices/SharePrices.aspx b/Websites/SharePrices/SharePrices/SharePrices.aspx index 5639bd9..3189cc8 100644 --- a/Websites/SharePrices/SharePrices/SharePrices.aspx +++ b/Websites/SharePrices/SharePrices/SharePrices.aspx @@ -39,7 +39,7 @@ Charts Holdings - Accounts + Accounts Analysis History Log @@ -94,8 +94,11 @@
-
-
+
+
+ +
+
@@ -119,7 +122,7 @@