aboutsummaryrefslogtreecommitdiff
path: root/src/main/java/com/juick/service/UserServiceImpl.java
blob: 4d3706316a616d1039dc8619d8eb2af757cd9295 (plain) (blame)
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
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
/*
 * Copyright (C) 2008-2017, Juick
 *
 * This program is free software: you can redistribute it and/or modify
 * it under the terms of the GNU Affero General Public License as
 * published by the Free Software Foundation, either version 3 of the
 * License, or (at your option) any later version.
 *
 * This program is distributed in the hope that it will be useful,
 * but WITHOUT ANY WARRANTY; without even the implied warranty of
 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
 * GNU Affero General Public License for more details.
 *
 * You should have received a copy of the GNU Affero General Public License
 * along with this program.  If not, see <http://www.gnu.org/licenses/>.
 */

package com.juick.service;

import com.juick.Message;
import com.juick.User;
import com.juick.model.AnonymousUser;
import com.juick.model.Auth;
import com.juick.model.UserInfo;
import org.apache.commons.collections4.CollectionUtils;
import org.apache.commons.lang3.RandomStringUtils;
import org.apache.commons.lang3.StringUtils;
import org.springframework.dao.DuplicateKeyException;
import org.springframework.dao.EmptyResultDataAccessException;
import org.springframework.jdbc.core.RowMapper;
import org.springframework.jdbc.core.namedparam.MapSqlParameterSource;
import org.springframework.jdbc.support.GeneratedKeyHolder;
import org.springframework.jdbc.support.KeyHolder;
import org.springframework.stereotype.Repository;
import org.springframework.transaction.annotation.Transactional;

import javax.annotation.Nonnull;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import java.sql.Timestamp;
import java.util.Collection;
import java.util.Collections;
import java.util.List;
import java.util.Objects;
import java.util.Optional;
import java.util.UUID;

/**
 * Created by aalexeev on 11/13/16.
 */
@Repository
public class UserServiceImpl extends BaseJdbcService implements UserService {

    private class UserMapper implements RowMapper<User> {
        @Override
        public User mapRow(@Nonnull ResultSet rs, int rowNum) throws SQLException {
            User user = new User();

            user.setUid(rs.getInt(1));
            user.setName(rs.getString(2));
            user.setCredentials(rs.getString(3));
            user.setBanned(rs.getBoolean(4));
            Timestamp seen = rs.getTimestamp(5);
            if (seen != null) {
                user.setSeen(seen.toInstant());
            }
            user.setVerified(rs.getInt(6) > 0);
            return user;
        }
    }

    @Transactional
    @Override
    public String getSignUpHashByJID(final String jid) {
        List<String> list = getJdbcTemplate().queryForList(
                "SELECT loginhash FROM jids WHERE jid = ? AND user_id IS NULL", String.class, jid);

        if (list.isEmpty()) {
            String hash = UUID.randomUUID().toString();
            getJdbcTemplate().update("INSERT INTO jids(jid, loginhash) VALUES (?, ?)", jid, hash);
            return hash;
        }
        return list.get(0);
    }

    @Transactional
    @Override
    public String getSignUpHashByTelegramID(final Long telegramId, final String username) {
        List<String> list = getJdbcTemplate().queryForList(
                "SELECT loginhash FROM telegram WHERE tg_id = ? AND user_id IS NULL",
                String.class,
                telegramId);

        if (list.isEmpty()) {
            String hash = UUID.randomUUID().toString();
            getJdbcTemplate().update(
                    "INSERT INTO telegram(tg_id, loginhash, tg_name) VALUES (?, ?, ?)", telegramId, hash, username);
            return hash;
        }
        return list.get(0);
    }

    @Transactional
    @Override
    public int createUser(final String username, final String password) {
        KeyHolder holder = new GeneratedKeyHolder();
        try {
            getJdbcTemplate().update(
                    con -> {
                        PreparedStatement stmt = con.prepareStatement(
                                "INSERT INTO users(nick,passw) VALUES (?,?)",
                                Statement.RETURN_GENERATED_KEYS);
                        stmt.setString(1, username);
                        stmt.setString(2, password);
                        return stmt;
                    },
                    holder);
        } catch (DuplicateKeyException e) {
            return -1;
        }

        int uid = holder.getKey().intValue();

        getJdbcTemplate().update("INSERT INTO useroptions(user_id) VALUES (?)", uid);
        getJdbcTemplate().update("INSERT INTO subscr_users(user_id, suser_id) VALUES (2, ?)", uid);

        return uid;
    }

    @Transactional(readOnly = true)
    @Override
    public Optional<User> getUserByUID(final int uid) {
        List<User> list = getJdbcTemplate().query(
                "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen, " +
                        "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                        "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                        "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                        "LEFT JOIN emails e ON e.user_id = u.id WHERE u.id = ?", new UserMapper(), uid);

        return list.isEmpty() ? Optional.empty() : Optional.of(list.get(0));
    }

    @Transactional(readOnly = true)
    @Nonnull
    @Override
    public User getUserByName(final String username) {
        if (StringUtils.isNotBlank(username)) {
            List<User> list = getJdbcTemplate().query(
                    "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen, " +
                            "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                            "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                            "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                            "LEFT JOIN emails e ON e.user_id = u.id " +
                            "WHERE u.nick = ?", new UserMapper(), username);

            if (!list.isEmpty())
                return list.get(0);
        }
        return AnonymousUser.INSTANCE;
    }

    @Override
    @Transactional(readOnly = true)
    @Nonnull
    public User getUserByEmail(String email) {
        if (StringUtils.isNotBlank(email)) {
            List<User> list = getJdbcTemplate().query(
                    "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen, " +
                            "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                            "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                            "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                            "LEFT JOIN emails e ON e.user_id = u.id " +
                            "WHERE u.id = (SELECT DISTINCT user_id FROM emails WHERE email = ?)",
                    new UserMapper(),
                    email);

            if (!list.isEmpty())
                return list.get(0);
        }
        return AnonymousUser.INSTANCE;
    }

    @Transactional(readOnly = true)
    @Override
    public User getUserByJID(final String jid) {
        User result = null;

        if (StringUtils.isNotBlank(jid)) {
            List<User> list = getJdbcTemplate().query(
                    "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen," +
                            "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                            "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                            "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                            "LEFT JOIN emails e ON e.user_id = u.id " +
                            "WHERE u.id = (SELECT user_id FROM jids WHERE jid = ?)",
                    new UserMapper(),
                    jid);

            if (!list.isEmpty())
                result = list.get(0);
        }
        return result;
    }

    @Transactional(readOnly = true)
    @Override
    public List<User> getUsersByName(final Collection<String> unames) {
        if (CollectionUtils.isEmpty(unames))
            return Collections.emptyList();

        return getNamedParameterJdbcTemplate().query(
                "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen," +
                        "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                        "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                        "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                        "LEFT JOIN emails e ON e.user_id = u.id " +
                        "WHERE u.nick IN (:unames)",
                new MapSqlParameterSource("unames", unames),
                new UserMapper());
    }

    @Transactional(readOnly = true)
    @Override
    public List<User> getUsersByID(final Collection<Integer> uids) {
        if (CollectionUtils.isEmpty(uids))
            return Collections.emptyList();

        return getNamedParameterJdbcTemplate().query(
                "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen," +
                        "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                        "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                        "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                        "LEFT JOIN emails e ON e.user_id = u.id " +
                        "WHERE u.id IN (:ids)",
                new MapSqlParameterSource("ids", uids),
                new UserMapper());
    }

    @Transactional(readOnly = true)
    @Override
    public List<String> getJIDsbyUID(final int uid) {
        return getJdbcTemplate().queryForList("SELECT jid FROM jids WHERE user_id = ? AND active = 1", String.class, uid);
    }

    @Transactional(readOnly = true)
    @Override
    public int getUIDbyJID(final String jid) {
        if (StringUtils.isNotBlank(jid)) {
            List<Integer> list = getJdbcTemplate().queryForList(
                    "SELECT user_id FROM jids WHERE jid = ?", Integer.class, jid);

            if (!list.isEmpty())
                return list.get(0);
        }
        return 0;
    }

    @Transactional(readOnly = true)
    @Override
    public int getUIDbyName(final String uname) {
        if (StringUtils.isNotBlank(uname)) {
            List<Integer> list = getJdbcTemplate().queryForList(
                    "SELECT id FROM users WHERE nick = ?", Integer.class, uname);

            if (!list.isEmpty())
                return list.get(0);
        }
        return 0;
    }

    @Transactional(readOnly = true)
    @Override
    public int getUIDbyHash(final String hash) {
        if (StringUtils.isNotBlank(hash)) {
            List<Integer> list = getJdbcTemplate().queryForList(
                    "SELECT user_id FROM logins WHERE hash = ?", Integer.class, hash);

            if (!list.isEmpty())
                return list.get(0);
        }
        return 0;
    }

    @Transactional(readOnly = true)
    @Override
    public com.juick.User getUserByHash(final String hash) {
        if (StringUtils.isNotBlank(hash)) {
            List<User> list = getJdbcTemplate().query(
                    "SELECT logins.user_id, u.nick, u.passw, u.banned, u.last_seen," +
                            "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                            "FROM logins INNER JOIN users u ON logins.user_id = u.id " +
                            "LEFT JOIN facebook f ON f.user_id = u.id " +
                            "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                            "LEFT JOIN emails e ON e.user_id = u.id " +
                            "WHERE logins.hash = ?",
                    new UserMapper(),
                    hash);

            if (!list.isEmpty()) {
                User user = list.get(0);
                user.setAuthHash(hash);
                return user;
            }
        }
        return AnonymousUser.INSTANCE;
    }

    @Transactional
    @Override
    public String getHashByUID(final int uid) {
        List<String> list = getJdbcTemplate().queryForList(
                "SELECT hash FROM logins WHERE user_id = ?", String.class, uid);

        if (list.isEmpty()) {
            String hash = RandomStringUtils.randomAlphanumeric(16).toUpperCase();
            getJdbcTemplate().update("INSERT INTO logins(user_id, hash) VALUES (?, ?)", uid, hash);
            return hash;
        }
        return list.get(0);
    }

    @Transactional(readOnly = true)
    @Override
    public int checkPassword(final String username, final String password) {
        if (StringUtils.isNotBlank(username)) {
            List<User> list = getJdbcTemplate().query(
                    "SELECT u.id, u.nick, u.passw, u.banned, u.last_seen," +
                            "COALESCE(f.fb_id, vk.vk_id, t.tg_id, e.user_id, 0) AS verified " +
                            "FROM users u LEFT JOIN facebook f ON f.user_id = u.id " +
                            "LEFT JOIN vk ON u.id = vk.user_id LEFT JOIN telegram t ON u.id = t.user_id " +
                            "LEFT JOIN emails e ON e.user_id = u.id " +
                            "WHERE nick = ?",
                    new UserMapper(),
                    username);

            if (!list.isEmpty()) {
                User user = list.get(0);
                if (Objects.equals(password, user.getCredentials()))
                    return user.getUid();
            }
        }
        return -1;
    }

    @Transactional
    @Override
    public boolean updatePassword(final User user, final String newPassword) {
        return user != null &&
                user.getUid() > 0 &&
                getJdbcTemplate().update("UPDATE users SET passw = ? WHERE id = ?", newPassword, user.getUid()) > 0;
    }

    @Transactional(readOnly = true)
    @Override
    public int getUserOptionInt(final int uid, final String option, final int defaultValue) {
        if (StringUtils.isBlank(option))
            return defaultValue;

        List<Integer> list = getJdbcTemplate().queryForList(
                "SELECT " + option + " FROM useroptions WHERE user_id = ?", Integer.class, uid);

        return list.isEmpty() ? defaultValue : list.get(0);
    }

    @Transactional
    @Override
    public int setUserOptionInt(final int uid, final String option, final int value) {
        if (StringUtils.isBlank(option))
            return 0;

        return getJdbcTemplate().update("UPDATE useroptions SET " + option + "= ? WHERE user_id = ?", value, uid);
    }

    @Transactional(readOnly = true)
    @Override
    public UserInfo getUserInfo(final User user) {
        List<UserInfo> list = getJdbcTemplate().query(
                "SELECT fullname, country, url, descr FROM usersinfo WHERE user_id = ?",
                ((rs, rowNum) -> {
                    UserInfo info = new UserInfo();
                    info.setFullName(rs.getString(1));
                    info.setCountry(rs.getString(2));
                    info.setUrl(rs.getString(3));
                    info.setDescription(rs.getString(4));
                    return info;
                }),
                user.getUid());

        return list.isEmpty() ? new UserInfo() : list.get(0);
    }

    @Transactional
    @Override
    public boolean updateUserInfo(final User user, final UserInfo info) {
        try {
            return getJdbcTemplate().update(
                    "INSERT INTO usersinfo(user_id, fullname, country, url, descr) VALUES (?, ?, ?, ?, ?)",
                    user.getUid(),
                    info.getFullName(),
                    info.getCountry(),
                    info.getUrl(),
                    info.getDescription()) > 0;
        } catch (DuplicateKeyException e) {
            return getJdbcTemplate().update("UPDATE usersinfo SET fullname = ?, country = ?, url = ?, descr = ? WHERE user_id = ?",
                    info.getFullName(),
                    info.getCountry(),
                    info.getUrl(),
                    info.getDescription(),
                    user.getUid()) > 0;
        }
    }

    @Transactional(readOnly = true)
    @Override
    public boolean getCanMedia(final int uid) {
        List<Integer> list = getJdbcTemplate().queryForList(
                "SELECT users.lastphoto - UNIX_TIMESTAMP() FROM users WHERE id = ?",
                Integer.class,
                uid);

        return !list.isEmpty() && list.get(0) < 3600;
    }

    @Transactional(readOnly = true)
    @Override
    public boolean isInWL(final int uid, final int check) {
        List<Integer> list = getJdbcTemplate().queryForList(
                "SELECT 1 FROM wl_users WHERE user_id = ? AND wl_user_id = ?",
                Integer.class, uid, check);

        return !list.isEmpty() && list.get(0) == 1;
    }

    @Transactional(readOnly = true)
    @Override
    public boolean isInBL(final int uid, final int check) {
        List<Integer> list = getJdbcTemplate().queryForList(
                "SELECT 1 FROM bl_users WHERE user_id = ? AND bl_user_id = ?", Integer.class, uid, check);

        return !list.isEmpty() && list.get(0) == 1;
    }

    @Transactional(readOnly = true)
    @Override
    public boolean isInBLAny(final int uid, final int uid2) {
        List<Integer> list = getJdbcTemplate().queryForList(
                "SELECT 1 FROM bl_users WHERE (user_id = ? AND bl_user_id = ?) "
                        + "OR (user_id = ? AND bl_user_id = ?)",
                new Object[]{uid, uid2, uid2, uid},
                Integer.class);

        return !list.isEmpty() && list.get(0) == 1;
    }

    @Transactional(readOnly = true)
    @Override
    public boolean isReplyToBL(final User user, final Message reply) {
        return getNamedParameterJdbcTemplate().queryForObject("WITH RECURSIVE banned(reply_id, user_id) AS (" +
                        "SELECT reply_id, user_id FROM replies " +
                        "WHERE replies.message_id = :mid " +
                        "AND EXISTS (SELECT 1 FROM bl_users b WHERE b.user_id = :uid AND b.bl_user_id = replies.user_id) " +
                        "UNION ALL SELECT replies.reply_id, replies.user_id FROM replies " +
                        "INNER JOIN banned ON banned.reply_id = replies.replyto " +
                        "WHERE replies.message_id = :mid) " +
                        "SELECT COUNT(reply_id) from replies " +
                        "INNER JOIN messages m ON m.message_id = replies.message_id " +
                        "WHERE replies.message_id = :mid " +
                        "AND replies.reply_id = :rid " +
                        "AND (EXISTS (SELECT 1 FROM banned WHERE banned.reply_id = replies.reply_id) " +
                        "OR EXISTS (SELECT 1 FROM bl_users b WHERE b.user_id = :uid AND b.bl_user_id = m.user_id)" +
                        "OR EXISTS (SELECT 1 FROM bl_users b WHERE b.bl_user_id = :uid AND b.user_id = m.user_id))",
                new MapSqlParameterSource("uid", user.getUid())
                        .addValue("mid", reply.getMid())
                        .addValue("rid", reply.getRid()),
                Integer.class) > 0;
    }

    @Transactional(readOnly = true)
    @Override
    public List<Integer> checkBL(final int visitor, final Collection<Integer> uids) {
        if (CollectionUtils.isEmpty(uids))
            return Collections.emptyList();

        return getNamedParameterJdbcTemplate().queryForList(
                "SELECT user_id FROM bl_users WHERE bl_user_id = :visitor and user_id IN (:ids)",
                new MapSqlParameterSource()
                        .addValue("visitor", visitor)
                        .addValue("ids", uids),
                Integer.class);
    }

    @Transactional(readOnly = true)
    @Override
    public boolean isSubscribed(final int uid, final int check) {
        List<Integer> list = getJdbcTemplate().queryForList(
                "SELECT 1 FROM subscr_users WHERE suser_id = ? AND user_id = ?",
                Integer.class, uid, check);

        return !list.isEmpty() && list.get(0) == 1;
    }

    @Transactional(readOnly = true)
    @Override
    public List<com.juick.User> getUserReadLeastPopular(final int uid, final int cnt) {
        return getJdbcTemplate().query(
                "SELECT users.id,users.nick FROM (subscr_users " +
                        "INNER JOIN users_subscr ON (subscr_users.suser_id=? " +
                        "AND subscr_users.user_id=users_subscr.user_id)) INNER JOIN users " +
                        "ON subscr_users.user_id=users.id ORDER BY cnt LIMIT ?",
                (rs, num) -> {
                    com.juick.User u = new com.juick.User();
                    u.setUid(rs.getInt(1));
                    u.setName(rs.getString(2));
                    return u;
                },
                uid,
                cnt);
    }

    @Transactional(readOnly = true)
    @Override
    public List<User> getUserReaders(final int uid) {
        return getJdbcTemplate().query(
                "SELECT users.id, users.nick FROM subscr_users " +
                        "INNER JOIN users ON subscr_users.suser_id=users.id " +
                        "WHERE subscr_users.user_id=? ORDER BY users.nick",
                (rs, num) -> {
                    com.juick.User u = new com.juick.User();
                    u.setUid(rs.getInt(1));
                    u.setName(rs.getString(2));
                    return u;
                },
                uid);
    }

    @Transactional(readOnly = true)
    @Override
    public List<User> getUserFriends(final int uid) {
        return getJdbcTemplate().query(
                "SELECT users.id,users.nick FROM subscr_users " +
                        "INNER JOIN users ON subscr_users.user_id=users.id " +
                        "WHERE subscr_users.suser_id=? AND users.id!=? " +
                        "ORDER BY users.nick",
                (rs, num) -> {
                    com.juick.User u = new com.juick.User();
                    u.setUid(rs.getInt(1));
                    u.setName(rs.getString(2));
                    return u;
                },
                uid,
                uid);
    }

    @Transactional(readOnly = true)
    @Override
    public Integer getUserRecommendations(User user) {
        try {
            return jdbcTemplate.queryForObject("SELECT COUNT(*) FROM favorites WHERE user_id=?", Integer.class, user.getUid());
        } catch (EmptyResultDataAccessException e) {
            return 0;
        }
    }

    @Transactional(readOnly = true)
    @Override
    public List<com.juick.User> getUserBLUsers(final int uid) {
        return getJdbcTemplate().query("SELECT users.id,users.nick FROM users INNER JOIN bl_users " +
                        "ON(bl_users.bl_user_id=users.id) WHERE bl_users.user_id=? ORDER BY users.nick",
                (rs, num) -> {
                    com.juick.User u = new com.juick.User();
                    u.setUid(rs.getInt(1));
                    u.setName(rs.getString(2));
                    return u;
                }, uid);
    }

    @Transactional
    @Override
    public boolean linkTwitterAccount(
            final User user, final String accessToken, final String accessTokenSecret, final String screenName) {
        return getJdbcTemplate().update("INSERT INTO twitter(user_id,access_token,access_token_secret,uname) " +
                        "VALUES (?,?,?,?)" +
                        " ON DUPLICATE KEY UPDATE access_token=?,access_token_secret=?,uname=?",
                user.getUid(), accessToken, accessTokenSecret, screenName, accessToken, accessTokenSecret, screenName) > 0;
    }

    @Transactional(readOnly = true)
    @Override
    public int getStatsMyReaders(final int uid) {
        List<Integer> list = getJdbcTemplate().queryForList("SELECT COUNT(*) FROM subscr_users WHERE user_id = ?", Integer.class, uid);
        return list.isEmpty() ? 0 : list.get(0);
    }

    @Transactional(readOnly = true)
    @Override
    public int getStatsMessages(final int uid) {
        List<Integer> list = getJdbcTemplate().queryForList("SELECT COUNT(*) FROM messages WHERE user_id = ?", Integer.class, uid);
        return list.isEmpty() ? 0 : list.get(0);
    }

    @Transactional(readOnly = true)
    @Override
    public int getStatsReplies(final int uid) {
        List<Integer> list = getJdbcTemplate().queryForList("SELECT COUNT(*) FROM replies WHERE user_id = ?", Integer.class, uid);
        return list.isEmpty() ? 0 : list.get(0);
    }

    @Transactional
    @Override
    public boolean setActiveStatusForJID(final String JID, final UserService.ActiveStatus jidStatus) {
        User user = getUserByJID(JID);
        if (user != null) {
            int newStatus = jidStatus == UserService.ActiveStatus.Active ? 1 : 0;
            return getJdbcTemplate().update(
                    "UPDATE jids SET active = ? WHERE user_id = ? AND jid = ?",
                    newStatus, user.getUid(), JID) >= 0;
        }
        return false;
    }

    @Transactional(readOnly = true)
    @Override
    public List<String> getAllJIDs(final User user) {
        return getJdbcTemplate().queryForList(
                "SELECT jid FROM jids WHERE user_id=?", String.class, user.getUid());
    }

    @Transactional(readOnly = true)
    @Override
    public List<Auth> getAuthCodes(final User user) {
        return getJdbcTemplate().query(
                "SELECT account,authcode FROM auth WHERE user_id=? AND protocol='xmpp'",
                (rs, num) -> new Auth(rs.getString(1), rs.getString(2)),
                user.getUid());
    }

    @Transactional(readOnly = true)
    @Override
    public List<String> getEmails(final User user) {
        return getJdbcTemplate().queryForList("SELECT email FROM emails WHERE user_id=?", String.class, user.getUid());
    }

    @Transactional(readOnly = true)
    @Override
    public String getEmailHash(final User user) {
        List<String> list = getJdbcTemplate().queryForList(
                "SELECT hash FROM mail WHERE user_id = ?",
                String.class,
                user.getUid());
        return list.isEmpty() ? StringUtils.EMPTY : list.get(0) + "@mail.juick.com";
    }

    @Transactional
    @Override
    public int deleteLoginForUser(final String name) {
        if (StringUtils.isBlank(name))
            return 0;

        return getJdbcTemplate().update(
                "delete from logins where user_id in (select id from users where nick = ?)", name);
    }

    @Transactional
    @Override
    public int setLoginForUser(final int uid, final String loginHash) {
        if (StringUtils.isEmpty(loginHash))
            return 0;

        return getNamedParameterJdbcTemplate().update(
                "INSERT INTO logins (user_id, hash) VALUES(:uid, :hash) ON DUPLICATE KEY UPDATE hash = :hash",
                new MapSqlParameterSource()
                        .addValue("hash", loginHash)
                        .addValue("uid", uid));
    }

    @Transactional
    @Override
    public void logout(int uid) {
        getJdbcTemplate().update("DELETE FROM logins WHERE user_id=?", uid);
    }

    @Transactional
    @Override
    public boolean deleteJID(int uid, String jid) {
        return getNamedParameterJdbcTemplate().update("DELETE FROM jids " +
                        "WHERE (SELECT COUNT(*) cnt FROM (select user_id, jid FROM jids j) c WHERE user_id=:uid) > 1 " +
                        "AND user_id=:uid AND jid=:jid",
                new MapSqlParameterSource()
                        .addValue("uid", uid)
                        .addValue("jid", jid)) > 0;
    }

    @Transactional
    @Override
    public boolean unauthJID(int uid, String jid) {
        return getJdbcTemplate()
                .update("DELETE FROM auth WHERE user_id=? AND protocol='xmpp' AND account=?", uid, jid) > 0;
    }

    @Transactional(readOnly = true)
    @Override
    public List<String> getActiveJIDs() {
        return getJdbcTemplate().queryForList("SELECT jid FROM jids WHERE active=1 AND loginhash IS NULL", String.class);
    }

    @Override
    public void updateLastSeen(User user) {
        getJdbcTemplate().update("UPDATE users SET last_seen=now() WHERE id=?", user.getUid());
    }
}