1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
|
-- -*- mode: sql; sql-product: postgres; -*-
CREATE TYPE bond_strat AS ENUM('M_STR_MAV', 'M_STR_SMEZZ', 'CSO_TRANCH',
'M_CLO_BB20', 'M_CLO_AAA', 'M_CLO_BBB', 'M_MTG_IO', 'M_MTG_THRU',
'M_MTG_GOOD', 'M_MTG_B4PR', 'M_MTG_RW');
CREATE TYPE asset_class AS ENUM('CSO', 'Subprime', 'CLO', 'Tranches', 'Futures', 'Cash', 'FX', 'Cleared');
CREATE TYPE action AS ENUM('NEW', 'UPDATE', 'CANCEL');
CREATE TYPE currency AS ENUM('USD', 'CAD', 'EUR', 'YEN');
CREATE TYPE bbg_type AS ENUM('Mtge', 'Corp');
CREATE type day_count AS ENUM('ACT/360', 'ACT/ACT', '30/360', 'ACT/365')
CREATE TABLE counterparties(code varchar(12) primary key,
name text,
city text,
state varchar(2),
location text,
dtc_number integer,
sales_contact text,
sales_email text,
sales_phone text,
valuation_contact1 text,
valuation_email1 text,
valuation_contact2 text,
valuation_email2 text,
valuation_contact3 text,
valuation_email3 text,
valuation_contact3 text,
valuation_email3 text,
valuation_contact4 = text,
valuation_email4 = text,
notes text);
CREATE INDEX ON counterparties(name);
CREATE TABLE bonds(id serial primary key,
deal_id varchar(28),
lastupdate timestamp,
action action,
folder bond_strat,
custodian varchar(12),
cashaccount varchar(10),
cp_code varchar(12) REFERENCES counterparties(code),
trade_date date,
settle_date date,
cusip varchar(9),
isin varchar(12),
description varchar(32),
faceamount float,
price float,
accrued float,
asset_class asset_class,
ticket text,
principal_payment float,
accrued_payment float);
CREATE TABLE securities(identifier varchar(12) PRIMARY KEY,
cusip varchar(9),
isin varchar(12),
description varchar(32),
face_amount float,
maturity date,
floater boolean,
spread float,
coupon float,
frequency smallint,
day_count day_count,
first_coupon_date date,
pay_delay smallint,
currency currency default 'USD',
bbg_type bbg_type default 'Mtge',
asset_class asset_class,
paid_down date default 'Infinity'
start_accrued_date date)
CREATE TABLE marks(date date,
identifier varchar(12) REFERENCES securities(identifier),
price float,
PRIMARY KEY(identifier, date));
CREATE TABLE cashflow_history(
identifier varchar(12) REFERENCES securities,
date date,
principal_bal float,
principal float,
interest float,
coupon float,
PRIMARY KEY (identifier, date));
CREATE TABLE fx(date date PRIMARY KEY,
eurusd float,
cadusd float);
CREATE OR REPLACE function list_marks(p_date date, include_unsettled boolean DEFAULT False)
RETURNS TABLE(identifier varchar(12), price float) AS $$
BEGIN
RETURN QUERY SELECT a.identifier, b.price FROM list_positions(p_date, Null, include_unsettled) a LEFT JOIN
(SELECT DISTINCT ON (identifier) date, marks.identifier, marks.price FROM marks
WHERE date<= p_date ORDER BY identifier, date DESC) b USING (identifier);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE function list_positions(p_date date,
p_class asset_class DEFAULT NULL,
include_unsettled boolean DEFAULT True)
RETURNS TABLE(identifier varchar(12), description varchar(32), notional float, strategy bond_strat,
curr_cpn float, start_accrued_date date, last_settle_date date,
principal_payment float, accrued_payment float, currency currency, daycount day_count,
bbg_type bbg_type) AS $$
DECLARE sqlquery text;
DECLARE asset_opt text;
DECLARE unsettled_opt text;
BEGIN
IF p_class is not NULL THEN
asset_opt := 'and securities.asset_class=$2 ';
ELSE
asset_opt := '';
END IF;
IF include_unsettled THEN
unsettled_opt = 'or settle_date>=$1';
ELSE
unsettled_opt = '';
END IF;
sqlquery := 'WITH temp as (SELECT bonds.identifier, asset_class, settle_date, folder,
principal_payment, accrued_payment, sum(faceamount*(2*buysell::int-1) )
OVER (PARTITION BY bonds.identifier) notional FROM bonds WHERE trade_date<=$1)
SELECT DISTINCT ON (temp.identifier) temp.identifier, securities.description, notional, folder,
securities.coupon, start_accrued_date, settle_date, temp.principal_payment,
temp.accrued_payment, securities.currency, securities.day_count, securities.bbg_type
FROM temp LEFT JOIN securities USING (identifier)
WHERE (temp.notional>0 '||unsettled_opt||') AND paid_down>$1 '||asset_opt
||' ORDER BY identifier, settle_date desc';
RETURN QUERY EXECUTE sqlquery USING p_date, p_class;
END;
$$ LANGUAGE plpgsql;
CREATE MATERIALIZED VIEW factors_history AS
WITH temp AS (
SELECT c.date,
c.identifier,
c.principal,
c.principal_bal,
c.interest,
lead(c.coupon) OVER w AS coupon,
(- c.principal) - c.principal_bal + lag(c.principal_bal) OVER w AS losses
FROM cashflow_history c
WINDOW w AS (PARTITION BY c.identifier ORDER BY c.date)
)
SELECT temp.date AS last_pay_date,
temp.date-securities.pay_delay AS prev_cpn_date,
temp.identifier,
temp.principal_bal / securities.face_amount AS factor,
temp.principal / securities.face_amount * 100::double precision AS principal,
temp.interest / securities.face_amount * 100::double precision AS interest,
temp.losses / securities.face_amount * 100::double precision AS losses,
COALESCE(temp.coupon, securities.coupon) AS coupon
FROM temp
JOIN securities USING (identifier);
CREATE UNIQUE INDEX factors_history_pkey ON factors_history(prev_cpn_date, identifier);
CREATE OR REPLACE function factors_history(p_date date)
RETURNS SETOF factors_history AS $$
BEGIN
RETURN QUERY
SELECT DISTINCT ON (identifier) * FROM factors_history
WHERE prev_cpn_date<=p_date ORDER BY identifier, prev_cpn_date desc;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION isleapyear (
D date
) RETURNS boolean
AS $$
DECLARE
y INTEGER;
BEGIN
y := extract (year from D);
if (y % 4) != 0 then
return false;
end if;
if (y % 400) = 0 then
return true;
end if;
return (( y % 100) != 0);
END;
$$ LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION yearfrac(date1 date, date2 date, daycount day_count)
RETURNS float AS $$
DECLARE
factor float;
y1 integer;
y2 integer;
m1 integer;
m2 integer;
d1 integer;
d2 integer;
BEGIN
IF daycount='30/360' THEN
y1 := extract(YEAR FROM date1);
y2 := extract(YEAR FROM date2);
m1 := extract(MONTH FROM date1);
m2 := extract(MONTH FROM date2);
d1 := extract(DAY FROM date1);
d2 := extract(DAY FROM date2);
IF d2=31 and (d1=30 or d1=31) THEN
d2:=30;
END IF;
IF d1=31 THEN
d1:=30;
END IF;
factor:= (360*(y2-y1) + 30*(m2-m1)+d2-d1)/360.;
ELSIF daycount='ACT/365' THEN
factor:=(date2-date1)/365.;
ELSIF daycount='ACT/360' THEN
factor:=(date2-date1)/360.;
ELSIF daycount='ACT/ACT' THEN
IF isleapyear(date1) THEN
factor:=(date2-date1)/366.;
ELSE
factor:=(date2-date1)/365.;
END IF;
END IF;
RETURN factor;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE function fx_rate(p_date date) RETURNS TABLE(currency currency, fxrate float) AS $$
BEGIN
RETURN QUERY SELECT unnest(Array['USD', 'EUR', 'CAD'])::currency,
unnest(Array[1, eurusd, cadusd]) FROM fx WHERE date=p_date;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE function risk_positions(p_date date, p_assetclass asset_class) RETURNS TABLE
(description varchar(32), identifier varchar(12), notional float, price float,
strategy bond_strat, factor float, local_market_value float, usd_market_value float,
curr_cpn float, int_acc float, last_pay_date date, principal_payment float,
accrued_payment float, last_settle_date date) AS $$
BEGIN
RETURN QUERY
SELECT a.description, a.identifier, a.notional, c.price, a.strategy, coalesce(b.factor, 1),
c.price/100. * a.notional * (CASE WHEN coalesce(b.factor,1)=0 THEN 1 ELSE coalesce(b.factor,1) END),
c.price/100. * a.notional * (CASE WHEN coalesce(b.factor,1)=0 THEN 1 ELSE coalesce(b.factor,1) END) * fxrate,
b.coupon,
a.notional * coalesce(b.factor,1) * fxrate *
yearfrac(case WHEN start_accrued_date>p_date+1 THEN b.prev_cpn_date ELSE start_accrued_date END, p_date+1, daycount) * b.coupon/100.,
b.last_pay_date, a.principal_payment, a.accrued_payment, a.last_settle_date
FROM list_positions(p_date, p_assetclass) a
LEFT JOIN factors_history(p_date) b USING (identifier)
LEFT JOIN list_marks(p_date, True) c USING (identifier)
LEFT JOIN fx_rate(p_date) USING (currency)
ORDER by identifier asc;
END;
$$ LANGUAGE plpgsql;
|