leading-project/finereport/xiazuan/2_operation/项目明细弹窗.sql

711 lines
37 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- ****************************************
-- 创建人员: 杨坤安
-- 创建日期: 2024-07-22
-- 功 能: 帆软明细报表-项目明细弹窗
-- 目 录: xianzuan>2_运营>项目明细弹窗.fvs
-- ****************************************
TRUNCATE TABLE dim_comm_base_info_d
INSERT INTO dim_comm_base_info_d
SELECT
B.organ_code AS organ_code -- erp片区id
,B.organ_name AS organ_name -- erp片区名称
,B.comm_id AS comm_id -- erp项目id
,B.comm_name AS comm_name -- erp项目名称
,A.Province AS province -- 省
,A.City AS city -- 市
,A.Citylevel AS citylevel -- 城市级别
,A.StateName AS statename -- 业态 【项目业态】
,A.ProjectDeliverySituation AS projectdeliverysituation -- 项目交付情况
,C.sold_area AS sold_area -- 已售面积
,C.unsold_area AS unsold_area -- 未售面积
,D.sold_parking_num AS sold_parking_num -- 已售车位
,D.unsold_Parking_num AS unsold_parking_num -- 未售车位
,A.ManageStage AS managestage -- 项目状态
,A.TakeOverTime AS takeovertime -- 交付时间
,A.CommFrom AS commfrom -- 项目来源
,A.DevSubject AS devsubject -- 项目开发商名称
,A.CommAddress AS commaddress -- 项目地址
,A.IS_UPLOAD AS is_upload -- 是否有上传项目平面图
,(A.FloorArea + A.UndergroundArea ) AS totalarea -- 建筑总面积
,A.FloorArea AS floorarea -- 地上面积
,A.UndergroundArea AS undergroundarea -- 地下面积
,A.ContractArea AS contractarea -- 合约面积
,A.TakeOverArea AS takeoverarea -- 在管面积
,C.CalcArea AS CalcArea -- 收费面积
,A.GreenArea AS greenarea -- 绿化面积
,C.room_num AS room_num -- 总户数
,C.delivered_num AS delivered_num -- 已交付户数
,C.rece_num AS rece_num -- 已接房数
,C.fit_num AS fit_num -- 正在装修户数
,C.done_fit_num AS done_fit_num -- 已完成装修户数
,C.done_fit_no AS done_fit_no -- 已完成装修未入住
,C.done_fit_yes AS done_fit_yes -- 已完成装修已入住
,IF(C.delivered_num = 0,0,(C.done_fit_yes / C.delivered_num )) AS stay_rate -- 入住率
,if(C.delivered_num = 0,0,(C.done_fit_num / C.delivered_num )) AS fit_rate -- 装修率
,A.PedEntrExitsCount AS PedEntrExitsCount -- 人行出入口数量
, A.CarEntrExitsCount AS CarEntrExitsCount -- 车行出入口数量
,A.MixedEntrExitsCount AS MixedEntrExitsCount -- 人车混行出入口数量
,A.PedEntrExitsCount + A.CarEntrExitsCount + A.MixedEntrExitsCount AS TotalEntrExitsCount -- 总出入口数量
,A.GuardedEntrExitsCount AS GuardedEntrExitsCount -- 有人值守出入口数量
,A.MonitoringRoomCount AS MonitoringRoomCount -- 独立监控室数量
,A.IsMonRoomMergedToGate AS ismonroommergedtogate -- 监控室是否合并至门岗
,A.ChargeMode AS ChargeMode -- 收费模式
,G.high_housing AS high_housing -- 住宅高层
,G.multi_housing AS multi_housing -- 住宅多层
,G.villa AS villa -- 别墅
,G.town_prope_fee AS town_prope_fee -- 联排物业服务费
,G.stacking_prope_fee AS stacking_prope_fee -- 叠拼物业服务费
,G.house_prope_fee AS house_prope_fee -- 洋房物业费
,G.apart_prope_fee AS apart_prope_fee -- 公寓物业服务费
,G.shop_prope_fee AS shop_prope_fee -- 商铺物业服务费
,G.office_prope_fee AS office_prope_fee -- 写字楼物业服务费
,G.kinder_prope_fee AS kinder_prope_fee -- 学校
,G.fact_prope_fee AS fact_prope_fee -- 公共建筑
,G.hotel_prope_fee AS hotel_prope_fee -- 酒店物业服务费
,G.manage_parking_fee AS manage_parking_fee -- 车位管理物业服务费
,G.month_parking_fee AS month_parking_fee -- 车位月租费用
,A.ContractName AS contractname -- 合同类型
,A.GetMethod AS getmethod -- 项目获取渠道
,A.sign_time AS sign_time -- 签约时间
,A.ContractTerm AS contractterm -- 合同期限
,A.ContractPartyName AS contractpartyname -- 合同对方名称
,A.PropertyMgrEntrustType AS propertymgrentrusttype -- 物业管理委托方类型
,A.is_contractfiled AS is_contractfiled -- 是否办理合同备案
,CASE WHEN A.IsSetCommittee = '1'
THEN'' ELSE ''
END AS is_committee -- 是否已成立业主委员会
,A.CommitteeTime AS CommitteeTime -- 业委会成立时间
,CONCAT(DATE_FORMAT(A.CommitteeTermStartDate, '%Y-%m-%d' ) , '',DATE_FORMAT(A.CommitteeTermEndDate, '%Y-%m-%d' )) AS service_day -- 任职时间
,A.ManageContractArea AS managecontractarea -- 管理口径合同面积 【在管面积】
,A.ManageKindName AS managekindname -- 管理性质名称 【项目归属】
FROM
(
SELECT
T.*
,CASE WHEN T.ProjectFloorPlan IS NULL OR JSON_EXTRACT( JSON_EXTRACT(cast( T.ProjectFloorPlan AS JSON ), '$[0]' ), '$.FileName' ) IS NULL THEN''
WHEN JSON_EXTRACT( JSON_EXTRACT( cast( T.ProjectFloorPlan AS JSON ), '$[0]' ), '$.FileName' ) IS NOT NULL THEN''
END AS IS_UPLOAD
,CASE WHEN T.IsContractFiled = '1'
THEN'' ELSE ''
END AS is_contractfiled -- 是否办理合同备案
,max(T.GetTime) OVER(PARTITION BY T.CommId)AS sign_time -- 签约时间
FROM
(
SELECT
*
,row_number() OVER(PARTITION BY CommId ORDER BY GetTime DESC) AS RK
FROM dw.dim_project_base_info_d -- 项目维度表
)T
WHERE T.RK = 1
) A
JOIN
(
SELECT
organ_code, -- erp片区id
organ_name, -- erp片区名称
comm_id, -- erp项目id
comm_name -- erp项目名称
FROM dw.dim_organ_mapping -- 片区项目映射维度表
WHERE comm_id IS NOT NULL
AND comm_name NOT LIKE '%撤场%'
AND comm_name NOT LIKE '%案场%'
AND comm_name NOT LIKE '%禁用%'
AND length( comm_id ) != 0
-- ${IF(LEN(p_area)!=0," and organ_code IN ('"+p_area+"')","")}
-- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")}
GROUP BY
organ_code, -- erp片区id
organ_name, -- erp片区名称
comm_id, -- erp项目id
comm_name -- erp项目名称
)B
ON A.CommId = B.comm_id
LEFT JOIN
(
SELECT
a.CommID AS CommID
,SUM(CASE WHEN a.roomstate <> 0 THEN 1 ELSE 0 END) AS room_num -- 项目对应房间数量
,SUM(CASE WHEN a.roomstate IN ( '1', '4', '9', '10', '5', '6' ) THEN a.buildarea ELSE 0 END ) AS sold_area -- 已售面积
,SUM(CASE WHEN a.roomstate = '2' THEN a.buildarea ELSE 0 END ) AS unsold_area -- 未售面积
,SUM(CASE WHEN a.roomstate NOT IN('0','2') THEN 1 ELSE 0 END ) AS delivered_num -- 已交付户数
,SUM(CASE WHEN a.roomstate IN ( '4', '9', '10', '5', '6' ) THEN 1 ELSE 0 END ) AS rece_num -- 已接房数
,SUM(CASE WHEN a.roomstate = '4' THEN 1 ELSE 0 END ) AS fit_num -- 正在装修户数
,SUM(CASE WHEN a.roomstate IN ( '9', '10', '5', '6' ) THEN 1 ELSE 0 END ) AS done_fit_num -- 已完成装修户数
,SUM(CASE WHEN a.roomstate = '5' THEN 1 ELSE 0 END ) AS done_fit_no -- 已完成装修未入住
,SUM(CASE WHEN a.roomstate IN ( '9', '10', '6' ) THEN 1 ELSE 0 END ) AS done_fit_yes -- 已完成装修已入住
,SUM(b.CalcArea) AS CalcArea
FROM
(
SELECT
*
FROM dw.dim_room_d
)a
LEFT JOIN
(
SELECT
b1.CommId AS CommId
,b1.RoomID AS RoomID
,SUM(CalcArea) AS CalcArea
FROM
(
SELECT
CommId
, CalcArea
, RoomID
FROM ods_erp_tb_hspr_coststansetting_d
WHERE RoomID <> '0'
GROUP BY CommId, CalcArea, RoomID
)b1
GROUP BY b1.CommId,b1.RoomID
)b
ON a.CommID = b.CommId
AND a.RoomID = b.RoomID
GROUP BY CommID
)C
ON A.CommId = C.CommID
LEFT JOIN
(
SELECT
CommID
,SUM( CASE WHEN ParkingState IN ( '0001', '0003' ) THEN 1 ELSE 0 END ) AS sold_parking_num -- 已售车位
,SUM(CASE WHEN ParkingState IN ( '0002', '0004' ) THEN 1 ELSE 0 END) AS unsold_Parking_num -- 未售车位
FROM ods_erp_tb_hspr_parking_d
WHERE IsDelete = '0'
GROUP BY
CommID
)D
ON A.COMMID = D.COMMID
LEFT JOIN
(
SELECT
A.CommId
-- 住宅高层
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN ('高层物业服务费', '电梯电费', '公共能耗费') THEN ROUND(ROUND(B.StanAmount,2),2) END),',','\n'),'-') AS high_housing -- 住宅高层
-- 住宅多层
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN ('多层物业服务费', '公共能耗费') THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS multi_housing -- 住宅多层
-- 别墅
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN ('别墅物业服务费', '公共能耗费') THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS villa -- 别墅
-- 联排物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%联排%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS town_prope_fee -- 联排物业服务费
-- 叠拼物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%叠拼%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS stacking_prope_fee -- 叠拼物业服务费
-- 洋房物业费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%洋房%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS house_prope_fee -- 洋房物业费
-- 公寓物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%公寓%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS apart_prope_fee -- 公寓物业服务费
-- 商铺物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%商铺%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS shop_prope_fee -- 商铺物业服务费
-- 写字楼物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%写字楼%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS office_prope_fee -- 写字楼物业服务费
-- 幼儿园物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%幼儿园%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS kinder_prope_fee-- 幼儿园物业服务费
-- 厂区物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%厂区%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS fact_prope_fee -- 厂区物业服务费
-- 酒店物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%酒店%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS hotel_prope_fee -- 酒店物业服务费
-- 车位管理物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN('车位管理物业服务费','车位物业服务费') THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS manage_parking_fee -- 车位管理物业服务费
-- 车位月租费用
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName = '车位月租' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS month_parking_fee -- 车位月租费用
FROM
(
SELECT
DISTINCT
CommID
,CostID
,StanID
FROM dim_bind_cost_stan_detail_d -- 绑定的收费标准明细
-- WHERE CommID = '214330'
)A
LEFT JOIN
(
SELECT
B1.CommID AS CommID
,B1.COSTID AS COSTID
,B1.StanID AS StanID
,B1.StanAmount AS StanAmount
,B2.COSTNAME AS COSTNAME
FROM
(
SELECT
CommID
,COSTID
,StanID
,StanAmount
FROM dim_cost_stand_d -- 小区收费标准
WHERE StanAmount <> 0
)B1
LEFT JOIN
(
SELECT
distinct
COMMID
,COSTID
,COSTNAME
FROM dim_costitem_d -- 项目上的费用名称
)B2
ON B1.CommID = B2.COMMID
AND B1.CostID = B2.COSTID
)B
ON A.CommID = B.COMMID
AND A.CostID = B.COSTID
AND A.StanID = B.StanID
GROUP BY
A.CommId
)G
ON A.COMMID = G.COMMID
;
DROP table dim_comm_base_info_d;
SELECT count(1)from dim_comm_base_info_d;
CREATE TABLE dim_comm_base_info_d
(
organ_code VARCHAR(100) COMMENT 'erp片区id',
organ_name VARCHAR(100) COMMENT 'erp片区名称',
comm_id VARCHAR(100) COMMENT 'erp项目id',
comm_name VARCHAR(100) COMMENT 'erp项目名称',
province VARCHAR(100) COMMENT '',
city VARCHAR(100) COMMENT '',
citylevel VARCHAR(100) COMMENT '城市级别',
statename VARCHAR(100) COMMENT '业态 【项目业态】',
projectdeliverysituation VARCHAR(100) COMMENT '项目交付情况',
sold_area DECIMAL(16,4) COMMENT '已售面积',
unsold_area DECIMAL(16,4) COMMENT '未售面积',
sold_parking_num INT COMMENT '已售车位',
unsold_parking_num INT COMMENT '未售车位',
managestage VARCHAR(100) COMMENT '项目状态',
takeovertime VARCHAR(100) COMMENT '交付时间',
commfrom VARCHAR(100) COMMENT '项目来源',
devsubject VARCHAR(100) COMMENT '项目开发商名称',
commaddress VARCHAR(100) COMMENT '项目地址',
is_upload VARCHAR(100) COMMENT '是否有上传项目平面图',
totalarea DECIMAL(16,4) COMMENT '建筑总面积',
floorarea DECIMAL(16,4) COMMENT '地上面积',
undergroundarea DECIMAL(16,4) COMMENT '地下面积',
contractarea DECIMAL(16,4) COMMENT '合约面积',
takeoverarea DECIMAL(16,4) COMMENT '在管面积',
CalcArea DECIMAL(16,4) COMMENT '收费面积',
greenarea DECIMAL(16,4) COMMENT '绿化面积',
room_num INT COMMENT '总户数',
delivered_num INT COMMENT '已交付户数',
rece_num INT COMMENT '已接房数',
fit_num INT COMMENT '正在装修户数',
done_fit_num INT COMMENT '已完成装修户数',
done_fit_no INT COMMENT '已完成装修未入住',
done_fit_yes INT COMMENT '已完成装修已入住',
stay_rate DECIMAL(8,4) COMMENT '入住率',
fit_rate DECIMAL(8,4) COMMENT '装修率',
PedEntrExitsCount INT COMMENT '人行出入口数量',
CarEntrExitsCount INT COMMENT '车行出入口数量',
MixedEntrExitsCount INT COMMENT '人车混行出入口数量',
TotalEntrExitsCount INT COMMENT '总出入口数量',
GuardedEntrExitsCount INT COMMENT '有人值守出入口数量',
MonitoringRoomCount INT COMMENT '独立监控室数量',
ismonroommergedtogate VARCHAR(100) COMMENT '监控室是否合并至门岗',
ChargeMode VARCHAR(100) COMMENT '收费模式',
high_housing VARCHAR(100) COMMENT '住宅高层',
multi_housing VARCHAR(100) COMMENT '住宅多层',
villa VARCHAR(100) COMMENT '别墅',
town_prope_fee VARCHAR(100) COMMENT '联排物业服务费',
stacking_prope_fee VARCHAR(100) COMMENT '叠拼物业服务费',
house_prope_fee VARCHAR(100) COMMENT '洋房物业费',
apart_prope_fee VARCHAR(100) COMMENT '公寓物业服务费',
shop_prope_fee VARCHAR(100) COMMENT '商铺物业服务费',
office_prope_fee VARCHAR(100) COMMENT '写字楼物业服务费',
kinder_prope_fee VARCHAR(100) COMMENT '学校',
fact_prope_fee VARCHAR(100) COMMENT '公共建筑',
hotel_prope_fee VARCHAR(100) COMMENT '酒店物业服务费',
manage_parking_fee VARCHAR(100) COMMENT '车位管理物业服务费',
month_parking_fee VARCHAR(100) COMMENT '车位月租费用',
contractname VARCHAR(100) COMMENT '合同类型',
getmethod VARCHAR(100) COMMENT '项目获取渠道',
sign_time VARCHAR(100) COMMENT '签约时间',
contractterm VARCHAR(100) COMMENT '合同期限',
contractpartyname VARCHAR(100) COMMENT '合同对方名称',
propertymgrentrusttype VARCHAR(100) COMMENT '物业管理委托方类型',
is_contractfiled VARCHAR(100) COMMENT '是否办理合同备案',
is_committee VARCHAR(100) COMMENT '是否已成立业主委员会',
CommitteeTime VARCHAR(100) COMMENT '业委会成立时间',
service_day VARCHAR(100) COMMENT '任职时间',
managecontractarea DECIMAL(16,4) COMMENT '管理口径合同面积 【在管面积】',
managekindname VARCHAR(100) COMMENT '管理性质名称 【项目归属】'
)COMMENT = '项目基础信息表';
SELECT
organ_name -- erp片区名称
,comm_name -- erp项目名称
,province -- 省
,city -- 市
,citylevel -- 城市级别
,statename -- 业态 【项目业态】
,projectdeliverysituation -- 项目交付情况
,sold_area -- 已售面积
,unsold_area -- 未售面积
,sold_parking_num -- 已售车位
,unsold_parking_num -- 未售车位
,managestage -- 项目状态
,left(takeovertime,10) as takeovertime -- 交付时间
,commfrom -- 项目来源
,devsubject -- 项目开发商名称
,commaddress -- 项目地址
,is_upload -- 是否有上传项目平面图
,totalarea -- 建筑总面积
,floorarea -- 地上面积
,undergroundarea -- 地下面积
,contractarea -- 合约面积
,takeoverarea -- 在管面积
,CalcArea -- 收费面积
,greenarea -- 绿化面积
,room_num -- 总户数
,delivered_num -- 已交付户数
,rece_num -- 已接房数
,fit_num -- 正在装修户数
,done_fit_num -- 已完成装修户数
,done_fit_no -- 已完成装修未入住
,done_fit_yes -- 已完成装修已入住
,stay_rate -- 入住率
,fit_rate -- 装修率
,PedEntrExitsCount -- 人行出入口数量
,CarEntrExitsCount -- 车行出入口数量
,MixedEntrExitsCount -- 人车混行出入口数量
,TotalEntrExitsCount -- 总出入口数量
,GuardedEntrExitsCount -- 有人值守出入口数量
,MonitoringRoomCount -- 独立监控室数量
,ismonroommergedtogate -- 监控室是否合并至门岗
,ChargeMode -- 收费模式
,high_housing -- 住宅高层
,multi_housing -- 住宅多层
,villa -- 别墅
,town_prope_fee -- 联排物业服务费
,stacking_prope_fee -- 叠拼物业服务费
,house_prope_fee -- 洋房物业费
,apart_prope_fee -- 公寓物业服务费
,shop_prope_fee -- 商铺物业服务费
,office_prope_fee -- 写字楼物业服务费
,kinder_prope_fee -- 学校
,fact_prope_fee -- 公共建筑
,hotel_prope_fee -- 酒店物业服务费
,manage_parking_fee -- 车位管理物业服务费
,month_parking_fee -- 车位月租费用
,contractname -- 合同类型
,getmethod -- 项目获取渠道
,left(sign_time,10) AS sign_time -- 签约时间
,contractterm -- 合同期限
,contractpartyname -- 合同对方名称
,propertymgrentrusttype -- 物业管理委托方类型
,is_contractfiled -- 是否办理合同备案
,is_committee -- 是否已成立业主委员会
,left(CommitteeTime,10) AS CommitteeTime -- 业委会成立时间
,left(service_day,10) AS service_day -- 任职时间
,managecontractarea -- 管理口径合同面积 【在管面积】
,managekindname -- 管理性质名称 【项目归属】'
FROM dim_comm_base_info_d
where 1 = 1
${IF(LEN(p_area)!=0," and organ_code IN ('"+p_area+"')","")}
-- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")}
AND CASE WHEN'${fine_username}' = 'WangXiaoLi0726'
THEN comm_name IN('【眉山】凯旋天域','【眉山】凯旋广场')
WHEN'${fine_username}' = 'SongPan1117'
THEN comm_name IN('【眉山】联想天府云城','【眉山】眉山联想叠云创新科技园三期')
WHEN'${fine_username}' = 'ZhuGuiQiong'
THEN comm_name IN('【眉山】江公丽景B区','【眉山】领地凯旋滨江')
WHEN'${fine_username}' = 'LiXin01'
THEN comm_name IN('【眉山】世代学府','【眉山】九号公馆')
WHEN'${fine_username}' = 'ChenYuHong0906'
THEN comm_name IN('【眉山】领地花屿二期','【眉山】领地凯旋国际公馆二期')
WHEN'${fine_username}' = 'WangJing'
THEN comm_name IN('【乐山】澜山悦','【乐山】领地蘭台府')
ELSE ${if(left(fine_role,2)=="项目","comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")}
-- ======================================
-- 数据集逻辑
-- ======================================
-- ****************************************
-- 创建人员: 杨坤安
-- 创建日期: 2024-07-22
-- 功 能: 帆软明细报表-项目明细弹窗
-- 目 录: xianzuan>2_运营>项目明细弹窗.fvs
-- ****************************************
with one_to_many AS(
SELECT
a.username AS username -- 用户名
,SUBSTRING_INDEX(SUBSTRING_INDEX(a.mang_project, ',',b.help_topic_id + 1),',',-1) AS mang_project -- 管理项目名
FROM ods_one_to_many_perm a
JOIN mysql.help_topic b
on b.help_topic_id < (LENGTH(a.mang_project) - length(replace(a.mang_project,',','')) + 1)
WHERE a.username = '${fine_username}'
)
SELECT
A.ManageKindName , -- 管理性质名称 【项目归属】
A.Province,-- 省
A.City,-- 市
A.Citylevel,-- 城市级别
A.ManageStage,-- 项目状态
A.TakeOverTime,-- 交付时间
A.CommFrom,-- 项目来源
A.DevSubject,-- 项目开发商名称
A.CommAddress,-- 项目地址
CASE
WHEN ProjectFloorPlan IS NULL
OR JSON_EXTRACT( JSON_EXTRACT( cast( A.ProjectFloorPlan AS JSON ), '$[0]' ), '$.FileName' ) IS NULL THEN''
WHEN JSON_EXTRACT( JSON_EXTRACT( cast( A.ProjectFloorPlan AS JSON ), '$[0]' ), '$.FileName' ) IS NOT NULL THEN''
END AS IS_UPLOAD,-- 是否有上传项目平面图 -- 项目平面图
( A.FloorArea + A.UndergroundArea ) AS TotalArea,-- 建筑总面积
A.FloorArea,-- 地上面积
A.UndergroundArea,-- 地下面积
A.GreenArea,-- 绿化面积
A.ContractTerm,
A.PropertyMgrEntrustType,
CASE
WHEN A.IsContractFiled = '1' THEN'' ELSE ''
END AS ,
A.ProjectDeliverySituation,
D.UnsoldParkingCount,
IF( A.PedEntrExitsCount = 0 OR PedEntrExitsCount IS NULL, '-', PedEntrExitsCount ) AS PedEntrExitsCount,
IF( A.CarEntrExitsCount = 0 OR CarEntrExitsCount IS NULL, '-', CarEntrExitsCount ) AS CarEntrExitsCount,
IF( A.MixedEntrExitsCount = 0 OR MixedEntrExitsCount IS NULL, '-', MixedEntrExitsCount ) AS MixedEntrExitsCount,
IF( A.GuardedEntrExitsCount = 0 OR GuardedEntrExitsCount IS NULL, '-', GuardedEntrExitsCount ) AS GuardedEntrExitsCount,
IF( A.MonitoringRoomCount = 0 OR MonitoringRoomCount IS NULL, '-', MonitoringRoomCount ) AS MonitoringRoomCount,
-- TotalEntrExitsCount = PedEntrExitsCount + CarEntrExitsCount +MixedEntrExitsCount
IF( A.PedEntrExitsCount = 0 OR PedEntrExitsCount IS NULL, '-', PedEntrExitsCount )
+ IF( A.CarEntrExitsCount = 0 OR CarEntrExitsCount IS NULL, '-', CarEntrExitsCount )
+ IF( A.MixedEntrExitsCount = 0 OR MixedEntrExitsCount IS NULL, '-', MixedEntrExitsCount ) AS TotalEntrExitsCount,
A.IsMonRoomMergedToGate,
A.ContractArea,-- 合同面积 【建筑面积】
A.TakeOverArea,-- 接管面积 【合约面积】
A.ManageContractArea ManageContractArea,-- 管理口径合同面积 【在管面积】
A.StateName AS StateName,-- 业态 【项目业态】
A.ContractName,-- 合同类型
A.GetMethod,-- 项目获取渠道
A.ContractPartyName,-- 合同对方名称
CASE
WHEN A.IsSetCommittee = '1' THEN'' ELSE ''
END AS ,-- 是否已成立业主委员会
A.CommitteeTime,-- 业委会成立时间
A.ChargeMode,
CONCAT(DATE_FORMAT(A.CommitteeTermStartDate, '%Y-%m-%d' ) , '',DATE_FORMAT(A.CommitteeTermEndDate, '%Y-%m-%d' )) AS ,-- 任职时间
C.room_num AS room_num,-- 总户数
B.organ_name AS organ_name,-- erp片区名称
B.comm_name AS comm_name,-- erp项目名称
C.``,
C.``,
D.``,
C.``,
C.``,
C.``,
C.``,
C.``,
C.``,
(C.`` / C.`` ) AS ,
(C.`` / C.`` ) AS ,
C.,-- 收费面积
A.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.,
G.
FROM
(
SELECT
T.*
,max(T.GetTime) OVER(PARTITION BY T.CommId)AS
FROM
(
SELECT
*
,row_number() OVER(PARTITION BY CommId ORDER BY GetTime DESC) AS RK
FROM dw.dim_project_base_info_d -- 项目维度表
)T
WHERE T.RK = 1
) A
JOIN
(
SELECT
organ_code, -- erp片区id
organ_name, -- erp片区名称
comm_id, -- erp项目id
comm_name -- erp项目名称
FROM dw.dim_organ_mapping -- 片区项目映射维度表
WHERE comm_id IS NOT NULL
AND comm_name NOT LIKE '%撤场%'
AND comm_name NOT LIKE '%案场%'
AND comm_name NOT LIKE '%禁用%'
AND length( comm_id ) != 0
${IF(LEN(p_area)!=0," and organ_code IN ('"+p_area+"')","")}
-- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")}
AND CASE WHEN (SELECT mang_project FROM ods_one_to_many_perm WHERE username = '${fine_username}') IS NOT NULL
THEN comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}')
ELSE ${if(left(fine_role,2)=="项目","comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")}
END
GROUP BY
organ_code, -- erp片区id
organ_name, -- erp片区名称
comm_id, -- erp项目id
comm_name -- erp项目名称
)B
ON A.CommId = B.comm_id
LEFT JOIN
(
SELECT
a.CommID
,SUM(CASE WHEN a.roomstate <> 0 THEN 1 ELSE 0 END) AS room_num, -- 项目对应房间数量
SUM( CASE WHEN a.roomstate IN ( '1', '4', '9', '10', '5', '6' ) THEN a.buildarea ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate = '2' THEN a.buildarea ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate NOT IN('0','2') THEN 1 ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate IN ( '4', '9', '10', '5', '6' ) THEN 1 ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate = '4' THEN 1 ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate IN ( '9', '10', '5', '6' ) THEN 1 ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate = '5' THEN 1 ELSE 0 END ) AS ,
SUM( CASE WHEN a.roomstate IN ( '9', '10', '6' ) THEN 1 ELSE 0 END ) AS ,
-- SUM(b.CalcArea) AS 收费面积
-- 2024-09-20更新取数新逻辑石老师确认 收费面积从房间表取
SUM(CASE WHEN a.roomstate IS NOT NULL AND a.roomstate <> '' THEN a.CalcArea ELSE 0 END) AS
FROM
(
SELECT
*
FROM dw.dim_room_d
)a
LEFT JOIN
(
SELECT
b1.CommId AS CommId
,b1.RoomID AS RoomID
,SUM(CalcArea) AS CalcArea
FROM
(
SELECT
CommId
, CalcArea
, RoomID
FROM ods_erp_tb_hspr_coststansetting_d
WHERE RoomID <> '0'
GROUP BY CommId, CalcArea, RoomID
)b1
GROUP BY b1.CommId,b1.RoomID
)b
ON a.CommID = b.CommId
AND a.RoomID = b.RoomID
GROUP BY CommID
)C
ON A.CommId = C.CommID
LEFT JOIN
(
SELECT
CommID
,SUM( CASE WHEN ParkingState IN ( '0001', '0003' ) THEN 1 ELSE 0 END ) AS
,SUM(CASE WHEN ParkingState IN ( '0002', '0004' ) THEN 1 ELSE 0 END) AS UnsoldParkingCount
FROM ods_erp_tb_hspr_parking_d
WHERE IsDelete = '0'
GROUP BY
CommID
)D
ON A.COMMID = D.COMMID
LEFT JOIN
(
SELECT
A.CommId
-- 住宅高层
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN ('高层物业服务费', '电梯电费', '公共能耗费') THEN ROUND(ROUND(B.StanAmount,2),2) END),',','\n'),'-') AS
-- 住宅多层
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN ('多层物业服务费', '公共能耗费') THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 别墅
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN ('别墅物业服务费', '公共能耗费') THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 联排物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%联排%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 叠拼物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%叠拼%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 洋房物业费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%洋房%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 公寓物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%公寓%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 商铺物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%商铺%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 写字楼物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%写字楼%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 幼儿园物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%幼儿园%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 厂区物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%厂区%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 酒店物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName LIKE '%酒店%' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 车位管理物业服务费
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName IN('车位管理物业服务费','车位物业服务费') THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
-- 车位月租费用
,IFNULL(REPLACE(group_concat(CASE WHEN B.CostName = '车位月租' THEN ROUND(B.StanAmount,2) END),',','\n'),'-') AS
FROM
(
SELECT
DISTINCT
CommID
,CostID
,StanID
FROM dim_bind_cost_stan_detail_d -- 绑定的收费标准明细
-- WHERE CommID = '214330'
)A
LEFT JOIN
(
SELECT
B1.CommID AS CommID
,B1.COSTID AS COSTID
,B1.StanID AS StanID
,B1.StanAmount AS StanAmount
,B2.COSTNAME AS COSTNAME
FROM
(
SELECT
CommID
,COSTID
,StanID
,StanAmount
FROM dim_cost_stand_d -- 小区收费标准
WHERE StanAmount <> 0
)B1
LEFT JOIN
(
SELECT
distinct
COMMID
,COSTID
,COSTNAME
FROM dim_costitem_d -- 项目上的费用名称
)B2
ON B1.CommID = B2.COMMID
AND B1.CostID = B2.COSTID
)B
ON A.CommID = B.COMMID
AND A.CostID = B.COSTID
AND A.StanID = B.StanID
GROUP BY
A.CommId
)G
ON A.COMMID = G.COMMID
;