-- **************************************** -- 创建人员: 杨坤安 -- 创建日期: 2024-07-22 -- 功 能: 帆软明细报表-项目明细弹窗 -- 目 录: xianzuan>2_运营>项目明细弹窗.fvs -- **************************************** 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, A.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( CommitteeTermEndDate, '%Y-%m-%d' ), ' 至 ', DATE_FORMAT( CommitteeTermStartDate, '%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 装修率, E.收费面积,-- 收费面积 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)+"'","")} 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 CommID ,SUM(CASE WHEN roomstate <> 0 THEN 1 ELSE 0 END) AS room_num, -- 项目对应房间数量 SUM( CASE WHEN roomstate IN ( '1', '4', '9', '10', '5', '6' ) THEN buildarea ELSE 0 END ) AS 已售面积, SUM( CASE WHEN roomstate = '2' THEN buildarea ELSE 0 END ) AS 未售面积, SUM( CASE WHEN SaleState = '已售' THEN 1 ELSE 0 END ) AS 已交付户数, SUM( CASE WHEN roomstate IN ( '4', '9', '10', '5', '6' ) THEN 1 ELSE 0 END ) AS 已接房数, SUM( CASE WHEN roomstate = '4' THEN 1 ELSE 0 END ) AS 正在装修户数, SUM( CASE WHEN roomstate IN ( '9', '10', '5', '6' ) THEN 1 ELSE 0 END ) AS 已完成装修户数, SUM( CASE WHEN roomstate = '5' THEN 1 ELSE 0 END ) AS 已完成装修未入住, SUM( CASE WHEN roomstate IN ( '9', '10', '6' ) THEN 1 ELSE 0 END ) AS 已完成装修已入住 FROM dw.dim_room_d 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 已售车位 FROM ods_erp_tb_hspr_parking_d GROUP BY CommID )D ON A.COMMID = D.COMMID LEFT JOIN ( SELECT A.CommId AS CommId ,SUM(A.CalcArea ) AS 收费面积 FROM ( SELECT CommId ,CalcArea ,RoomID FROM dim_bind_cost_stan_detail_d WHERE RoomID <> 0 GROUP BY CommId ,CalcArea ,RoomID )A group BY A.CommId )E ON A.COMMID = E.COMMID LEFT JOIN ( SELECT A.CommId, IFNULL(group_concat(CASE WHEN B.CostName IN ('高层物业服务费', '电梯电费', '公共能耗费') THEN ROUND(ROUND(B.StanAmount,2),2) END),'-') AS 住宅高层, -- 住宅多层 IFNULL(group_concat(CASE WHEN B.CostName IN ('多层物业服务费', '公共能耗费') THEN ROUND(B.StanAmount,2) END),'-') AS 住宅多层, -- 别墅 IFNULL(group_concat(CASE WHEN B.CostName IN ('别墅物业服务费', '公共能耗费') THEN ROUND(B.StanAmount,2) END),'-') AS 别墅, -- 联排物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '联排物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 联排物业服务费, -- 叠拼物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '叠拼物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 叠拼物业服务费, -- 洋房物业费 IFNULL(group_concat(CASE WHEN B.CostName = '洋房物业费' THEN ROUND(B.StanAmount,2) END),'-') AS 洋房物业费, -- 公寓物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '公寓物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 公寓物业服务费, -- 商铺物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '商铺物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 商铺物业服务费, -- 写字楼物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '写字楼物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 写字楼物业服务费, -- 幼儿园物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '幼儿园物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 幼儿园物业服务费, -- 厂区物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '厂区物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 厂区物业服务费, -- 酒店物业服务费 IFNULL(group_concat(CASE WHEN B.CostName = '酒店物业服务费' THEN ROUND(B.StanAmount,2) END),'-') AS 酒店物业服务费, -- 车位管理物业服务费 IFNULL(group_concat(CASE WHEN B.CostName IN('车位管理物业服务费','车位物业服务费') THEN ROUND(B.StanAmount,2) END),'-') AS 车位管理物业服务费, -- 车位月租费用 IFNULL(group_concat(CASE WHEN B.CostName = '车位月租' THEN ROUND(B.StanAmount,2) END),'-') 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