pdf_code/zzb_data_prod/处理历史数据/外部数据导入宽表 -科创板.sql

272 lines
9.1 KiB
MySQL
Raw Normal View History

2025-09-02 15:23:55 +08:00
set @year = "2024";
SET @next_year = CAST(CAST(@year AS UNSIGNED) + 1 AS CHAR);
set @enddate = CONCAT(@year,"" ,"-6-30 00:00:00");
set @enddate_1 = CONCAT(@year,"" ,"-12-31 00:00:00");
set @InfoPublDate = CONCAT(@next_year,"" ,"-9-30 00:00:00");
-- 年报是0 半年报是1
set @report_type = 1;
-- set @year = "2024";
-- SET @next_year = CAST(CAST(@year AS UNSIGNED) + 2 AS CHAR);
-- set @enddate = CONCAT(@year,"" ,"-12-31 00:00:00");
-- set @enddate_1 = CONCAT(@year,"" ,"-12-31 00:00:00");
-- set @InfoPublDate = CONCAT(@next_year,"" ,"-4-30 00:00:00");
-- -- 年报是0 半年报是1
-- set @report_type = 0;
drop table if exists third_quarter_external_data_tmp_pre;
-- 创建表结构
CREATE TABLE `third_quarter_external_data_tmp_pre` (
`year` varchar(4) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NOT NULL DEFAULT '',
`report_type` int(1) NOT NULL DEFAULT 0,
`InnerCode` varchar(200) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`CompanyCode` varchar(200) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`SecuCode` varchar(6) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`ChiName` varchar(200) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`Infopubldate` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`InfoPublDate_end` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`OperatingReenue` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`NPFromParentCompanyOwners` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`NetProfitCut` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`NetOperateCashFlow` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`NetFinanceCashFlow` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`NetInvestCashFlow` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`NonRecurringProfitLoss` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`BasicEPS` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`DilutedEPS` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`WROE` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`WROECut` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`TotalAssets` varchar(100) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`CashEquivalents` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`AccountReceivable` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`Inventories` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`TotalFixedAsset` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`TConstruInProcess` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`GoodWill` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`ShortTermLoan` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`AccountsPayable` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`ContractLiability` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`LongtermLoan` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`AccountingStandards` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`OperatingExpense` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`OperatingCost` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`AdministrationExpense` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`FinancialExpense` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
`RAndD` varchar(50) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL
) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_general_ci ROW_FORMAT = Dynamic;
-- 插入数据
insert into third_quarter_external_data_tmp_pre
select distinct @year as year
,@report_type as report_type
,t1.*
,Infopubldate
,InfoPublDate_end
,OperatingReenue
,NPFromParentCompanyOwners
,NetProfitCut
,NetOperateCashFlow
,NetFinanceCashFlow
,NetInvestCashFlow
,NonRecurringProfitLoss
,BasicEPS
,DilutedEPS
,WROE
,WROECut
,TotalAssets
,CashEquivalents
,AccountReceivable
,Inventories
,TotalFixedAsset
,TConstruInProcess
,GoodWill
,ShortTermLoan
,AccountsPayable
,ContractLiability
,LongtermLoan
,AccountingStandards
,OperatingExpense
,OperatingCost
,AdministrationExpense
,FinancialExpense
,RAndD
from
(
select
InnerCode
,CompanyCode
,LPAD(SecuCode,6,'0') as SecuCode
,ChiName
from secumain s
where ListedState=1
and ListedSector in (1,2,6,7,8)
and SecuCategory in (1,41)
and SecuMarket in (18,83,90)
)t1
left join
(
select
CompanyCode
,Infopubldate
,OperatingReenue
,NPParComOwners as NPFromParentCompanyOwners
,NetProfitCut
,NetOperateCashFlow
,NetFinanceCashFlow
,NetInvestCashFlow
,NonRecurringProfitLoss
,BasicEPS
,DilutedEPS
,WROE
,WROECut
from
(
SELECT *
FROM (SELECT b.*
,@rownum := @rownum+1
,IF(@pdept = b.CompanyCode, @rank := @rank + 1, @rank := 1) AS rank_num
,@pdept := b.CompanyCode
FROM (SELECT * FROM lc_stibmaindata a
where EndDate=@enddate and InfoPublDate < @InfoPublDate
ORDER BY a.CompanyCode, a.InfoPublDate DESC) b
-- 初始化自定义变量值
,(SELECT @rownum :=0, @pdept := NULL, @rank:=0) c
-- 该排序必须,否则结果会不对
ORDER BY b.CompanyCode, b.InfoPublDate DESC) result
order by CompanyCode, rank_num
)t where t.rank_num=2
)t2
on t1.CompanyCode = t2.CompanyCode
left join
(
select
EndDate,
InfoSourceCode as InfoSource,
CompanyCode
from
(
SELECT *
FROM (SELECT b.*
,@rownum := @rownum+1
,IF(@pdept = b.CompanyCode, @rank := @rank + 1, @rank := 1) AS rank_num
,@pdept := b.CompanyCode
FROM (SELECT * FROM lc_stibmaindata a
where EndDate=@enddate and InfoPublDate < @InfoPublDate
ORDER BY a.CompanyCode, a.InfoPublDate DESC) b
-- 初始化自定义变量值
,(SELECT @rownum :=0, @pdept := NULL, @rank:=0) c
-- 该排序必须,否则结果会不对
ORDER BY b.CompanyCode, b.InfoPublDate DESC) result
order by CompanyCode, rank_num
)t where t.rank_num=2
)t5
on t1.CompanyCode = t5.CompanyCode
left join
(
select
CompanyCode,
TotalAssets
from
(
SELECT *
FROM (SELECT b.*
,@rownum := @rownum+1
,IF(@pdept = b.CompanyCode, @rank := @rank + 1, @rank := 1) AS rank_num
,@pdept := b.CompanyCode
FROM (SELECT * FROM lc_stibmaindata a
where EndDate=@enddate_1 and InfoPublDate < @InfoPublDate
ORDER BY a.CompanyCode, a.InfoPublDate DESC) b
-- 初始化自定义变量值
,(SELECT @rownum :=0, @pdept := NULL, @rank:=0) c
-- 该排序必须,否则结果会不对
ORDER BY b.CompanyCode, b.InfoPublDate DESC) result
order by CompanyCode, rank_num
)t where t.rank_num=2
)t6
on t1.CompanyCode = t6.CompanyCode
left join
(
select
EndDate,
InfoPublDate as InfoPublDate_end,
InfoSourceCode as InfoSource,
CompanyCode,
CashEquivalents,
AccountReceivable,
Inventories,
TotalFixedAsset,
TConstruInProcess,
GoodWill,
ShortTermLoan,
AccountsPayable,
ContractLiability,
LongtermLoan
from
(
SELECT *
FROM (SELECT b.*
,@rownum := @rownum+1
,IF(@pdept = b.CompanyCode, @rank := @rank + 1, @rank := 1) AS rank_num
,@pdept := b.CompanyCode
FROM (SELECT * FROM lc_stibbalancesheet a
where IfMerged =1
and EndDate=@enddate_1 and InfoPublDate < @InfoPublDate
ORDER BY a.CompanyCode, a.InfoPublDate DESC) b
-- 初始化自定义变量值
,(SELECT @rownum :=0, @pdept := NULL, @rank:=0) c
-- 该排序必须,否则结果会不对
ORDER BY b.CompanyCode, b.InfoPublDate DESC) result
order by CompanyCode, rank_num
)t where t.rank_num=2
)t4
on t1.CompanyCode = t4.CompanyCode
left join
(
select
CompanyCode
,EndDate
,null as AccountingStandards
,OperatingExpense
,OperatingCost
,AdministrationExpense
,FinancialExpense
,RAndD
from
(
SELECT *
FROM (SELECT b.*
,@rownum := @rownum+1
,IF(@pdept = b.CompanyCode, @rank := @rank + 1, @rank := 1) AS rank_num
,@pdept := b.CompanyCode
FROM (SELECT * FROM lc_stibincomestate a
where IfMerged =1
and EndDate=@enddate and InfoPublDate < @InfoPublDate
ORDER BY a.CompanyCode, a.InfoPublDate DESC) b
-- 初始化自定义变量值
,(SELECT @rownum :=0, @pdept := NULL, @rank:=0) c
-- 该排序必须,否则结果会不对
ORDER BY b.CompanyCode, b.InfoPublDate DESC) result
order by CompanyCode, rank_num
)t where t.rank_num=2
)t3
on t1.CompanyCode = t3.CompanyCode
;
INSERT INTO third_measure_data SELECT * from third_quarter_external_data_tmp_pre;
SELECT * from third_measure_data where year = 2024 and report_type = 1;