HouseResourceMapMapper.java 14 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617
  1. package com.nokia.financeapi.dao.house;
  2. import com.nokia.financeapi.pojo.dto.GetBuildingAreaStatDto;
  3. import com.nokia.financeapi.pojo.dto.GetBuildingMapDto;
  4. import com.nokia.financeapi.pojo.dto.GetBuildingOptionsDto;
  5. import com.nokia.financeapi.pojo.dto.GetBuildingRepairStatDto;
  6. import com.nokia.financeapi.pojo.dto.GetHouseNoticeDto;
  7. import com.nokia.financeapi.pojo.dto.GetLandBuildingStatDto;
  8. import com.nokia.financeapi.pojo.vo.GetBuildingAreaStatVo;
  9. import com.nokia.financeapi.pojo.vo.GetBuildingMapVo;
  10. import com.nokia.financeapi.pojo.vo.GetBuildingOptionsVo;
  11. import com.nokia.financeapi.pojo.vo.GetBuildingRepairStatVo;
  12. import com.nokia.financeapi.pojo.vo.GetHouseNoticeVo;
  13. import com.nokia.financeapi.pojo.vo.GetLandBuildingStatVo;
  14. import org.apache.ibatis.annotations.Mapper;
  15. import org.apache.ibatis.annotations.Param;
  16. import org.apache.ibatis.annotations.Select;
  17. import java.util.List;
  18. @Mapper
  19. public interface HouseResourceMapMapper {
  20. /**
  21. * 获取最新月份全省或地市的建筑面积统计
  22. */
  23. @Select("""
  24. <script>
  25. with
  26. t1 as (
  27. select
  28. sum(case when building_use = '综合用房' then building_area else 0 end) as area_synthesis,
  29. sum(case when building_use = '设备用房' then building_area else 0 end) as area_equipment,
  30. sum(case when building_use = '营销用房' then building_area else 0 end) as area_marketing,
  31. sum(case when building_use = '附属用房' then building_area else 0 end) as area_affiliate,
  32. sum(case when building_use = '行政用房' then building_area else 0 end) as area_administration,
  33. sum(case when building_use not in ('综合用房', '设备用房', '营销用房', '附属用房', '行政用房') then building_area else 0 end) as area_other,
  34. sum(building_area_self_use) as area_self_use,
  35. sum(building_area_rent) as area_rent,
  36. sum(building_area) - sum(building_area_self_use) - sum(building_area_rent) as area_unused,
  37. sum(building_area) as area_total
  38. from
  39. house.building_month
  40. where
  41. year_month = (
  42. select
  43. max(year_month)
  44. from
  45. house.building_month)
  46. <if test="dto.city != null and dto.city != ''">
  47. and city = #{dto.city}
  48. </if>
  49. )
  50. select
  51. round(area_self_use / 10000, 2) as area_self_use,
  52. round(area_rent / 10000, 2) as area_rent,
  53. round(area_unused / 10000, 2) as area_unused,
  54. round(area_synthesis / area_total * 100, 2) as percent_synthesis,
  55. round(area_equipment / area_total * 100, 2) as percent_equipment,
  56. round(area_marketing / area_total * 100, 2) as percent_marketing,
  57. round(area_affiliate / area_total * 100, 2) as percent_affiliate,
  58. round(area_administration / area_total * 100, 2) as percent_administration,
  59. round(area_other / area_total * 100, 2) as percent_other,
  60. round(area_self_use / area_total * 100, 2) as percent_self_use,
  61. round(area_rent / area_total * 100, 2) as percent_rent,
  62. round(area_unused / area_total * 100, 2) as percent_unused
  63. from t1
  64. </script>
  65. """)
  66. GetBuildingAreaStatVo getBuildingAreaStat(@Param("dto") GetBuildingAreaStatDto dto);
  67. /**
  68. * 统计最新月份各个地市的建筑和土地数量
  69. */
  70. @Select("""
  71. with
  72. t1 as (
  73. select
  74. city as area_name,
  75. count(1) as building_count
  76. from
  77. house.building_month
  78. where
  79. year_month = (
  80. select
  81. max(year_month)
  82. from
  83. house.building_month)
  84. group by
  85. city
  86. ),
  87. t2 as (
  88. select
  89. city as area_name,
  90. count(1) as land_count
  91. from
  92. house.land_month
  93. where
  94. year_month = (
  95. select
  96. max(year_month)
  97. from
  98. house.land_month)
  99. group by
  100. city
  101. )
  102. select
  103. t1.area_name,
  104. t1.building_count,
  105. t2.land_count
  106. from
  107. t1
  108. join t2 on
  109. t1.area_name = t2.area_name
  110. order by
  111. t1.area_name
  112. """)
  113. List<GetLandBuildingStatVo> getCityLandBuildingStat();
  114. /**
  115. * 统计最新月份某地市各个区县的建筑和土地数量
  116. */
  117. @Select("""
  118. <script>
  119. with
  120. t1 as (
  121. select
  122. district as area_name,
  123. count(1) as building_count
  124. from
  125. house.building_month
  126. where
  127. city = #{dto.city}
  128. and district is not null
  129. and district != ''
  130. and year_month = (
  131. select
  132. max(year_month)
  133. from
  134. house.building_month)
  135. group by
  136. district
  137. ),
  138. t2 as (
  139. select
  140. district as area_name,
  141. count(1) as land_count
  142. from
  143. house.land_month
  144. where
  145. city = #{dto.city}
  146. and district is not null
  147. and district != ''
  148. and year_month = (
  149. select
  150. max(year_month)
  151. from
  152. house.land_month)
  153. group by
  154. district
  155. )
  156. select
  157. t1.area_name,
  158. t1.building_count,
  159. t2.land_count
  160. from
  161. t1
  162. join t2 on
  163. t1.area_name = t2.area_name
  164. order by t1.area_name
  165. </script>
  166. """)
  167. List<GetLandBuildingStatVo> getDistrictLandBuildingStat(@Param("dto") GetLandBuildingStatDto dto);
  168. /**
  169. * 获取建筑数据最新的日期
  170. */
  171. @Select("""
  172. select max(year_month) from house.building_month
  173. """)
  174. Integer getBuildingMonthMaxDate();
  175. /**
  176. * 获取区县最大面积建筑
  177. */
  178. @Select("""
  179. with
  180. t101 as (
  181. select
  182. *
  183. from
  184. house.building_month
  185. where
  186. lng_bd09 is not null
  187. and lat_bd09 is not null
  188. and year_month = #{dto.endDate}
  189. and city = #{dto.city}
  190. and district = #{dto.district}
  191. order by
  192. building_area desc
  193. limit 10
  194. ),
  195. t102 as (
  196. select
  197. building_id,
  198. sum(amount) as maintenance_cost
  199. from
  200. house.building_repair_main_month
  201. where
  202. repair_type != '财务预提冲销'
  203. and exists (select 1 from t101 where t101.building_id = house.building_repair_main_month.building_id)
  204. and year_month >= #{dto.startDate}
  205. and year_month <= #{dto.endDate}
  206. group by
  207. building_id
  208. ),
  209. t103 as (
  210. select
  211. t101.*,
  212. t102.maintenance_cost
  213. from t101 left join t102 on t101.building_id = t102.building_id
  214. )
  215. select
  216. building_id,
  217. site_num,
  218. address,
  219. area_sector,
  220. building_name,
  221. acquisition_date,
  222. building_use,
  223. building_area,
  224. building_area_idle,
  225. building_area_rent,
  226. round(maintenance_cost, 2) as maintenance_cost,
  227. building_img,
  228. lng_bd09 as lng,
  229. lat_bd09 as lat
  230. from
  231. t103
  232. order by
  233. building_area desc
  234. """)
  235. List<GetBuildingMapVo> getBuildingByDistrict(@Param("dto") GetBuildingMapDto dto);
  236. /**
  237. * 获取坐标范围内的建筑,相同坐标保留建筑面积最大的
  238. */
  239. @Select("""
  240. with
  241. t101 as (
  242. select
  243. *
  244. from
  245. house.building_month
  246. where
  247. year_month = #{dto.endDate}
  248. and lng_bd09 >= #{dto.leftLng}
  249. and lng_bd09 <= #{dto.rightLng}
  250. and lat_bd09 >= #{dto.leftLat}
  251. and lat_bd09 <= #{dto.rightLat}
  252. ),
  253. t102 as (
  254. select
  255. distinct on
  256. (lng_bd09, lat_bd09) *
  257. from
  258. t101
  259. order by
  260. lng_bd09,
  261. lat_bd09,
  262. building_area desc
  263. ),
  264. t103 as (
  265. select
  266. building_id,
  267. sum(amount) as maintenance_cost
  268. from
  269. house.building_repair_main_month
  270. where
  271. repair_type != '财务预提冲销'
  272. and exists (select 1 from t102 where t102.building_id = house.building_repair_main_month.building_id)
  273. and year_month >= #{dto.startDate}
  274. and year_month <= #{dto.endDate}
  275. group by
  276. building_id
  277. ),
  278. t104 as (
  279. select
  280. t102.*,
  281. t103.maintenance_cost
  282. from t102 left join t103 on t102.building_id = t103.building_id
  283. )
  284. select
  285. building_id,
  286. site_num,
  287. address,
  288. area_sector,
  289. building_name,
  290. acquisition_date,
  291. building_use,
  292. building_area,
  293. building_area_idle,
  294. building_area_rent,
  295. round(maintenance_cost, 2) as maintenance_cost,
  296. building_img,
  297. lng_bd09 as lng,
  298. lat_bd09 as lat
  299. from
  300. t104
  301. order by
  302. building_area desc
  303. limit 150
  304. """)
  305. List<GetBuildingMapVo> getBuildingByCoordinate(@Param("dto") GetBuildingMapDto dto);
  306. /**
  307. * 统计最新年份各个地市的维修费
  308. */
  309. @Select("""
  310. with
  311. t1 as (
  312. select
  313. city,
  314. sum(case when repair_type = '零星维修' then amount else 0 end) as odd_sum,
  315. sum(amount) as total_sum
  316. from
  317. house.building_repair_main_month
  318. where
  319. repair_type != '财务预提冲销'
  320. and year_num = (
  321. select
  322. max(year_num)
  323. from
  324. house.building_repair_main_month)
  325. group by
  326. city
  327. ),
  328. t2 as (
  329. select
  330. *,
  331. case
  332. when total_sum = 0 then 0
  333. else odd_sum / total_sum * 100
  334. end as odd_percent
  335. from
  336. t1
  337. ),
  338. t3 as (
  339. select
  340. *
  341. from t2 left join house.second_unit_sort on t2.city = house.second_unit_sort.second_unit
  342. order by house.second_unit_sort.sort desc
  343. )
  344. select
  345. city as area_name,
  346. round(odd_sum / 10000,
  347. 2) as odd_sum,
  348. round(total_sum / 10000,
  349. 2) as total_sum,
  350. round(odd_percent,
  351. 2) as odd_percent
  352. from
  353. t3
  354. """)
  355. List<GetBuildingRepairStatVo> getCityRepairStat();
  356. /**
  357. * 统计最新年份某个地市的各个区县的维修费
  358. */
  359. @Select("""
  360. with
  361. t1 as (
  362. select
  363. city,
  364. district,
  365. sum(case when repair_type = '零星维修' then amount else 0 end) as odd_sum,
  366. sum(amount) as total_sum
  367. from
  368. house.building_repair_main_month
  369. where
  370. repair_type != '财务预提冲销'
  371. and year_num = (
  372. select
  373. max(year_num)
  374. from
  375. house.building_repair_main_month)
  376. and district is not null
  377. and district != ''
  378. and city = #{dto.city}
  379. group by
  380. city,
  381. district
  382. ),
  383. t2 as (
  384. select
  385. *,
  386. case
  387. when total_sum = 0 then 0
  388. else odd_sum / total_sum * 100
  389. end as odd_percent
  390. from
  391. t1
  392. )
  393. select
  394. district as area_name,
  395. round(odd_sum / 10000,
  396. 2) as odd_sum,
  397. round(total_sum / 10000,
  398. 2) as total_sum,
  399. round(odd_percent,
  400. 2) as odd_percent
  401. from
  402. t2
  403. order by
  404. total_sum
  405. """)
  406. List<GetBuildingRepairStatVo> getDistrictRepairStat(@Param("dto") GetBuildingRepairStatDto dto);
  407. /**
  408. * 获取不动产公告
  409. */
  410. @Select("""
  411. select * from house.notices
  412. where city = #{dto.city}
  413. order by create_time desc
  414. """)
  415. List<GetHouseNoticeVo> getNotice(@Param("dto") GetHouseNoticeDto dto);
  416. /**
  417. * 获取区县内的建筑,相同坐标保留建筑面积最大的
  418. */
  419. @Select("""
  420. with
  421. t101 as (
  422. select
  423. distinct on
  424. (lng_bd09, lat_bd09) *
  425. from
  426. house.building_month
  427. where
  428. lng_bd09 is not null
  429. and lat_bd09 is not null
  430. and year_month = #{dto.endDate}
  431. and city = #{dto.city}
  432. and district = #{dto.district}
  433. order by
  434. lng_bd09,
  435. lat_bd09,
  436. building_area desc
  437. ),
  438. t102 as (
  439. select
  440. building_id,
  441. sum(amount) as maintenance_cost
  442. from
  443. house.building_repair_main_month
  444. where
  445. repair_type != '财务预提冲销'
  446. and exists (select 1 from t101 where t101.building_id = house.building_repair_main_month.building_id)
  447. and year_month >= #{dto.startDate}
  448. and year_month <= #{dto.endDate}
  449. group by
  450. building_id
  451. ),
  452. t103 as (
  453. select
  454. t101.*,
  455. t102.maintenance_cost
  456. from t101 left join t102 on t101.building_id = t102.building_id
  457. )
  458. select
  459. building_id,
  460. site_num,
  461. address,
  462. area_sector,
  463. building_name,
  464. acquisition_date,
  465. building_use,
  466. building_area,
  467. building_area_idle,
  468. building_area_rent,
  469. round(maintenance_cost, 2) as maintenance_cost,
  470. building_img,
  471. lng_bd09 as lng,
  472. lat_bd09 as lat
  473. from
  474. t103
  475. order by
  476. building_area desc
  477. """)
  478. List<GetBuildingOptionsVo> getBuildingOptions(@Param("dto") GetBuildingOptionsDto dto);
  479. /**
  480. * 获取省本部建筑选项,相同坐标保留建筑面积最大的
  481. */
  482. @Select("""
  483. with
  484. t101 as (
  485. select
  486. distinct on
  487. (lng_bd09, lat_bd09) *
  488. from
  489. house.building_month
  490. where
  491. lng_bd09 is not null
  492. and lat_bd09 is not null
  493. and year_month = #{dto.endDate}
  494. and area_name = #{dto.city}
  495. order by
  496. lng_bd09,
  497. lat_bd09,
  498. building_area desc
  499. ),
  500. t102 as (
  501. select
  502. building_id,
  503. sum(amount) as maintenance_cost
  504. from
  505. house.building_repair_main_month
  506. where
  507. repair_type != '财务预提冲销'
  508. and exists (select 1 from t101 where t101.building_id = house.building_repair_main_month.building_id)
  509. and year_month >= #{dto.startDate}
  510. and year_month <= #{dto.endDate}
  511. group by
  512. building_id
  513. ),
  514. t103 as (
  515. select
  516. t101.*,
  517. t102.maintenance_cost
  518. from t101 left join t102 on t101.building_id = t102.building_id
  519. )
  520. select
  521. building_id,
  522. site_num,
  523. address,
  524. area_sector,
  525. building_name,
  526. acquisition_date,
  527. building_use,
  528. building_area,
  529. building_area_idle,
  530. building_area_rent,
  531. round(maintenance_cost, 2) as maintenance_cost,
  532. building_img,
  533. lng_bd09 as lng,
  534. lat_bd09 as lat
  535. from
  536. t103
  537. order by
  538. building_area desc
  539. """)
  540. List<GetBuildingOptionsVo> getSbbBuildingOptions(@Param("dto") GetBuildingOptionsDto dto);
  541. /**
  542. * 获取省本部建筑,相同坐标保留建筑面积最大的
  543. */
  544. @Select("""
  545. with
  546. t101 as (
  547. select
  548. distinct on
  549. (lng_bd09, lat_bd09) *
  550. from
  551. house.building_month
  552. where
  553. lng_bd09 is not null
  554. and lat_bd09 is not null
  555. and year_month = #{dto.endDate}
  556. and area_name = #{dto.city}
  557. order by
  558. lng_bd09,
  559. lat_bd09,
  560. building_area desc
  561. ),
  562. t102 as (
  563. select
  564. building_id,
  565. sum(amount) as maintenance_cost
  566. from
  567. house.building_repair_main_month
  568. where
  569. repair_type != '财务预提冲销'
  570. and exists (select 1 from t101 where t101.building_id = house.building_repair_main_month.building_id)
  571. and year_month >= #{dto.startDate}
  572. and year_month <= #{dto.endDate}
  573. group by
  574. building_id
  575. ),
  576. t103 as (
  577. select
  578. t101.*,
  579. t102.maintenance_cost
  580. from t101 left join t102 on t101.building_id = t102.building_id
  581. )
  582. select
  583. building_id,
  584. site_num,
  585. address,
  586. area_sector,
  587. building_name,
  588. acquisition_date,
  589. building_use,
  590. building_area,
  591. building_area_idle,
  592. building_area_rent,
  593. round(maintenance_cost, 2) as maintenance_cost,
  594. building_img,
  595. lng_bd09 as lng,
  596. lat_bd09 as lat
  597. from
  598. t103
  599. order by
  600. building_area desc
  601. """)
  602. List<GetBuildingMapVo> getSbbBuildings(@Param("dto") GetBuildingMapDto dto);
  603. }