Last time I was looking on the
calculation of simple moving average using the new windowing features in
transact SQL. I was curious how to do some deeper calculation in the stock
analysis area. So today I shall see how we calculate the Stockhastic oscillator.
This function use two inputs. D% and K% and the formula are:
%K = 100*(C - L14)/(H14 - L14). C = the most recent closing price L14 = the low of the 14 previous trading sessions H14 = the highest price traded during the same 14-day period.
%D = 3 or 8-day period moving average of
%K
CREATE table
#calculation (
[id] [int],
[aktie] [nchar](10) NULL,
[datum]
[date] NULL,
[stang] [decimal](18, 2) NULL,
[K] [decimal](18, 2) NULL
CONSTRAINT [PK_calculation] PRIMARY
KEY CLUSTERED
(
[id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE
= OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ARITHABORT OFF
SET ANSI_WARNINGS
OFF
GO
INSERT INTO
#calculation
SELECT id, aktie, datum, stang
,K = (100*((stang - MIN(stang) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 13 PRECEDING AND CURRENT ROW))) / ((MAX(stang) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 13 PRECEDING AND CURRENT ROW)) - (MIN(stang) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 13 PRECEDING AND CURRENT ROW))))
FROM dbo.borsdata
GO
SELECT id, aktie, datum, stang
,AVG(stang) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 199 PRECEDING AND CURRENT ROW) as '200 SMA'
,AVG(stang) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 49 PRECEDING AND CURRENT ROW) as '50 SMA'
,AVG(stang) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 19 PRECEDING AND CURRENT ROW) as '20 SMA'
,K
,D = (AVG(K) OVER (PARTITION BY aktie ORDER BY datum ROWS BETWEEN 2 PRECEDING AND CURRENT ROW))
FROM #calculation
drop table #calculation