The following script contains the SQL statements for this query.
-- Find the 21-day and 5-day moving average price for a specified -- list of 1000 stocks during a 6-month period. (Use split adjusted prices) */ truncate table hist_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,'2010-06-01') and B.TRADE_DATE <= '2010-12-01' GROUP BY B.INSTRUMENT_ID, B.TRADING_SYMBOL, B.TRADE_DATE, B.CLOSE_PRICE ORDER BY B.INSTRUMENT_ID, B.TRADE_DATE; SELECT 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 >= '2010-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 >= '2010-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 ;
Copyright © 2005. Sybase Inc. All rights reserved. |
![]() |