The following script contains the SQL statements for this query:
--(Based on the previous query) Find the points (specific days) when the --5-day moving average intersects the 21-day moving average for these stocks. --The output is to be sorted by INSTRUMENT_ID and date. truncate table hist_temp; truncate table hist6_temp; commit; insert hist_temp SELECT number(),B.INSTRUMENT_ID, B.TRADING_SYMBOL, B.TRADE_DATE,B.CLOSE_PRICE, IFNULL(sum(A.SPLIT_FACTOR),1,sum(A.SPLIT_FACTOR)) FROM STOCK_HISTORY AS B left outer join SPLIT_EVENT as A on B.INSTRUMENT_ID = A.INSTRUMENT_ID AND B.TRADE_DATE < A.EFFECTIVE_DATE WHERE B.TRADING_SYMBOL BETWEEN 'AAA' AND 'BML' AND LENGTH(B.TRADING_SYMBOL) = 3 and B.TRADE_DATE >= DATEADD(DAY,-28,'2012-06-01') and B.TRADE_DATE <= '2012-12-01' GROUP BY B.INSTRUMENT_ID,TRADING_SYMBOL, B.TRADE_DATE, B.CLOSE_PRICE ORDER BY B.INSTRUMENT_ID, B.TRADE_DATE; Insert hist6_temp SELECT number(),x.INSTRUMENT_ID, x.TRADING_SYMBOL, x.TRADE_DATE, avg_5day, avg_21day FROM (SELECT B.INSTRUMENT_ID, B.TRADING_SYMBOL, B.TRADE_DATE, AVG(C.CLOSE_PRICE * B.SPLIT_FACTOR) avg_5day FROM hist_temp as B left outer join hist_temp as C on B.INSTRUMENT_ID = C.INSTRUMENT_ID and c.row_nbr BETWEEN b.row_nbr - 5 and b.row_nbr Where B.TRADE_DATE >= '2012-06-01' GROUP BY B.INSTRUMENT_ID, B.TRADING_SYMBOL, B.TRADE_DATE) x, (SELECT B.INSTRUMENT_ID, B.TRADING_SYMBOL, B.TRADE_DATE, AVG(C.CLOSE_PRICE * B.SPLIT_FACTOR) avg_21day FROM hist_temp as B left outer join hist_temp as C on B.INSTRUMENT_ID = C.INSTRUMENT_ID and c.row_nbr BETWEEN b.row_nbr - 21 and b.row_nbr Where B.TRADE_DATE >= '2012-06-01' GROUP BY B.INSTRUMENT_ID,B.TRADING_SYMBOL, B.TRADE_DATE) y where x.INSTRUMENT_ID = y.INSTRUMENT_ID and x.TRADE_DATE = y.TRADE_DATE order by x.INSTRUMENT_ID, x.TRADE_DATE; select z.TRADING_SYMBOL, z.TRADE_DATE, DAY_5, DAY_21, PREV_DAY5, PREV_DAY21 from (SELECT a.INSTRUMENT_ID, a.TRADING_SYMBOL, a.TRADE_DATE, avg(b.avg_21day) as prev_day21 from hist6_temp a, hist6_temp b where a.INSTRUMENT_ID = b.INSTRUMENT_ID and b.row_nbr between a.row_nbr - 2 and a.row_nbr - 1 group by a.INSTRUMENT_ID, a.TRADING_SYMBOL, a.TRADE_DATE) x, (SELECT a.INSTRUMENT_ID, a.TRADING_SYMBOL, a.TRADE_DATE, avg(b.avg_5day) as prev_day5 from hist6_temp a, hist6_temp b where a.INSTRUMENT_ID = b.INSTRUMENT_ID and b.row_nbr between a.row_nbr - 2 and a.row_nbr - 1 group by a.INSTRUMENT_ID, a.TRADING_SYMBOL, a.TRADE_DATE) y, (SELECT INSTRUMENT_ID, TRADING_SYMBOL, TRADE_DATE, avg_5day as day_5, avg_21day as day_21 from hist6_temp) z where z.INSTRUMENT_ID = x.INSTRUMENT_ID and z.TRADE_DATE = x.TRADE_DATE and z.INSTRUMENT_ID = y.INSTRUMENT_ID and z.TRADE_DATE = y.TRADE_DATE and sign(day_21-day_5) * sign(prev_day21-prev_day5) < 0;