RunningINFORATIO
Updated 2024-03-14 15:05:16.413000
Syntax
SELECT [westclintech].[wct].[RunningINFORATIO](
<@R, float,>
,<@Rb, float,>
,<@Scale, float,>
,<@Prices, bit,>
,<@RowNum, int,>
,<@Id, tinyint,>)
Description
Use the scalar function RunningINFORATIO to calculate the information ratio from column values in an ordered resultant table without the need of a self-join. The information ratio is calculated over all the values from the first value to the last value in the ordered group or partition. If the column values are presented to the function out of order, an error message will be generated.
The information ratio is calculated as the mean difference of the returns and a benchmark return divided by the standard deviation of the differences multiplied by the square root of a scaling factor. For daily returns the scale factor might be 252; for weekly returns 52; for monthly returns 12. The standard deviation is the sample standard deviation.
\operatorname{INFORATIO}=\frac{\bar{R}-\bar{R_b}}{\sigma_{R-R_b}}\ast\sqrt{scale}
Arguments
@Id
a unique identifier for the RunningINFORATIO calculation. @Id allows you to specify multiple information ratios within a resultant table. @Id is an expression of type tinyint or of a type that can be implicitly converted to tinyint.
@Prices
a bit value identifying whether the supplied @R and @Rb values are prices (or portfolio values) or returns. If @Prices is true, then the returns are calculated. @Prices is an expression of type bit or of a type that can be implicitly converted to bit.
@R
the return or price value; if a return value is being supplied, it should be the percentage return in floating point format (i.e. 10% = 0.1). @R is an expression of type float or of a type that can be implicitly converted to float.
@Scale
the scaling factor used in the calculation. @Scale is an expression of type float or of a type that can be implicitly converted to float.
@Rb
the benchmark return or price; if a benchmark return is being supplied, is should be the percentage in floating point format (i.e. 10% = 0.1). @Rb is an expression of type float or of a type that can be implicitly converted to float.
@RowNum
the number of the row within the group for which the information ratio is being calculated. If @RowNum for the current row in a set is less than or equal to the previous @RowNum and @RowNum is not equal to 1, an error message will be generated. @RowNum is an expression of type int or of a type that can be implicitly converted to int.
Return Type
float
Remarks
If @Scale IS NULL then @Scale is set to 12.
If @Prices IS NULL then @Prices is set to 'False'.
Examples
In this example we have 12 months’ worth of return data for and we want to calculate the information ratio.
SELECT CAST(eom as date) as eom,
cast(r as float) as r,
Cast(rb as float) as rb
into #s
FROM
(
VALUES
('2012-01-31', 0.008374, 0.008161),
('2012-02-29', 0.014544, 0.009818),
('2012-03-31', 0.010549, 0.003224),
('2012-04-30', -0.003218, -0.003088),
('2012-05-31', 0.001395, 0.008685),
('2012-06-30', 0.016985, 0.01045),
('2012-07-31', 0.007003, 0.009179),
('2012-08-31', -0.000834, 0.006815),
('2012-09-30', 0.009294, 0.007383),
('2012-10-31', 0.012554, 0.009464),
('2012-11-30', 0.005767, 0.002783),
('2012-12-31', -0.000496, 0.005062)
) n (eom, r, rb);
SELECT EOM,
r,
rb,
wct.RunningINFORATIO( r, --@R
rb, --@Rb
12, --@Scale
'False', --@Prices
ROW_NUMBER() OVER (ORDER BY eom ASC), --@RowNum
NULL --@Id
) as INFO
FROM #s;
DROP TABLE #s;
This produces the following result.
{"columns":[{"field":"EOM","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"r","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"rb","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"INFO"}],"rows":[{"EOM":"2012-01-31","r":"0.008374","rb":"0.008161","INFO":"NULL"},{"EOM":"2012-02-29","r":"0.014544","rb":"0.009818","INFO":"2.68070681134636"},{"EOM":"2012-03-31","r":"0.010549","rb":"0.003224","INFO":"3.9351346757467"},{"EOM":"2012-04-30","r":"-0.003218","rb":"-0.003088","INFO":"2.90540015030581"},{"EOM":"2012-05-31","r":"0.001395","rb":"0.008685","INFO":"0.601537550348331"},{"EOM":"2012-06-30","r":"0.016985","rb":"0.01045","INFO":"1.19816250281277"},{"EOM":"2012-07-31","r":"0.007003","rb":"0.009179","INFO":"0.869687568642996"},{"EOM":"2012-08-31","r":"-0.000834","rb":"0.006815","INFO":"0.116174630261801"},{"EOM":"2012-09-30","r":"0.009294","rb":"0.007383","INFO":"0.244792458708043"},{"EOM":"2012-10-31","r":"0.012554","rb":"0.009464","INFO":"0.436060082807129"},{"EOM":"2012-11-30","r":"0.005767","rb":"0.002783","INFO":"0.602033363783932"},{"EOM":"2012-12-31","r":"-0.000496","rb":"0.005062","INFO":"0.225057176618478"}]}
In this example we have 13 months’ worth of price data for and we want to calculate the information ratio.
SET NOCOUNT ON;
SELECT CAST(eom as date) as eom,
cast(r as money) as r,
Cast(rb as money) as rb
into #s
FROM
(
VALUES
('2011-12-31', 50, 100),
('2012-01-31', 50.42, 100.82),
('2012-02-29', 51.15, 101.81),
('2012-03-31', 51.69, 102.13),
('2012-04-30', 51.53, 101.82),
('2012-05-31', 51.6, 102.7),
('2012-06-30', 52.47, 103.78),
('2012-07-31', 52.84, 104.73),
('2012-08-31', 52.8, 105.44),
('2012-09-30', 53.29, 106.22),
('2012-10-31', 53.96, 107.23),
('2012-11-30', 54.27, 107.52),
('2012-12-31', 54.24, 108.07)
) n (eom, r, rb);
SELECT EOM,
r,
rb,
wct.RunningINFORATIO( r, --@R
rb, --@Rb
12, --@Scale
'True', --@Prices
ROW_NUMBER() OVER (ORDER BY eom ASC), --@RowNum
NULL --@Id
) as INFO
FROM #s;
DROP TABLE #s;
This produces the following result.
{"columns":[{"field":"EOM","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"r","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"rb","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"INFO"}],"rows":[{"EOM":"2011-12-31","r":"50.00","rb":"100.00","INFO":"NULL"},{"EOM":"2012-01-31","r":"50.42","rb":"100.82","INFO":"NULL"},{"EOM":"2012-02-29","r":"51.15","rb":"101.81","INFO":"2.66922905163852"},{"EOM":"2012-03-31","r":"51.69","rb":"102.13","INFO":"3.89285791187229"},{"EOM":"2012-04-30","r":"51.53","rb":"101.82","INFO":"2.91747312517382"},{"EOM":"2012-05-31","r":"51.60","rb":"102.70","INFO":"0.611034090753194"},{"EOM":"2012-06-30","r":"52.47","rb":"103.78","INFO":"1.19287152750386"},{"EOM":"2012-07-31","r":"52.84","rb":"104.73","INFO":"0.872234970098944"},{"EOM":"2012-08-31","r":"52.80","rb":"105.44","INFO":"0.123221418965237"},{"EOM":"2012-09-30","r":"53.29","rb":"106.22","INFO":"0.250620742602983"},{"EOM":"2012-10-31","r":"53.96","rb":"107.23","INFO":"0.44162577825319"},{"EOM":"2012-11-30","r":"54.27","rb":"107.52","INFO":"0.612159825080578"},{"EOM":"2012-12-31","r":"54.24","rb":"108.07","INFO":"0.224522166142312"}]}
In this example we have 13 months’ worth of price data for three different portfolios and we want to calculate the information ratio. Note how each information ratio column in the resultant table has a unique @Id.
SELECT CAST(EOM as date) as EOM,
AAA,
BBB,
CCC,
BMK
INTO #s
FROM
(
VALUES
('2011-12-31', 74.58, 49.34, 54.97, 100),
('2012-01-31', 75.17, 48.73, 56.07, 100.82),
('2012-02-29', 74.61, 49.78, 54.66, 101.81),
('2012-03-31', 74.69, 55.25, 55.39, 102.13),
('2012-04-30', 75.6, 47.78, 57.4, 101.82),
('2012-05-31', 75.53, 50.34, 54.92, 102.7),
('2012-06-30', 75.41, 46.81, 55.12, 103.78),
('2012-07-31', 75.83, 51.53, 55.56, 104.73),
('2012-08-31', 74.58, 52.14, 54.24, 105.44),
('2012-09-30', 74.77, 51.22, 57.41, 106.22),
('2012-10-31', 74.33, 49.68, 55.76, 107.23),
('2012-11-30', 75.06, 45.44, 56.28, 107.52),
('2012-12-31', 75.25, 51.96, 53.19, 108.07)
) n (EOM, AAA, BBB, CCC, BMK);
SELECT EOM,
wct.RunningINFORATIO(AAA, BMK, 12, 'True', ROW_NUMBER() OVER (ORDER BY eom
ASC), 1) as AAA,
wct.RunningINFORATIO(BBB, BMK, 12, 'True', ROW_NUMBER() OVER (ORDER BY eom
ASC), 2) as BBB,
wct.RunningINFORATIO(CCC, BMK, 12, 'True', ROW_NUMBER() OVER (ORDER BY eom
ASC), 3) as CCC
FROM #s;
DROP TABLE #s;
This produces the following result.
{"columns":[{"field":"EOM","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"AAA"},{"field":"BBB"},{"field":"CCC"}],"rows":[{"EOM":"2011-12-31","AAA":"NULL","BBB":"NULL","CCC":"NULL"},{"EOM":"2012-01-31","AAA":"NULL","BBB":"NULL","CCC":"NULL"},{"EOM":"2012-02-29","AAA":"-2.53287857225603","BBB":"-0.670222203243517","CCC":"-1.21254057019029"},{"EOM":"2012-03-31","AAA":"-2.42887935570662","BBB":"1.70831447933928","CCC":"-0.562774128032074"},{"EOM":"2012-04-30","AAA":"-0.28751974009322","BBB":"-0.301132993654973","CCC":"0.742672111272349"},{"EOM":"2012-05-31","AAA":"-0.799672772223789","BBB":"0.0834332934095227","CCC":"-0.472794520066031"},{"EOM":"2012-06-30","AAA":"-1.31183123925642","BBB":"-0.468770269560868","CCC":"-0.559267461050082"},{"EOM":"2012-07-31","AAA":"-1.40048556295106","BBB":"0.122343103745679","CCC":"-0.543401746270146"},{"EOM":"2012-08-31","AAA":"-1.94093672830627","BBB":"0.142559896617809","CCC":"-0.93424097466334"},{"EOM":"2012-09-30","AAA":"-2.01054132789827","BBB":"0.00868188486539341","CCC":"-0.147058345789798"},{"EOM":"2012-10-31","AAA":"-2.34529088690404","BBB":"-0.178729871636421","CCC":"-0.520105890699677"},{"EOM":"2012-11-30","AAA":"-1.86758149549442","BBB":"-0.535185297725232","CCC":"-0.431442427795981"},{"EOM":"2012-12-31","AAA":"-1.85772821653992","BBB":"0.0434775121159037","CCC":"-0.862858177548675"}]}
In this example, we have the same data as in the previous example, except that is stored in 3rd normal form rather than in the de-normalized form. The benchmark is included in the table with using the symbol BMK. We use the PARTITION clause in order to generate the correct row number within a symbol.
SELECT CAST(eom as date) as eom,
sym,
CAST(pr as float) as pr
INTO #s
FROM
(
VALUES
('2011-12-31', 'AAA', 74.58),
('2012-01-31', 'AAA', 75.17),
('2012-02-29', 'AAA', 74.61),
('2012-03-31', 'AAA', 74.69),
('2012-04-30', 'AAA', 75.6),
('2012-05-31', 'AAA', 75.53),
('2012-06-30', 'AAA', 75.41),
('2012-07-31', 'AAA', 75.83),
('2012-08-31', 'AAA', 74.58),
('2012-09-30', 'AAA', 74.77),
('2012-10-31', 'AAA', 74.33),
('2012-11-30', 'AAA', 75.06),
('2012-12-31', 'AAA', 75.25),
('2011-12-31', 'BBB', 49.34),
('2012-01-31', 'BBB', 48.73),
('2012-02-29', 'BBB', 49.78),
('2012-03-31', 'BBB', 55.25),
('2012-04-30', 'BBB', 47.78),
('2012-05-31', 'BBB', 50.34),
('2012-06-30', 'BBB', 46.81),
('2012-07-31', 'BBB', 51.53),
('2012-08-31', 'BBB', 52.14),
('2012-09-30', 'BBB', 51.22),
('2012-10-31', 'BBB', 49.68),
('2012-11-30', 'BBB', 45.44),
('2012-12-31', 'BBB', 51.96),
('2011-12-31', 'CCC', 54.97),
('2012-01-31', 'CCC', 56.07),
('2012-02-29', 'CCC', 54.66),
('2012-03-31', 'CCC', 55.39),
('2012-04-30', 'CCC', 57.4),
('2012-05-31', 'CCC', 54.92),
('2012-06-30', 'CCC', 55.12),
('2012-07-31', 'CCC', 55.56),
('2012-08-31', 'CCC', 54.24),
('2012-09-30', 'CCC', 57.41),
('2012-10-31', 'CCC', 55.76),
('2012-11-30', 'CCC', 56.28),
('2012-12-31', 'CCC', 53.19),
('2011-12-31', 'BMK', 100),
('2012-01-31', 'BMK', 100.82),
('2012-02-29', 'BMK', 101.81),
('2012-03-31', 'BMK', 102.13),
('2012-04-30', 'BMK', 101.82),
('2012-05-31', 'BMK', 102.7),
('2012-06-30', 'BMK', 103.78),
('2012-07-31', 'BMK', 104.73),
('2012-08-31', 'BMK', 105.44),
('2012-09-30', 'BMK', 106.22),
('2012-10-31', 'BMK', 107.23),
('2012-11-30', 'BMK', 107.52),
('2012-12-31', 'BMK', 108.07)
) n (eom, sym, pr);
SELECT s1.EOM,
s1.sym,
wct.RunningINFORATIO(
s1.pr,
s2.pr,
12,
'True',
ROW_NUMBER() OVER (PARTITION BY s1.SYM ORDER BY
s1.sym, s1.eom ASC),
1
) as INFO
FROM #s s1
JOIN #s s2
ON s1.eom = s2.eom
WHERE s1.sym <> 'BMK'
AND s2.sym = 'BMK';
This produces the following result.
{"columns":[{"field":"EOM","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"sym"},{"field":"INFO"}],"rows":[{"EOM":"2011-12-31","sym":"AAA","INFO":"NULL"},{"EOM":"2012-01-31","sym":"AAA","INFO":"NULL"},{"EOM":"2012-02-29","sym":"AAA","INFO":"-2.53287857225603"},{"EOM":"2012-03-31","sym":"AAA","INFO":"-2.42887935570662"},{"EOM":"2012-04-30","sym":"AAA","INFO":"-0.28751974009322"},{"EOM":"2012-05-31","sym":"AAA","INFO":"-0.799672772223789"},{"EOM":"2012-06-30","sym":"AAA","INFO":"-1.31183123925642"},{"EOM":"2012-07-31","sym":"AAA","INFO":"-1.40048556295106"},{"EOM":"2012-08-31","sym":"AAA","INFO":"-1.94093672830627"},{"EOM":"2012-09-30","sym":"AAA","INFO":"-2.01054132789827"},{"EOM":"2012-10-31","sym":"AAA","INFO":"-2.34529088690404"},{"EOM":"2012-11-30","sym":"AAA","INFO":"-1.86758149549442"},{"EOM":"2012-12-31","sym":"AAA","INFO":"-1.85772821653992"},{"EOM":"2011-12-31","sym":"BBB","INFO":"NULL"},{"EOM":"2012-01-31","sym":"BBB","INFO":"NULL"},{"EOM":"2012-02-29","sym":"BBB","INFO":"-0.670222203243517"},{"EOM":"2012-03-31","sym":"BBB","INFO":"1.70831447933928"},{"EOM":"2012-04-30","sym":"BBB","INFO":"-0.301132993654973"},{"EOM":"2012-05-31","sym":"BBB","INFO":"0.0834332934095227"},{"EOM":"2012-06-30","sym":"BBB","INFO":"-0.468770269560868"},{"EOM":"2012-07-31","sym":"BBB","INFO":"0.122343103745679"},{"EOM":"2012-08-31","sym":"BBB","INFO":"0.142559896617809"},{"EOM":"2012-09-30","sym":"BBB","INFO":"0.00868188486539341"},{"EOM":"2012-10-31","sym":"BBB","INFO":"-0.178729871636421"},{"EOM":"2012-11-30","sym":"BBB","INFO":"-0.535185297725232"},{"EOM":"2012-12-31","sym":"BBB","INFO":"0.0434775121159037"},{"EOM":"2011-12-31","sym":"CCC","INFO":"NULL"},{"EOM":"2012-01-31","sym":"CCC","INFO":"NULL"},{"EOM":"2012-02-29","sym":"CCC","INFO":"-1.21254057019029"},{"EOM":"2012-03-31","sym":"CCC","INFO":"-0.562774128032074"},{"EOM":"2012-04-30","sym":"CCC","INFO":"0.742672111272349"},{"EOM":"2012-05-31","sym":"CCC","INFO":"-0.472794520066031"},{"EOM":"2012-06-30","sym":"CCC","INFO":"-0.559267461050082"},{"EOM":"2012-07-31","sym":"CCC","INFO":"-0.543401746270146"},{"EOM":"2012-08-31","sym":"CCC","INFO":"-0.93424097466334"},{"EOM":"2012-09-30","sym":"CCC","INFO":"-0.147058345789798"},{"EOM":"2012-10-31","sym":"CCC","INFO":"-0.520105890699677"},{"EOM":"2012-11-30","sym":"CCC","INFO":"-0.431442427795981"},{"EOM":"2012-12-31","sym":"CCC","INFO":"-0.862858177548675"}]}
Using the same data, we could PIVOT the results into a tabular format.
SELECT EOM,
AAA,
BBB,
CCC
FROM
(
SELECT s1.EOM,
s1.sym,
wct.RunningINFORATIO(
s1.pr,
s2.pr,
12,
'True',
ROW_NUMBER() OVER (PARTITION BY s1.SYM ORDER
BY s1.sym, s1.eom ASC),
1
) as INFO
FROM #s s1
JOIN #s s2
ON s1.eom = s2.eom
WHERE s1.sym <> 'BMK'
AND s2.sym = 'BMK'
) d
PIVOT
(
sum(INFO)
for sym in (AAA, BBB, CCC)
) as P;
This produces the following result.
{"columns":[{"field":"EOM","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"AAA"},{"field":"BBB"},{"field":"CCC"}],"rows":[{"EOM":"2011-12-31","AAA":"NULL","BBB":"NULL","CCC":"NULL"},{"EOM":"2012-01-31","AAA":"NULL","BBB":"NULL","CCC":"NULL"},{"EOM":"2012-02-29","AAA":"-2.53287857225603","BBB":"-0.670222203243517","CCC":"-1.21254057019029"},{"EOM":"2012-03-31","AAA":"-2.42887935570662","BBB":"1.70831447933928","CCC":"-0.562774128032074"},{"EOM":"2012-04-30","AAA":"-0.28751974009322","BBB":"-0.301132993654973","CCC":"0.742672111272349"},{"EOM":"2012-05-31","AAA":"-0.799672772223789","BBB":"0.0834332934095227","CCC":"-0.472794520066031"},{"EOM":"2012-06-30","AAA":"-1.31183123925642","BBB":"-0.468770269560868","CCC":"-0.559267461050082"},{"EOM":"2012-07-31","AAA":"-1.40048556295106","BBB":"0.122343103745679","CCC":"-0.543401746270146"},{"EOM":"2012-08-31","AAA":"-1.94093672830627","BBB":"0.142559896617809","CCC":"-0.93424097466334"},{"EOM":"2012-09-30","AAA":"-2.01054132789827","BBB":"0.00868188486539341","CCC":"-0.147058345789798"},{"EOM":"2012-10-31","AAA":"-2.34529088690404","BBB":"-0.178729871636421","CCC":"-0.520105890699677"},{"EOM":"2012-11-30","AAA":"-1.86758149549442","BBB":"-0.535185297725232","CCC":"-0.431442427795981"},{"EOM":"2012-12-31","AAA":"-1.85772821653992","BBB":"0.0434775121159037","CCC":"-0.862858177548675"}]}