-- **************************************** -- 创建人员: 杨坤安 -- 创建日期: 2024-07-22 -- 功 能: 帆软明细报表-项目明细弹窗 -- 目 录: xianzuan>2_运营>项目明细弹窗.fvs -- **************************************** SELECT-- ${if(len(p_area) == 0,"B.organ_name","B.comm_name")} as p_area -- ,A.CommId AS CommId -- 项目id 可关联maping表 -- ${if(len(p_area) == 0,",'-'",",A.ManageKindName")} as newManageKind -- ,A.ManageKind AS ManageKind -- 管理性质 【项目归属】 A.ManageKindName AS 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, A.IsMonRoomMergedToGate, A.ContractArea , -- 合同面积 【建筑面积】 A.TakeOverArea , -- 接管面积 【合约面积】 A.ManageContractArea ManageContractArea, -- 管理口径合同面积 【在管面积】 -- ${if(len(p_area) == 0,",'-'",",A.StateName")} as newStateName 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 ,-- 总户数 -- ,A.Province AS Province -- 省 -- ,A.City AS City -- 市 -- ,A.County AS County -- 区 B.organ_code AS organ_code, -- erp片区id B.organ_name AS organ_name, -- erp片区名称 -- ,B.comm_id AS -- erp项目id B.comm_name AS comm_name, -- erp项目名称 D.`已售面积`, D.`未售面积` , E.`已售车位`, F.`已交付户数`, F.`已接房数`, F.`正在装修户数`, F.`已完成装修户数`, F.`已完成装修未入住`, F.`已完成装修已入住`,( F.`已完成装修已入住` / F.`已交付户数` ) AS 入住率,( F.`已完成装修户数` / F.`已交付户数` ) AS 装修率, G.收费面积, -- 收费面积 H.签约时间, I.住宅高层, I.住宅多层, I.别墅, I.联排物业服务费, I.叠拼物业服务费, I.洋房物业费, I.公寓物业服务费, I.商铺物业服务费, I.写字楼物业服务费, I.幼儿园物业服务费, I.厂区物业服务费, I.酒店物业服务费, I.车位管理物业服务费, I.车位月租费用 FROM dw.dim_project_base_info_d 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 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, count( 1 ) AS room_num -- 项目对应房间数量 FROM dw.dim_room_d GROUP BY CommID ) C ON A.CommId = C.CommID LEFT JOIN ( SELECT CommID, 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 未售面积 FROM dim_room_d GROUP BY CommID ) D ON A.COMMID = D.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 ) E ON A.COMMID = E.COMMID LEFT JOIN ( SELECT CommID, 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 dim_room_d GROUP BY CommID ) F ON A.COMMID = F.COMMID LEFT JOIN ( SELECT CommId, SUM(CalcArea) AS 收费面积 FROM dim_bind_cost_stan_detail_d GROUP BY CommId ) G ON A.COMMID = G.COMMID LEFT JOIN ( SELECT commid,max(GetTime) AS 签约时间 FROM dim_project_base_info_d GROUP BY CommId ) H ON A.COMMID = H.COMMID LEFT JOIN ( SELECT A.CommId, CASE WHEN SUM(CASE WHEN B.CostName IN ('高层物业服务费', '电梯电费', '公共能耗费') THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName IN ('高层物业服务费', '电梯电费', '公共能耗费') THEN StanAmount ELSE 0 END) END AS 住宅高层, -- 住宅多层 CASE WHEN SUM(CASE WHEN B.CostName IN ('多层物业服务费', '公共能耗费') THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName IN ('多层物业服务费', '公共能耗费') THEN StanAmount ELSE 0 END) END AS 住宅多层, -- 别墅 CASE WHEN SUM(CASE WHEN B.CostName IN ('别墅物业服务费', '公共能耗费') THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName IN ('别墅物业服务费', '公共能耗费') THEN StanAmount ELSE 0 END) END AS 别墅, -- 联排物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '联排物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '联排物业服务费' THEN StanAmount ELSE 0 END) END AS 联排物业服务费, -- 叠拼物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '叠拼物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '叠拼物业服务费' THEN StanAmount ELSE 0 END) END AS 叠拼物业服务费, -- 洋房物业费 CASE WHEN SUM(CASE WHEN B.CostName = '洋房物业费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '洋房物业费' THEN StanAmount ELSE 0 END) END AS 洋房物业费, -- 公寓物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '公寓物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '公寓物业服务费' THEN StanAmount ELSE 0 END) END AS 公寓物业服务费, -- 商铺物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '商铺物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '商铺物业服务费' THEN StanAmount ELSE 0 END) END AS 商铺物业服务费, -- 写字楼物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '写字楼物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '写字楼物业服务费' THEN StanAmount ELSE 0 END) END AS 写字楼物业服务费, -- 幼儿园物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '幼儿园物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '幼儿园物业服务费' THEN StanAmount ELSE 0 END) END AS 幼儿园物业服务费, -- 厂区物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '厂区物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '厂区物业服务费' THEN StanAmount ELSE 0 END) END AS 厂区物业服务费, -- 酒店物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '酒店物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '酒店物业服务费' THEN StanAmount ELSE 0 END) END AS 酒店物业服务费, -- 车位管理物业服务费 CASE WHEN SUM(CASE WHEN B.CostName = '车位管理物业服务费' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '车位管理物业服务费' THEN StanAmount ELSE 0 END) END AS 车位管理物业服务费, -- 车位月租费用 CASE WHEN SUM(CASE WHEN B.CostName = '车位月租' THEN StanAmount ELSE 0 END) = 0 THEN '-' ELSE SUM(CASE WHEN B.CostName = '车位月租' THEN StanAmount ELSE 0 END) END AS 车位月租费用 FROM dim_cost_stand_d A LEFT JOIN (SELECT distinct COMMID, COSTID,COSTNAME FROM dim_costitem_d) B ON A.CommID = B.COMMID AND A.CostID = B.COSTID GROUP BY A.CommId ) I ON A.COMMID = I.COMMID where 1 = 1 ${IF(LEN(p_area)!=0," and B.organ_code IN ('"+p_area+"')","")} ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")}