Created
February 4, 2010 01:39
-
-
Save eight/294278 to your computer and use it in GitHub Desktop.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
CREATE OR REPLACE PACKAGE WKD_PKG AS | |
/* | |
営業日パッケージ | |
※土曜、日曜が営業日の場合は、IS_WORKDAYを直す | |
※国民の祝日が営業日の場合は、休日テーブルを直す | |
-- 休日テーブル(祝祭日、お盆とか、都民の日とかも) | |
create table holidays ( | |
holiday date, | |
primary key(holiday) | |
); | |
-- 2010年の国民の祝日を入れておく | |
-- ここが便利 http://cbdb.cybozu.co.jp/cgi-bin/db.cgi?page=DBView&did=690 | |
insert into holidays values(to_date('2010-01-01','YYYY-MM-DD')); --元日 | |
insert into holidays values(to_date('2010-01-11','YYYY-MM-DD')); --成人の日 | |
insert into holidays values(to_date('2010-02-11','YYYY-MM-DD')); --建国記念の日 | |
insert into holidays values(to_date('2010-03-21','YYYY-MM-DD')); --春分の日 | |
insert into holidays values(to_date('2010-03-22','YYYY-MM-DD')); --振替休日 | |
insert into holidays values(to_date('2010-04-29','YYYY-MM-DD')); --昭和の日 | |
insert into holidays values(to_date('2010-05-03','YYYY-MM-DD')); --憲法記念日 | |
insert into holidays values(to_date('2010-05-04','YYYY-MM-DD')); --みどりの日 | |
insert into holidays values(to_date('2010-05-05','YYYY-MM-DD')); --こどもの日 | |
insert into holidays values(to_date('2010-07-19','YYYY-MM-DD')); --海の日 | |
insert into holidays values(to_date('2010-09-20','YYYY-MM-DD')); --敬老の日 | |
insert into holidays values(to_date('2010-09-23','YYYY-MM-DD')); --秋分の日 | |
insert into holidays values(to_date('2010-10-11','YYYY-MM-DD')); --体育の日 | |
insert into holidays values(to_date('2010-11-03','YYYY-MM-DD')); --文化の日 | |
insert into holidays values(to_date('2010-11-23','YYYY-MM-DD')); --勤労感謝の日 | |
insert into holidays values(to_date('2010-12-23','YYYY-MM-DD')); --天皇誕生日 | |
*/ | |
/* | |
|| 開始日からi_days営業日後の日付を返す | |
|| i_daysが正数なら未来、負数なら過去 | |
|| ※開始日は数えない | |
*/ | |
FUNCTION WORKDAY( i_startdate IN date, i_days IN number) RETURN DATE; | |
/* | |
|| 指定した日付が営業日ならYを返す。営業日じゃなければNを返す。 | |
*/ | |
FUNCTION IS_WORKDAY( i_date IN date) RETURN CHAR; | |
-- 今日が営業日かどうか | |
FUNCTION IS_WORKDAY RETURN CHAR; | |
/* | |
|| 開始日と終了日の間に含まれる営業日の日数を返す。 | |
|| 日数には開始日と終了日も含まれる。 | |
*/ | |
FUNCTION NETWORKDAY( i_startdate IN date, i_enddate IN date) RETURN NUMBER; | |
END WKD_PKG; | |
/ | |
---------------------------------------------------------- | |
-- PACKAGE BODY | |
---------------------------------------------------------- | |
CREATE OR REPLACE PACKAGE BODY WKD_PKG AS | |
FUNCTION WORKDAY( i_startdate IN date, i_days IN number) RETURN DATE | |
IS | |
i NUMBER := 0; | |
work_days NUMBER := 0; | |
BEGIN | |
IF i_days = 0 THEN | |
RETURN i_startdate; | |
END IF; | |
WHILE true LOOP | |
IF i_days > 0 THEN | |
i := i + 1; | |
ELSE | |
i := i - 1; | |
END IF; | |
IF IS_WORKDAY(i_startdate + i) = 'Y' THEN | |
work_days := work_days + 1; | |
END IF; | |
IF abs(work_days) = abs(i_days) THEN | |
exit; | |
END IF; | |
END LOOP; | |
RETURN i_startdate + i; | |
END; | |
FUNCTION IS_WORKDAY(i_date IN date) RETURN CHAR | |
IS | |
hol NUMBER := 0; | |
BEGIN | |
-- 日曜日:1と土曜日:7に含まれない | |
IF TO_CHAR(i_date, 'D') NOT IN ('1', '7') THEN | |
-- 土日以外でholidaysに存在しなければ営業日 | |
SELECT COUNT(*) INTO hol FROM holidays WHERE holiday=trunc(i_date); | |
IF hol = 0 THEN | |
RETURN 'Y'; | |
END IF; | |
END IF; | |
RETURN 'N'; | |
END; | |
FUNCTION IS_WORKDAY RETURN CHAR | |
IS | |
BEGIN | |
RETURN IS_WORKDAY(SYSDATE); | |
END; | |
FUNCTION NETWORKDAY( i_startdate IN date, i_enddate IN date) RETURN NUMBER | |
IS | |
i number := 0; | |
diff number := 0; | |
days number := 0; | |
BEGIN | |
diff := trunc(i_enddate) - trunc(i_startdate); | |
FOR i IN 0..diff LOOP | |
IF IS_WORKDAY(i_startdate + i) = 'Y' THEN | |
days := days + 1; | |
END IF; | |
END LOOP; | |
RETURN days; | |
END; | |
END WKD_PKG; | |
/ | |
/* | |
-- テスト | |
-- 適当に | |
SELECT to_char(WKD_PKG.workday(to_date('2010-01-09','YYYY-MM-DD'), 2),'YYYY-MM-DD') FROM dual; | |
SELECT to_char(WKD_PKG.workday(to_date('2010-01-08','YYYY-MM-DD'), 4),'YYYY-MM-DD') FROM dual; | |
SELECT to_char(WKD_PKG.workday(to_date('2010-01-07','YYYY-MM-DD'), 4),'YYYY-MM-DD') FROM dual; | |
SELECT to_char(WKD_PKG.workday(to_date('2010-01-07','YYYY-MM-DD'), -4),'YYYY-MM-DD') FROM dual; | |
-- 全部6のはず。9,10が土日。11日が祝日。 | |
SELECT WKD_PKG.NETWORKDAY(to_date('2010-01-07','YYYY-MM-DD'),to_date('2010-01-15','YYYY-MM-DD')) FROM dual; | |
SELECT WKD_PKG.NETWORKDAY(to_date('2010-01-07','YYYY-MM-DD'),to_date('2010-01-16','YYYY-MM-DD')) FROM dual; | |
SELECT WKD_PKG.NETWORKDAY(to_date('2010-01-07','YYYY-MM-DD'),to_date('2010-01-17','YYYY-MM-DD')) FROM dual; | |
-- 7のはず。9,10が土日。11日が祝日。 | |
SELECT WKD_PKG.NETWORKDAY(to_date('2010-01-07','YYYY-MM-DD'),to_date('2010-01-18','YYYY-MM-DD')) FROM dual; | |
*/ |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment