You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
sql-tools/农历支持.sql

445 lines
15 KiB

1 year ago
IF object_id('dbo.FNGetLunarYearId') IS NOT NULL
BEGIN
DROP FUNCTION dbo.FNGetLunarYearId
END
GO
CREATE FUNCTION dbo.FNGetLunarYearId
(
@Year INT
)
RETURNS INT
BEGIN
IF @Year >= 2000
BEGIN
RETURN (SELECT FDataInt FROM
(SELECT 2000 AS FYear,51552 AS FDataInt
UNION ALL SELECT 2001 AS FYear,55636 AS FDataInt
UNION ALL SELECT 2002 AS FYear,54432 AS FDataInt
UNION ALL SELECT 2003 AS FYear,55888 AS FDataInt
UNION ALL SELECT 2004 AS FYear,30034 AS FDataInt
UNION ALL SELECT 2005 AS FYear,22176 AS FDataInt
UNION ALL SELECT 2006 AS FYear,43959 AS FDataInt
UNION ALL SELECT 2007 AS FYear,9680 AS FDataInt
UNION ALL SELECT 2008 AS FYear,37584 AS FDataInt
UNION ALL SELECT 2009 AS FYear,51893 AS FDataInt
UNION ALL SELECT 2010 AS FYear,43344 AS FDataInt
UNION ALL SELECT 2011 AS FYear,46240 AS FDataInt
UNION ALL SELECT 2012 AS FYear,47780 AS FDataInt
UNION ALL SELECT 2013 AS FYear,44368 AS FDataInt
UNION ALL SELECT 2014 AS FYear,21977 AS FDataInt
UNION ALL SELECT 2015 AS FYear,19360 AS FDataInt
UNION ALL SELECT 2016 AS FYear,42416 AS FDataInt
UNION ALL SELECT 2017 AS FYear,86390 AS FDataInt
UNION ALL SELECT 2018 AS FYear,21168 AS FDataInt
UNION ALL SELECT 2019 AS FYear,43312 AS FDataInt
UNION ALL SELECT 2020 AS FYear,31060 AS FDataInt
UNION ALL SELECT 2021 AS FYear,27296 AS FDataInt
UNION ALL SELECT 2022 AS FYear,44368 AS FDataInt
UNION ALL SELECT 2023 AS FYear,23378 AS FDataInt
UNION ALL SELECT 2024 AS FYear,19296 AS FDataInt
UNION ALL SELECT 2025 AS FYear,42726 AS FDataInt
UNION ALL SELECT 2026 AS FYear,42208 AS FDataInt
UNION ALL SELECT 2027 AS FYear,53856 AS FDataInt
UNION ALL SELECT 2028 AS FYear,60005 AS FDataInt
UNION ALL SELECT 2029 AS FYear,54576 AS FDataInt
UNION ALL SELECT 2030 AS FYear,23200 AS FDataInt
UNION ALL SELECT 2031 AS FYear,30371 AS FDataInt
UNION ALL SELECT 2032 AS FYear,38608 AS FDataInt
UNION ALL SELECT 2033 AS FYear,19415 AS FDataInt
UNION ALL SELECT 2034 AS FYear,19152 AS FDataInt
UNION ALL SELECT 2035 AS FYear,42192 AS FDataInt
UNION ALL SELECT 2036 AS FYear,118966 AS FDataInt
UNION ALL SELECT 2037 AS FYear,53840 AS FDataInt
UNION ALL SELECT 2038 AS FYear,54560 AS FDataInt
UNION ALL SELECT 2039 AS FYear,56645 AS FDataInt
UNION ALL SELECT 2040 AS FYear,46496 AS FDataInt
UNION ALL SELECT 2041 AS FYear,22224 AS FDataInt
UNION ALL SELECT 2042 AS FYear,21938 AS FDataInt
UNION ALL SELECT 2043 AS FYear,18864 AS FDataInt
UNION ALL SELECT 2044 AS FYear,42359 AS FDataInt
UNION ALL SELECT 2045 AS FYear,42160 AS FDataInt
UNION ALL SELECT 2046 AS FYear,43600 AS FDataInt
UNION ALL SELECT 2047 AS FYear,111189 AS FDataInt
UNION ALL SELECT 2048 AS FYear,27936 AS FDataInt
UNION ALL SELECT 2049 AS FYear,44448 AS FDataInt
) AS T
WHERE FYear = @Year)
END
ELSE IF @Year >= 1950
BEGIN
RETURN (SELECT FDataInt FROM
(SELECT 1950 AS FYear,27808 AS FDataInt
UNION ALL SELECT 1951 AS FYear,46416 AS FDataInt
UNION ALL SELECT 1952 AS FYear,86869 AS FDataInt
UNION ALL SELECT 1953 AS FYear,19872 AS FDataInt
UNION ALL SELECT 1954 AS FYear,42448 AS FDataInt
UNION ALL SELECT 1955 AS FYear,83315 AS FDataInt
UNION ALL SELECT 1956 AS FYear,21200 AS FDataInt
UNION ALL SELECT 1957 AS FYear,43432 AS FDataInt
UNION ALL SELECT 1958 AS FYear,59728 AS FDataInt
UNION ALL SELECT 1959 AS FYear,27296 AS FDataInt
UNION ALL SELECT 1960 AS FYear,44710 AS FDataInt
UNION ALL SELECT 1961 AS FYear,43856 AS FDataInt
UNION ALL SELECT 1962 AS FYear,19296 AS FDataInt
UNION ALL SELECT 1963 AS FYear,43748 AS FDataInt
UNION ALL SELECT 1964 AS FYear,42352 AS FDataInt
UNION ALL SELECT 1965 AS FYear,21088 AS FDataInt
UNION ALL SELECT 1966 AS FYear,62051 AS FDataInt
UNION ALL SELECT 1967 AS FYear,55632 AS FDataInt
UNION ALL SELECT 1968 AS FYear,23383 AS FDataInt
UNION ALL SELECT 1969 AS FYear,22176 AS FDataInt
UNION ALL SELECT 1970 AS FYear,38608 AS FDataInt
UNION ALL SELECT 1971 AS FYear,19925 AS FDataInt
UNION ALL SELECT 1972 AS FYear,19152 AS FDataInt
UNION ALL SELECT 1973 AS FYear,42192 AS FDataInt
UNION ALL SELECT 1974 AS FYear,54484 AS FDataInt
UNION ALL SELECT 1975 AS FYear,53840 AS FDataInt
UNION ALL SELECT 1976 AS FYear,54616 AS FDataInt
UNION ALL SELECT 1977 AS FYear,46400 AS FDataInt
UNION ALL SELECT 1978 AS FYear,46496 AS FDataInt
UNION ALL SELECT 1979 AS FYear,103846 AS FDataInt
UNION ALL SELECT 1980 AS FYear,38320 AS FDataInt
UNION ALL SELECT 1981 AS FYear,18864 AS FDataInt
UNION ALL SELECT 1982 AS FYear,43380 AS FDataInt
UNION ALL SELECT 1983 AS FYear,42160 AS FDataInt
UNION ALL SELECT 1984 AS FYear,45690 AS FDataInt
UNION ALL SELECT 1985 AS FYear,27216 AS FDataInt
UNION ALL SELECT 1986 AS FYear,27968 AS FDataInt
UNION ALL SELECT 1987 AS FYear,44870 AS FDataInt
UNION ALL SELECT 1988 AS FYear,43872 AS FDataInt
UNION ALL SELECT 1989 AS FYear,38256 AS FDataInt
UNION ALL SELECT 1990 AS FYear,19189 AS FDataInt
UNION ALL SELECT 1991 AS FYear,18800 AS FDataInt
UNION ALL SELECT 1992 AS FYear,25776 AS FDataInt
UNION ALL SELECT 1993 AS FYear,29859 AS FDataInt
UNION ALL SELECT 1994 AS FYear,59984 AS FDataInt
UNION ALL SELECT 1995 AS FYear,27480 AS FDataInt
UNION ALL SELECT 1996 AS FYear,21952 AS FDataInt
UNION ALL SELECT 1997 AS FYear,43872 AS FDataInt
UNION ALL SELECT 1998 AS FYear,38613 AS FDataInt
UNION ALL SELECT 1999 AS FYear,37600 AS FDataInt
)AS T
WHERE FYear = @Year)
END
ELSE
BEGIN
RETURN ISNULL ( (SELECT FDataInt FROM
(SELECT 1900 AS FYear,19416 AS FDataInt
UNION ALL SELECT 1901 AS FYear,19168 AS FDataInt
UNION ALL SELECT 1902 AS FYear,42352 AS FDataInt
UNION ALL SELECT 1903 AS FYear,21717 AS FDataInt
UNION ALL SELECT 1904 AS FYear,53856 AS FDataInt
UNION ALL SELECT 1905 AS FYear,55632 AS FDataInt
UNION ALL SELECT 1906 AS FYear,91476 AS FDataInt
UNION ALL SELECT 1907 AS FYear,22176 AS FDataInt
UNION ALL SELECT 1908 AS FYear,39632 AS FDataInt
UNION ALL SELECT 1909 AS FYear,21970 AS FDataInt
UNION ALL SELECT 1910 AS FYear,19168 AS FDataInt
UNION ALL SELECT 1911 AS FYear,42422 AS FDataInt
UNION ALL SELECT 1912 AS FYear,42192 AS FDataInt
UNION ALL SELECT 1913 AS FYear,53840 AS FDataInt
UNION ALL SELECT 1914 AS FYear,119381 AS FDataInt
UNION ALL SELECT 1915 AS FYear,46400 AS FDataInt
UNION ALL SELECT 1916 AS FYear,54944 AS FDataInt
UNION ALL SELECT 1917 AS FYear,44450 AS FDataInt
UNION ALL SELECT 1918 AS FYear,38320 AS FDataInt
UNION ALL SELECT 1919 AS FYear,84343 AS FDataInt
UNION ALL SELECT 1920 AS FYear,18800 AS FDataInt
UNION ALL SELECT 1921 AS FYear,42160 AS FDataInt
UNION ALL SELECT 1922 AS FYear,46261 AS FDataInt
UNION ALL SELECT 1923 AS FYear,27216 AS FDataInt
UNION ALL SELECT 1924 AS FYear,27968 AS FDataInt
UNION ALL SELECT 1925 AS FYear,109396 AS FDataInt
UNION ALL SELECT 1926 AS FYear,11104 AS FDataInt
UNION ALL SELECT 1927 AS FYear,38256 AS FDataInt
UNION ALL SELECT 1928 AS FYear,21234 AS FDataInt
UNION ALL SELECT 1929 AS FYear,18800 AS FDataInt
UNION ALL SELECT 1930 AS FYear,25958 AS FDataInt
UNION ALL SELECT 1931 AS FYear,54432 AS FDataInt
UNION ALL SELECT 1932 AS FYear,59984 AS FDataInt
UNION ALL SELECT 1933 AS FYear,28309 AS FDataInt
UNION ALL SELECT 1934 AS FYear,23248 AS FDataInt
UNION ALL SELECT 1935 AS FYear,11104 AS FDataInt
UNION ALL SELECT 1936 AS FYear,100067 AS FDataInt
UNION ALL SELECT 1937 AS FYear,37600 AS FDataInt
UNION ALL SELECT 1938 AS FYear,116951 AS FDataInt
UNION ALL SELECT 1939 AS FYear,51536 AS FDataInt
UNION ALL SELECT 1940 AS FYear,54432 AS FDataInt
UNION ALL SELECT 1941 AS FYear,120998 AS FDataInt
UNION ALL SELECT 1942 AS FYear,46416 AS FDataInt
UNION ALL SELECT 1943 AS FYear,22176 AS FDataInt
UNION ALL SELECT 1944 AS FYear,107956 AS FDataInt
UNION ALL SELECT 1945 AS FYear,9680 AS FDataInt
UNION ALL SELECT 1946 AS FYear,37584 AS FDataInt
UNION ALL SELECT 1947 AS FYear,53938 AS FDataInt
UNION ALL SELECT 1948 AS FYear,43344 AS FDataInt
UNION ALL SELECT 1949 AS FYear,46423 AS FDataInt
)AS T
WHERE FYear = @Year),0)
END
RETURN 0
END
GO
IF object_id('dbo.PConvertLunar','P') IS NOT NULL
BEGIN
DROP PROCEDURE dbo.PConvertLunar
END
GO
IF object_id('dbo.PConvertLunar','P') IS NOT NULL
BEGIN
DROP PROCEDURE dbo.PConvertLunar
END
GO
IF OBJECT_ID('TLunarCache#') IS NULL
BEGIN
CREATE TABLE TLunarCache#
(
FGregorian VARCHAR(10),
FLunar VARCHAR(10),
CONSTRAINT PK_LUNAR_CACHE PRIMARY KEY CLUSTERED(FGregorian)
)
CREATE NONCLUSTERED INDEX IX_LUNAR_CACHE_LUNAR ON TLunarCache# (FLunar)
END
GO
CREATE PROCEDURE dbo.PConvertLunar
(
@Type CHAR, --'L' ת<EFBFBD><EFBFBD><EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD>, 'G'ת<EFBFBD><EFBFBD><EFBFBD>ɹ<EFBFBD><EFBFBD><EFBFBD>
@Source VARCHAR(10),
@Dest VARCHAR(10) OUTPUT
)
AS
BEGIN
IF @Type = 'G'
BEGIN
SELECT @Dest = MIN(FGregorian)
FROM TLunarCache# WITH(NOLOCK)
WHERE FLunar = @Source
END
ELSE IF @Type = 'L'
BEGIN
SELECT @Dest = FLunar
FROM TLunarCache# WITH(NOLOCK)
WHERE FGregorian = @Source
END
ELSE
BEGIN
RETURN
END
IF @Dest IS NOT NULL
BEGIN
RETURN
END
DECLARE @Year INT
SELECT @Year = LEFT(@Source,4)
IF @Year < 1901 OR @Year > 2049
BEGIN
SELECT @Dest = ''
RETURN
END
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD>û<EFBFBD>л<EFBFBD><EFBFBD><EFBFBD>, <EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>ǰ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD>
DECLARE @FromDate DATETIME
DECLARE @ToDate DATETIME
DECLARE @Lunar VARCHAR(10)
IF @Year = 1901
BEGIN
SELECT @FromDate = CAST(@Year AS VARCHAR(4)) + '-01-01'
END
ELSE
BEGIN
SELECT @FromDate = DATEADD(YEAR,-1,LEFT(@Source,4) + '-01-01')
END
IF @Year = 2049
BEGIN
SELECT @ToDate = CAST(@Year AS VARCHAR(4)) + '-12-31'
END
ELSE
BEGIN
SELECT @ToDate = DATEADD(YEAR,1,LEFT(@Source,4) + '-12-31')
END
--ũת<EFBFBD><EFBFBD>
IF @Type = 'G'
BEGIN
WHILE(@FromDate <= @ToDate)
BEGIN
IF NOT EXISTS(SELECT 1 FROM TLunarCache# WHERE FGregorian = @FromDate)
BEGIN
SELECT @Lunar = dbo.FNGetLunar(@FromDate)
IF @Lunar = @Source
BEGIN
SELECT @Dest = CONVERT(VARCHAR(10),@FromDate,23)
END
INSERT TLunarCache#(FGregorian,FLunar)
SELECT CONVERT(VARCHAR(10),@FromDate,23),@Lunar
END
SELECT @FromDate = DATEADD(DAY,1,@FromDate)
END
END
ELSE
BEGIN
WHILE(@FromDate <= @ToDate)
BEGIN
IF NOT EXISTS(SELECT 1 FROM TLunarCache# WHERE FGregorian = @FromDate)
BEGIN
SELECT @Lunar = dbo.FNGetLunar(@FromDate)
INSERT TLunarCache#(FGregorian,FLunar)
SELECT CONVERT(VARCHAR(10),@FromDate,23),@Lunar
END
SELECT @FromDate = DATEADD(DAY,1,@FromDate)
END
SELECT @Dest = dbo.FNGetLunar(@Source)
END
END
GO
IF object_id('dbo.FNGetLunar') IS NOT NULL
BEGIN
DROP FUNCTION dbo.FNGetLunar
END
GO
CREATE FUNCTION dbo.FNGetLunar (@Date DATETIME)
RETURNS VARCHAR(10)
BEGIN
declare @soldata int
declare @offset int
declare @ilunar int
declare @i int
declare @j int
declare @ydays int
declare @mdays int
declare @mleap int
declare @mleap1 int
declare @mleapnum int
declare @bleap smallint
declare @temp int
declare @year nvarchar(10)
declare @month nvarchar(10)
declare @day nvarchar(10)
declare @chinesenum nvarchar(10)
declare @outputdate nvarchar(30)
set @offset=datediff(day,'1900-01-30',@Date)
--ȷ<EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD>ʼ
set @i=1900
--set @offset=@soldata
while @i<2050 and @offset>0
begin
set @ydays=348
set @mleapnum=0
select @ilunar=dbo.FNGetLunarYearId(@i)
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
set @j=32768
while @j>8
begin
if @ilunar & @j >0
set @ydays=@ydays+1
set @j=@j/2
end
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>ĸ<EFBFBD><EFBFBD><EFBFBD> 1-12 , û<EFBFBD>򴫻<EFBFBD> 0
set @mleap = @ilunar & 15
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>µ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD> ,<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
if @mleap > 0
begin
if @ilunar & 65536 > 0
set @mleapnum=30
else
set @mleapnum=29
set @ydays=@ydays+@mleapnum
end
set @offset=@offset-@ydays
set @i=@i+1
end
if @offset <= 0
begin
set @offset=@offset+@ydays
set @i=@i-1
select @ilunar=dbo.FNGetLunarYearId(@i)
end
--ȷ<EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
set @year=@i
--ȷ<EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD>¿<EFBFBD>ʼ
set @i = 1
--<EFBFBD>ж<EFBFBD><EFBFBD>Ǹ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
set @mleap = @ilunar & 15
set @bleap = 0
while @i < 13 and @offset > 0
begin
--<EFBFBD>ж<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
set @mdays=0
if (@mleap > 0 and @i = (@mleap+1) and @bleap=0)
begin--<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
set @i=@i-1
set @bleap=1
set @mleap1= @mleap
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>µ<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
if @ilunar & 65536 > 0
set @mdays = 30
else
set @mdays = 29
end
else
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
begin
set @j=1
set @temp = 65536
while @j<=@i
begin
set @temp=@temp/2
set @j=@j+1
end
if @ilunar & @temp > 0
set @mdays = 30
else
set @mdays = 29
end
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
if @bleap=1 and @i= (@mleap+1)
set @bleap=0
set @offset=@offset-@mdays
set @i=@i+1
end
if @offset <= 0
begin
set @offset=@offset+@mdays
set @i=@i-1
end
--ȷ<EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD>½<EFBFBD><EFBFBD><EFBFBD>
set @month=@i
--ȷ<EFBFBD><EFBFBD>ũ<EFBFBD><EFBFBD><EFBFBD>ս<EFBFBD><EFBFBD><EFBFBD>
set @day=ltrim(@offset)
--<EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD><EFBFBD>
SELECT @outputdate = @year + '-' + RIGHT('0' + @month,2) + '-' + RIGHT('0' + @day,2)
return @outputdate
END
GO