initial commit

This commit is contained in:
Peter Wood
2022-07-15 15:37:20 -04:00
parent 70a85b6024
commit 27e7c7829c
13 changed files with 249 additions and 0 deletions

2
.gitignore vendored Normal file
View File

@@ -0,0 +1,2 @@
.vs/*
budget.sqlproj

View File

@@ -0,0 +1,52 @@
use Leo
go
alter function dbo.fn_GetHoliday (@date date)
returns varchar(50)
as
begin
declare @s varchar(50)
select @s =
case
when dbo.fn_ShiftHolidayToWorkday(cast(yr as varchar) + '-01-01') = @date
then 'New Year'
when dbo.fn_ShiftHolidayToWorkday(cast(yr + 1 as varchar) + '-01-01') = @date
then 'New Year'
when mn = 1 and DayOfMonth between 15 and 21 and DayName = 'Monday'
then 'Martin Luther King Jr Day'
when mn = 2 and DayOfMonth between 15 and 21 and DayName = 'Monday'
then 'Presidents'' Day'
when mn = 5 and DayOfMonth >= 25 and DayName = 'Monday'
then 'Memorial Day'
when dbo.fn_ShiftHolidayToWorkday(cast(yr as varchar) + '-06-19') = @date
then 'Juneteenth'
when dbo.fn_ShiftHolidayToWorkday(cast(yr as varchar) + '-07-04') = @date
then 'Independence Day'
when mn = 9 and DayOfMonth <= 7 and DayName = 'Monday'
then 'Labor Day'
when dbo.fn_ShiftHolidayToWorkday(cast(yr as varchar) + '-11-11') = @date
then 'Veteran''s Day'
when mn = 10 and DayOfMonth between 8 and 14 and DayName = 'Monday'
then 'Columbus Day'
when mn = 11 and DayOfMonth between 22 and 28 and DayName = 'Thursday'
then 'Thanksgiving Day'
--when mn = 11 and DayOfMonth between 23 and 29 and DayName = 'Friday'
-- then 'Day After Thanksgiving'
when dbo.fn_ShiftHolidayToWorkday(cast(yr as varchar) + '-12-25') = @date
then 'Christmas Day'
--when dbo.fn_ShiftHolidayToWorkday(cast(yr as varchar) + '-12-31') = @date
-- then 'New Years Eve'
else null
end
from (
select
yr = year(@date),
mn = month(@date),
DayOfMonth = day(@date),
DayName = datename(weekday,@date)
) c
return @s
end
go

View File

@@ -0,0 +1,12 @@
use Leo
go
alter function dbo.tvf_BudgetInPeriod (
@str_dt date = null
, @end_dt date = null
) returns table
as return
select Id, TrxDate, TrxDate_ISO8601, TrxDescription, TrxAmount, RunningBal
from dbo.vw_BudgetRunningBalance
where TrxDate between isnull(@str_dt, dateadd(day, 1, eomonth(getDate(), -1))) and isnull(@end_dt, eomonth(getdate()))
go

View File

@@ -0,0 +1,15 @@
use Leo
go
create FUNCTION dbo.tvf_GetHolidays(@year int)
RETURNS TABLE
AS
RETURN (
select dt, dbo.fn_GetHoliday(dt) as Holiday
from (
select dateadd(day, number, convert(varchar,@year) + '-01-01') dt
from master..spt_values
where type='p'
) d
where year(dt) = @year and dbo.fn_GetHoliday(dt) is not null
)

View File

@@ -0,0 +1,16 @@
use Leo
go
create proc dbo.proc_CreateTransaction (
@date date, @description varchar(200), @amount decimal(11,2)
)
as
begin
set @date = isnull(@date, getdate())
insert into dbo.BUDGET_DETAIL (TrxDate, TrxDescription, TrxAmount)
select @date, @description, @amount
select SCOPE_IDENTITY()
end
go

View File

@@ -0,0 +1,18 @@
use Leo
go
alter proc dbo.proc_GetTransactions (
@yr smallint = null, @mo smallint = null
)
as
begin
set @yr = isnull(@yr, year(getdate()))
set @mo = isnull(@mo, month(getdate()))
select Id, TrxDate, TrxDate_ISO8601, TrxDescription, TrxAmount, RunningBal
from dbo.vw_BudgetRunningBalance
where
YEAR(TrxDate) = @yr
and MONTH(TrxDate) = @mo
end
go

View File

@@ -0,0 +1,54 @@
use Leo
go
alter PROCEDURE dbo.proc_MonthlyIncomeExpense (
@p_Year smallint
)
AS
with credit as (
SELECT
det.TrxDate
, ctg.CtgDescription
, det.TrxAmount
, YR=year(det.TrxDate)
, MO=month(det.TrxDate)
FROM
dbo.BUDGET_CATEGORY ctg
JOIN BUDGET_DETAIL det ON ctg.CtgDescription = det.TrxDescription
WHERE
ctg.CtgCredit = 1
and year(det.TrxDate) = @p_Year
)
, debit as (
select
det.TrxDescription
, det.TrxDate
, det.TrxAmount
, YR=year(det.TrxDate)
, MO=month(det.TrxDate)
from
dbo.BUDGET_DETAIL det
left join dbo.BUDGET_CATEGORY ctg on ctg.CtgDescription = det.TrxDescription
where
year(det.TrxDate) = @p_Year
and det.TrxDescription <> 'Initial Balance'
and det.TrxAmount <> 0
and isnull(CtgCredit, 0) = 0
)
select
crd.YR
, crd.MO
, EXPENSES=dbt.TTL
, INCOME=crd.TTL
, TTL=crd.TTL+dbt.TTL
from (
select YR, MO, TTL=sum(credit.TrxAmount) from credit group by YR, MO
) crd
join (
select YR, MO, TTL=sum(debit.TrxAmount) from debit group by YR, MO
) dbt on crd.YR = dbt.YR and crd.MO = dbt.MO
return
go

View File

@@ -0,0 +1,22 @@
use Leo
go
alter proc dbo.proc_UpdateHolidaysTable
as
if not exists(select TABLE_NAME from INFORMATION_SCHEMA.TABLES where TABLE_NAME = 'HOLIDAYS')
create table dbo.HOLIDAYS(dt date primary key clustered, Holiday varchar(50))
declare @year int = 2019
while @year < year(getdate()) + 40
begin
insert into dbo.Holidays(dt, Holiday)
select fhol.dt, fhol.Holiday
from
dbo.tvf_GetHolidays(@year) fhol
left join dbo.Holidays tbh on fhol.dt = tbh.dt
where fhol.dt is null
set @year = @year + 1
end
go

View File

@@ -0,0 +1,14 @@
use Leo
go
if object_id('dbo.BUDGET_CATEGORY', 'U') is not null
drop table dbo.BUDGET_CATEGORY
go
CREATE TABLE dbo.BUDGET_CATEGORY
(
CtgId smallint IDENTITY(1,1) NOT NULL
, CtgDescription varchar(200) NULL
, CtgCredit bit default 0
)
GO

15
tables/BUDGET_DETAIL.sql Normal file
View File

@@ -0,0 +1,15 @@
use Leo
go
if object_id('dbo.BUDGET_DETAIL', 'U') is not null
drop table dbo.BUDGET_DETAIL
go
create table dbo.BUDGET_DETAIL
(
TrxId int identity not null
, TrxDescription varchar(200) not null
, TrxDate date not null
, TrxAmount decimal(9,2)
, InsertDtTm datetime default CURRENT_TIMESTAMP
)

12
tables/HOLIDAYS.sql Normal file
View File

@@ -0,0 +1,12 @@
use Leo
go
CREATE TABLE dbo.HOLIDAYS
(
dt date NOT NULL,
Holiday varchar(50) NULL,
PRIMARY KEY CLUSTERED (
dt ASC
)
)
GO

View File

@@ -0,0 +1,9 @@
use Leo
go
create view dbo.vw_BUDGET_RUNNING_BAL
as
select
BDT_DATE, BDT_DESCRIPTION, BDT_AMOUNT
, sum(BDT_AMOUNT) over(order by BDT_DATE, BDT_AMOUNT desc rows unbounded preceding) RUNNING_BAL
from dbo.BUDGET_DETAIL

View File

@@ -0,0 +1,8 @@
use Leo
go
create view dbo.vw_CURR_MONTH_BUDGET
as
select *
from dbo.vw_BUDGET_RUNNING_BAL
where BDT_DATE between dateadd(DAY, 1, EOMONTH(getDate(), -1)) and eomonth(getDate())