This repository has been archived by the owner on Oct 12, 2023. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 0
/
BoardMapper.xml
311 lines (292 loc) · 13 KB
/
BoardMapper.xml
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
<?xml version="1.0" encoding="UTF-8" ?>
<!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN"
"http://mybatis.org/dtd/mybatis-3-mapper.dtd">
<mapper namespace="com.pozafly.tripllo.board.dao.BoardDao">
<select id="readBoardOne" parameterType="Long" resultType="com.pozafly.tripllo.board.model.Board">
select *
from board
where id = #{boardId}
</select>
<select id="readPersonalBoardList" parameterType="Map" resultType="com.pozafly.tripllo.board.model.Board">
select
a.id,
a.title,
a.bg_color,
a.public_yn,
a.hashtag,
a.like_count,
a.created_at,
a.created_by,
EXISTS
(
select 1
from board_has_like
where board_id = a.id and user_id = #{userId}
) as own_like
from board a
where a.created_by = #{userId}
<choose>
<when test='"firstCall".equals(lastCreatedAt)'>
order by created_at desc
limit 14
</when>
<otherwise>
and created_at <![CDATA[ < ]]> #{lastCreatedAt}
order by created_at desc
limit 6
</otherwise>
</choose>
</select>
<select id="readSearchUserBoard" parameterType="Map" resultType="com.pozafly.tripllo.board.model.Board">
select
a.id,
a.title,
a.bg_color,
a.public_yn,
a.hashtag,
a.like_count,
a.created_at,
a.created_by,
EXISTS
(
select 1
from board_has_like
where board_id = a.id and user_id = #{userId}
) as own_like
from board a
where a.created_by = #{searchUser}
and a.public_yn = 'Y'
<choose>
<when test='"firstCall".equals(lastCreatedAt)'>
order by created_at desc
limit 16
</when>
<otherwise>
and created_at <![CDATA[ < ]]> #{lastCreatedAt}
order by created_at desc
limit 8
</otherwise>
</choose>
</select>
<select id="rerenderBoard" parameterType="Map" resultType="com.pozafly.tripllo.board.model.Board">
select
a.id,
a.title,
a.bg_color,
a.public_yn,
a.hashtag,
a.like_count,
a.created_at,
a.created_by,
EXISTS
(
select 1
from board_has_like
where board_id = a.id and user_id = #{userId}
) as own_like
from board a
where a.created_by = #{userId}
order by created_at desc
<if test='count != null and !"".equals(count)'>
limit #{count}
</if>
</select>
<select id="boardCount" parameterType="Long" resultType="int">
select
count(*)
from board
where id = #{boardId}
</select>
<select id="readRecentBoards" parameterType="Map" resultType="com.pozafly.tripllo.board.model.Board">
select
a.id,
a.title,
a.bg_color,
a.public_yn,
a.hashtag,
a.like_count,
a.created_at,
a.created_by,
EXISTS
(
select 1
from board_has_like
where board_id = a.id and user_id = #{userId}
) as own_like
from board a
where a.id in
<foreach collection="recentList" item="item" open="(" separator="," close=")">
#{item}
</foreach>
order by Field (id,
<foreach collection="recentList" item="item" open="" separator="," close=")">
#{item}
</foreach>
limit 3
</select>
<select id="readInvitedBoards" parameterType="Map" resultType="com.pozafly.tripllo.board.model.Board">
select
a.id,
a.title,
a.bg_color,
a.public_yn,
a.hashtag,
a.like_count,
a.created_at,
a.created_by,
EXISTS
(
select 1
from board_has_like
where board_id = a.id and user_id = #{userId}
) as own_like
from board a
where a.id in
<foreach collection="invitedList" item="item" open="(" separator="," close=")">
#{item}
</foreach>
order by Field (id,
<foreach collection="invitedList" item="item" open="" separator="," close=")">
#{item}
</foreach>
</select>
<!--
1:N 설명 :
먼저, board는 다수의 list를 가지고 list는 다수의 card를 가지는 관계이다.
이 녀석을 boardId 하나로 조회하기 위해서 select id="readBoardDetail" 태그와 같이 left outer join으로 해당 데이터를 모두 조회해와야 한다.
그러면 카드 갯수만큼의 레코드가 생기게 되고 그걸 그냥 반환하면 어느 board의 어느 list, card인지가 판변이 불가능함. 따라서 List, Map으로 점철된 코드를
생성해내야 하는데, Mybatis의 resultMap, collection 태그를 사용하여 1:N 관계의 표현을 나타낼 수 있다.
1. 먼저 조회한 칼럼 갯수만큼 model을 만들어 두고 dao에 return 타입으로 준다.
2. 각각의 들어갈 ResultMap Class를 생성하여 @Data를 붙여주고 칼럼명을 적어두자. 기존에 class가 있지만, 따로 생성해두는 이유는
private List<ListResultMap> lists;
이런 식으로 List<> 형식으로 둔 객체를 생성해야하는데 다른 곳에서 조회 시, lists가 같이 붙어서 나오므로 새로 생성하여 매핑해두었다.
3. xml에 resultMap 을 3개 생성한다. type은 빈 객체를 매핑시켜준다.
4. ResultMap
-ResultMap의 id : 쿼리문이 들어가는 select 태그의 resultMap의 이름이거나, 다른 resultMap에서 부를 이름.
-ResultMap의 type : 아까 생성한 ResultMap class 명. 즉, 리턴 타입아다.
-id : PK를 적어둔다. (foreign key와는 다르게 해당 테이블의 기본키만 적는다.)
-result : 빈 객체 안의 칼럼을 하나씩 적어둔다.
-property : 빈 객체의 선언된 변수 명.
-column : 쿼리 조회 시 리턴 될 칼럼 명.
-collection : List나 Map으로 매핑될 녀석을 선언 하는 태그.
-property : 빈 객체에 선언된 List or Map의 변수 명.
-ofType : 리턴 될 타입 명. 즉, collection의 리턴타입이라고 보면 됨.
-resultMap : collection 조회 후 리턴될 resultMap 명.
-foreignColumn : 상위 테이블에서 하위 테이블에 매칭될 외래키를 적는다. 하위 resultMap의 id 태그(PK)와는 상관없다.
-※ columnPrefix : 이 녀석은 하위 테이블이 상위 테이블의 기본키를 외래키로 지정했을 때 테이블을 구분하기 위해서
alias (쿼리문 칼럼 as ...) 를 주었을 경우
<id property="id" column="list_id"/>
<id property="id" column="id"/>
이렇게 column을 list_를 빼고 사용할 수 있게 만들어준다. ex) <collection columnPrefix="list_">
다만 여기서 사용하지 않은 이유는 우리 테이블 구조는 3단계로,
columnPrefix가 상속이 되기 때문에 alias를 길게 붙어줘야 하므로 그냥 칼럼명 전체를 적어주었음.
-->
<select id="readBoardDetail" parameterType="Long" resultMap="BoardDetailResult">
select
a.id as board_id,
a.title as board_title,
a.bg_color as board_bg_color,
a.invited_user as board_invited_user,
a.public_yn as board_public_yn,
a.hashtag as board_hashtag,
a.like_count as board_like_count,
a.created_at as board_created_at,
a.created_by as board_created_by,
d.picture as board_created_by_picture,
b.id as list_id,
b.board_id as list_board_id,
b.title as list_title,
b.pos as list_pos,
c.id as card_id,
c.list_id as card_list_id,
c.title as card_title,
c.pos as card_pos,
c.description as card_description,
c.label_color as card_label_color,
c.location as card_location,
c.is_checklist as card_is_checklist,
c.is_attachment as card_is_attachment,
c.due_date as card_due_date,
case when (
exists (select 1 from comment e where c.id = e.card_id)
) = 0 then null
when (
exists (select 1 from comment e where c.id = e.card_id)
) = 1 then 1 end as card_is_comment
from board a
left outer join list b on a.id = b.board_id
left outer join card c on b.id = c.list_id
left outer join user d on a.created_by = d.id
where a.id = #{boardId}
order by b.pos, c.pos
</select>
<resultMap id="BoardDetailResult" type="com.pozafly.tripllo.board.model.responseBoardDetail.BoardResultMap">
<id property="id" column="board_id"/>
<result property="title" column="board_title"/>
<result property="bgColor" column="board_bg_color"/>
<result property="invitedUser" column="board_invited_user"/>
<result property="publicYn" column="board_public_yn" />
<result property="hashtag" column="board_hashtag"/>
<result property="likeCount" column="board_like_count"/>
<result property="createdAt" column="board_created_at"/>
<result property="createdBy" column="board_created_by"/>
<result property="createdByPicture" column="board_created_by_picture"/>
<collection property="lists" ofType="com.pozafly.tripllo.board.model.responseBoardDetail.ListResultMap"
resultMap="BoardListsResult" foreignColumn="list_board_id" />
</resultMap>
<resultMap id="BoardListsResult" type="com.pozafly.tripllo.board.model.responseBoardDetail.ListResultMap">
<id property="id" column="list_id"/>
<result property="boardId" column="list_board_id"/>
<result property="title" column="list_title"/>
<result property="pos" column="list_pos"/>
<collection property="cards" ofType="com.pozafly.tripllo.board.model.responseBoardDetail.CardResultMap"
resultMap="ListsCardsResult" foreignColumn="card_list_id" />
</resultMap>
<resultMap id="ListsCardsResult" type="com.pozafly.tripllo.board.model.responseBoardDetail.CardResultMap">
<id property="id" column="card_id" />
<result property="listId" column="card_list_id"/>
<result property="title" column="card_title"/>
<result property="pos" column="card_pos"/>
<result property="description" column="card_description"/>
<result property="labelColor" column="card_label_color"/>
<result property="location" column="card_location"/>
<result property="isChecklist" column="card_is_checklist"/>
<result property="isAttachment" column="card_is_attachment"/>
<result property="dueDate" column="card_due_date"/>
<result property="isComment" column="card_is_comment"/>
</resultMap>
<insert id="createBoard" parameterType="Map">
insert into board values (null, #{title}, #{userId}, #{bgColor}, null, #{publicYn}, #{hashtag}, 0, now(), #{userId}, null, null)
<selectKey resultType="Long" keyProperty="id" order="AFTER" >
select last_insert_id() as id
</selectKey>
<!-- keyProperty 는 컬럼명이다. 즉 board에 id 칼럼의 setter, getter가 존재해야함.-->
</insert>
<update id="updateBoard" parameterType="Map">
update board
set
<if test='title != null and !"".equals(title)'>
title = #{title},
</if>
<if test='bgColor != null and !"".equals(bgColor)'>
bg_color = #{bgColor},
</if>
<if test='invitedUser != null'>
invited_user = #{invitedUser},
</if>
<if test='publicYn != null and !"".equals(publicYn)'>
public_yn = #{publicYn},
</if>
<if test='hashtag != null'>
hashtag = #{hashtag},
</if>
updated_at = now(),
updated_by = #{userId}
where id = #{boardId}
</update>
<delete id="deleteBoard" parameterType="Long">
delete
from board
where id = #{id}
</delete>
</mapper>