Tuesday, March 26, 2013

Windowing functions - stochastic oscillator



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

The oscillators value are between 0 and 100. Below 20 is oversold and over 80 is overbought. A buy respective sell signals is occur when the %K is cut thru %D from across 80 respective below 20.

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

Friday, March 8, 2013

High number of LATCH_EX waits

During an implementation of a new SQL environment for a customer I went into some problem with high nr of waits of LATCH_EX type when they run some heavy batches. I was not sure what this really was. I quite familiar with PAGELATCH and so on. Those are much more common, at least in server I have seen.
The customer asked me to investigate what the problem was. First I read the whitepaper “Diagnosing and Resolving Latch Contention on SQL Server” from Microsoft.
There were some ideas coming up after that. The server did have many CPU cores, 32 to be exact. The database had only one datafile.
First I tried to add more files to the database. I tried to use 4 but there was no big change. I went down from 32 ms in average to 27ms. After investigate sys.dm_os_latch_stats is was quite obvious what the problem was. ACCESS_METHODS_DATASET_PARENT was huge.



Regarding BOL it means Used to synchronize child dataset access to the parent dataset during parallel operations.

I did some try to set the Max Degree of Parallelism from default 0 to 4 or 8. This change had the desired effect. In the graf below we can see the effect very clearly on the black line. We see the batch starts, then a change to 8 for the Max Degree of Parallelism. Then I change it back, and then to 4 and then to 8.