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
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
|
CREATE TABLE tranche_data (
QuoteDate date,
TrancheId integer,
BasketId integer,
Maturity date,
Tenor varchar(4),
RefBasketPrice float,
BPS varchar(1),
BasketDuration float,
TQC varchar(1),
TrancheDuration float,
TrancheDelta float,
CorrAtDetachment float,
Basis float,
QuoteSource varchar(2),
Index varchar(4),
Series smallint,
Upfront float,
Running float,
Attach smallint,
Detach smallint,
IndexFactor float,
CumulativeLoss float
);
GRANT ALL ON tranche_data TO serenitas_user;
CREATE TABLE index_version(
BasketID serial,
Index index_type,
Series smallint,
Version smallint,
IndexFactor float,
CumulativeLoss float,
PRIMARY KEY(BasketID)
);
CREATE TABLE index_maturity(
Index index_type,
series smallint,
tenor tenor,
maturity date,
coupon integer,
PRIMARY KEY(index, series, tenor)
);
CREATE OR REPLACE VIEW index_desc AS
SELECT b.basketid, b.index, b.series, b.version, a.tenor, a.maturity, b.indexfactor, b.cumulativeloss, b.lastdate
FROM index_maturity a
JOIN index_version b ON a.index = b.index AND a.series = b.series;
GRANT ALL ON index_maturity TO serenitas_user;
GRANT ALL ON index_version TO serenitas_user;
GRANT ALL ON index_desc TO serenitas_user;
CREATE TABLE quotes (
QuoteDate timestamp,
Index index_type,
Series smallint,
Version smallint,
tenor tenor,
attach smallint,
detach smallint,
RefBasketPrice float,
Upfront float,
Running float,
BasketDuration float,
TrancheDuration float,
TrancheDelta float,
CorrAtDetachment float,
Basis float,
QuoteSource varchar(4)
);
CREATE TABLE tranche_quotes (
QuoteDate timestamp,
Index index_type,
Series smallint,
Version smallint,
Tenor tenor,
Attach smallint,
Detach smallint,
TrancheUpfrontBid float,
TrancheUpfrontMid float,
TrancheUpfrontAsk float,
TrancheRunningBid float,
TrancheRunningMid float,
TrancheRunningAsk float,
IndexRefPrice real,
IndexRefSpread smallint,
IndexDuration real,
TrancheDuration real,
TrancheDelta real,
CorrAtDetachment real,
Basis real,
QuoteSource varchar(4),
PRIMARY KEY(QuoteDate, Index, Series, Version, Tenor, Attach, Detach, QuoteSource, trancherunningmid)
);
GRANT ALL ON quotes TO serenitas_user;
GRANT ALL ON tranche_quotes TO serenitas_user;
-- Idiosyncracies:
-- for Itraxx 9 index:
-- tr.id coupon type
-- 3-6 98155 all running
-- 98154 U+500
-- 6-9 98160 all running
-- 166395 U+300
-- 98159 U+500
-- For IG 9 index:
-- tr.id coupon type
-- 3-7 162290 all running
-- 162291 U+500
-- 7-10 162298 all running
-- 162300 U+500
-- 10-15 162301 all running
-- 162304 U+500
-- 15-30 162305 all running
-- 162306 U+500
-- 30-100 162307 all running
-- 162308 U+500
-- All other tranches should have a unique trancheid for a given basketid, attach, detach combination
CREATE TYPE curr AS ENUM('USD', 'EUR', 'JPY', 'GBP', 'CAD');
CREATE TYPE sen AS ENUM('Senior', 'Subordinated');
CREATE TYPE tier AS ENUM('SNRFOR', 'SECDOM', 'SUBLT2', 'PREFT1', 'JRSUBUT2');
CREATE TYPE bbgSource AS ENUM('MSG1', 'CBIN', 'CBGN', 'MKIT');
CREATE TYPE DocClause AS ENUM('No Restructuring', 'Modified Modified Restructurin', 'Full Restructuring');
CREATE TYPE tenor AS ENUM('6mo', '1yr', '2yr', '3yr', '4yr', '5yr', '7yr', '10yr');
CREATE TYPE index_type AS ENUM('IG', 'HY', 'EU', 'LCDX', 'XO');
CREATE TABLE CDS_Issuers(
Name text,
company_id integer,
ticker text,
currency curr,
seniority sen,
doc_clause DocClause,
cds_curve text[8] UNIQUE,
index_list integer[],
markit_ticket text,
markit_tier tier,
spread integer,
PRIMARY KEY(company_id));
GRANT ALL ON CDS_Issuers to serenitas_user;
CREATE TABLE bbg_issuers(
Name text,
company_id integer,
ticker text,
currency curr,
seniority sen,
doc_clause DocClause,
cds_curve text[8] UNIQUE,
index_list integer[],
PRIMARY KEY(company_id));
GRANT ALL ON bbg_issuers to serenitas_user;
CREATE TABLE bbg_markit_mapping(
date date,
company_id integer REFERENCES CDS_Issuers,
markit_ticker text,
markit_tier tier,
spread integer,
PRIMARY KEY(company_id, date));
GRANT ALL ON bbg_markit_mapping to serenitas_user;
CREATE TABLE cds_quotes(
Date Date,
curve_ticker text,
UpfrontBid float,
UpfrontAsk float,
RunningBid float,
RunningAsk float,
Source bbgSource,
Recovery float,
PRIMARY KEY(curve_ticker, Date));
GRANT ALL ON cds_quotes to serenitas_user;
CREATE OR REPLACE FUNCTION nameToBasketID(index_name varchar(4), p_date date) RETURNS integer AS $$
DECLARE
p_index index_type;
p_series smallint;
p_basketid integer;
BEGIN
p_index := upper(left(index_name, 2))::index_type;
p_series := right(index_name, -2);
SELECT MIN(basketid) INTO p_basketid FROM index_version WHERE Index=p_index and
Series=p_series and lastdate>=p_date;
RETURN p_basketid;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION index_members(index_name varchar(4), p_date date)
RETURNS SETOF CDS_Issuers AS $$
DECLARE
basketid integer;
BEGIN
SELECT nameToBasketID(index_name, p_date) INTO basketid;
RETURN QUERY SELECT * FROM CDS_Issuers WHERE index_list @> Array[basketid];
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION historical_cds_quotes(date) RETURNS SETOF cds_quotes AS $$
BEGIN
RETURN QUERY SELECT b.*
FROM (SELECT max(c.Date) AS latestdate, c.curve_ticker FROM cds_quotes c
WHERE c.Date<=$1 GROUP BY c.curve_ticker) a
JOIN cds_quotes b ON a.curve_ticker = b.curve_ticker AND a.latestdate=b.Date;
END;
-- simpler query but slower
-- BEGIN
-- RETURN QUERY SELECT DISTINCT ON (curve_ticker) * from cds_quotes where date<=$1 ORDER BY
-- curve_ticker, DATE desc;
-- END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION historical_cds_issuers(date) RETURNS SETOF cds_issuers AS $$
BEGIN
RETURN QUERY SELECT bbg_issuers.*, map.markit_ticker, map.markit_tier, map.spread FROM
(SELECT b.* FROM (SELECT min(c.date) AS latestdate, c.company_id FROM bbg_markit_mapping c
WHERE c.date>=$1 GROUP BY c.company_id) a
JOIN bbg_markit_mapping b ON a.company_id = b.company_id AND a.latestdate=b.date) map
JOIN bbg_issuers USING (company_id);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION curve_quotes(varchar(4), date) RETURNS
TABLE(cds_ticker text, date date, spread_curve float[], upfront_curve float[], recovery_curve float[]) AS $$
BEGIN
RETURN QUERY SELECT max(markit_ticker) AS t, max(a.date),
array_agg((a.runningbid+a.runningask)/2 ORDER BY tenor),
array_agg((a.upfrontbid+a.upfrontask)/2 ORDER BY tenor),
array_agg(a.Recovery ORDER BY tenor) FROM historical_cds_quotes($2) a RIGHT JOIN
(SELECT generate_series(1, 8) AS tenor, unnest(cds_curve) AS curve_ticker, markit_ticker, company_id
FROM index_members($1, $2)) b
ON b.curve_ticker = a.curve_ticker GROUP by company_id ORDER BY t;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION curve_quotes_fmt(varchar(4), date) RETURNS
TABLE(cds_ticker text, date date, spread_curve text, upfront_curve text, recovery_curve text) AS $$
BEGIN
RETURN QUERY SELECT max(markit_ticker) AS t, max(a.date),
string_agg(to_char((a.runningbid+a.runningask)/2, 'FM999'), ',' ORDER BY tenor),
string_agg(to_char((a.upfrontbid+a.upfrontask)/2, 'FM99D99'), ',' ORDER BY tenor),
string_agg(to_char(a.Recovery, 'FM0D99'), ',' ORDER BY tenor) FROM historical_cds_quotes($2) a RIGHT JOIN
(SELECT generate_series(1, 8) AS tenor, unnest(cds_curve) AS curve_ticker, markit_ticker, company_id
FROM index_members($1, $2)) b
ON b.curve_ticker = a.curve_ticker GROUP by company_id ORDER BY t;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE index_quotes(
date date,
index index_type,
series smallint,
version smallint,
tenor tenor,
closeprice float,
closespread float,
modelprice float,
modelpread float,
adjcloseprice float,
adjmodelprice float,
duration float,
theta float,
PRIMARY KEY(date, index, series, tenor));
CREATE OR REPLACE FUNCTION get_tranche_quotes(pg_index_type text, pg_series integer, pg_tenor text,
pg_date date)
RETURNS SETOF tranche_quotes AS
$$
DECLARE r RECORD;
DECLARE indexname text;
DECLARE lower_attach smallint;
DECLARE flag boolean;
BEGIN
indexname := pg_index_type || pg_series;
IF lower(indexname) ='hy9' or lower(indexname) ='hy10'
THEN
lower_attach = 10::smallint;
ELSE
lower_attach = 0::smallint;
END IF;
flag := FALSE;
FOR r in EXECUTE
'SELECT DISTINCT quotesource, quotedate FROM TRANCHE_QUOTES
WHERE index=$1::index_type AND series=$2 AND quotedate::date=$3
AND tenor =$4::tenor ORDER BY quotedate desc'
USING pg_index_type, pg_series, pg_date, pg_tenor LOOP
IF pg_index_type = 'HY' AND pg_series >=15 THEN
EXECUTE
'SELECT array_agg(attach ORDER by attach asc)||100::smallint=$6||array_agg(detach) FROM
tranche_quotes where index=$1::index_type and series=$2 and tenor=$3::tenor
and quotedate=$4 and detach-attach!=5::smallint and quotesource=$5'
INTO flag
USING pg_index_type, pg_series, pg_tenor, r.quotedate, r.quotesource, lower_attach;
IF flag THEN
RETURN QUERY
SELECT * FROM tranche_quotes WHERE index=pg_index_type::index_type AND series= pg_series
AND tenor=pg_tenor::tenor AND quotedate=r.quotedate AND detach-attach!=5::smallint AND
quotesource=r.quotesource ORDER BY attach asc;
RETURN;
END IF;
ELSE
EXECUTE
'SELECT array_agg(attach ORDER BY attach asc)||100::smallint=$6||array_agg(detach) FROM
tranche_quotes where index=$1::index_type and series=$2 and tenor=$3::tenor
and quotedate=$4 and quotesource=$5'
INTO flag
USING pg_index_type, pg_series, pg_tenor, r.quotedate, r.quotesource, lower_attach;
IF flag THEN
RETURN QUERY
SELECT * FROM tranche_quotes WHERE index=pg_index_type::index_type AND series=pg_series
AND tenor=pg_tenor::tenor AND quotedate=r.quotedate AND quotesource=r.quotesource
ORDER BY attach asc;
RETURN;
END IF;
END IF;
END LOOP;
END;
$$ language plpgsql;
CREATE TABLE risk_numbers(
date date,
index index_type,
series integer,
tenor tenor,
indexprice float,
indexbasis float,
indexEL float,
indexduration float,
indextheta float,
attach integer[],
Skew float[],
"Dealer Deltas" float[],
"Model Deltas" float[],
"Forward Deltas" float[],
gammas float[],
thetas float[],
corr01 float[],
durations float[],
el float[],
PRIMARY KEY(date, index, series, tenor));
GRANT ALL ON risk_numbers to serenitas_user;
|