@@ -31,4 +31,134 @@ public function addTrackLogin(string $username, string $userIp, bool $success):
31
31
$ this ->_em ->persist ($ trackELoginRecord );
32
32
$ this ->_em ->flush ();
33
33
}
34
+
35
+ public function failedByMonth (int $ months = 12 ): array
36
+ {
37
+ $ sql = "
38
+ SELECT DATE_FORMAT(login_date, '%Y-%m-01') AS month, COUNT(*) AS failed
39
+ FROM track_e_login_record
40
+ WHERE success = 0 AND login_date >= (CURRENT_DATE - INTERVAL :m MONTH)
41
+ GROUP BY month ORDER BY month ASC
42
+ " ;
43
+ return $ this ->getEntityManager ()->getConnection ()
44
+ ->executeQuery ($ sql , ['m ' => $ months ])
45
+ ->fetchAllAssociative ();
46
+ }
47
+
48
+ public function topUsernames (int $ days = 30 , int $ limit = 5 ): array
49
+ {
50
+ $ conn = $ this ->getEntityManager ()->getConnection ();
51
+ $ stmt = $ conn ->prepare ("
52
+ SELECT username, COUNT(*) AS failed
53
+ FROM track_e_login_record
54
+ WHERE success = 0 AND login_date >= (CURRENT_DATE - INTERVAL :d DAY)
55
+ GROUP BY username ORDER BY failed DESC LIMIT :l
56
+ " );
57
+ $ stmt ->bindValue ('d ' , $ days , \PDO ::PARAM_INT );
58
+ $ stmt ->bindValue ('l ' , $ limit , \PDO ::PARAM_INT );
59
+ return $ stmt ->executeQuery ()->fetchAllAssociative ();
60
+ }
61
+
62
+ public function topIps (int $ days = 30 , int $ limit = 5 ): array
63
+ {
64
+ $ conn = $ this ->getEntityManager ()->getConnection ();
65
+ $ stmt = $ conn ->prepare ("
66
+ SELECT user_ip AS ip, COUNT(*) AS failed
67
+ FROM track_e_login_record
68
+ WHERE success = 0 AND login_date >= (CURRENT_DATE - INTERVAL :d DAY)
69
+ GROUP BY user_ip ORDER BY failed DESC LIMIT :l
70
+ " );
71
+ $ stmt ->bindValue ('d ' , $ days , \PDO ::PARAM_INT );
72
+ $ stmt ->bindValue ('l ' , $ limit , \PDO ::PARAM_INT );
73
+ return $ stmt ->executeQuery ()->fetchAllAssociative ();
74
+ }
75
+
76
+ public function findFailedPaginated (int $ page , int $ pageSize , array $ filters = []): array
77
+ {
78
+ $ where = ["success = 0 " ];
79
+ $ params = [];
80
+
81
+ if (!empty ($ filters ['username ' ])) { $ where [] = "username = :u " ; $ params ['u ' ] = $ filters ['username ' ]; }
82
+ if (!empty ($ filters ['ip ' ])) { $ where [] = "user_ip = :ip " ; $ params ['ip ' ] = $ filters ['ip ' ]; }
83
+ if (!empty ($ filters ['from ' ])) { $ where [] = "login_date >= :fr " ; $ params ['fr ' ] = $ filters ['from ' ]; }
84
+ if (!empty ($ filters ['to ' ])) { $ where [] = "login_date <= :to " ; $ params ['to ' ] = $ filters ['to ' ]; }
85
+
86
+ $ whereSql = $ where ? ('WHERE ' .implode (' AND ' , $ where )) : '' ;
87
+ $ offset = ($ page - 1 ) * $ pageSize ;
88
+ $ conn = $ this ->getEntityManager ()->getConnection ();
89
+
90
+ $ rows = $ conn ->executeQuery (
91
+ "SELECT login_date, user_ip, username
92
+ FROM track_e_login_record
93
+ $ whereSql
94
+ ORDER BY login_date DESC
95
+ LIMIT :lim OFFSET :off " ,
96
+ $ params + ['lim ' => $ pageSize , 'off ' => $ offset ],
97
+ ['lim ' => \PDO ::PARAM_INT , 'off ' => \PDO ::PARAM_INT ]
98
+ )->fetchAllAssociative ();
99
+
100
+ $ total = (int ) $ conn ->executeQuery (
101
+ "SELECT COUNT(*) FROM track_e_login_record $ whereSql " , $ params
102
+ )->fetchOne ();
103
+
104
+ return ['items ' => $ rows , 'total ' => $ total , 'page ' => $ page , 'pageSize ' => $ pageSize ];
105
+ }
106
+
107
+ public function failedByDay (int $ days = 7 ): array
108
+ {
109
+ $ conn = $ this ->getEntityManager ()->getConnection ();
110
+ $ stmt = $ conn ->prepare ("
111
+ SELECT DATE(login_date) AS day, COUNT(*) AS failed
112
+ FROM track_e_login_record
113
+ WHERE success = 0
114
+ AND login_date >= (CURRENT_DATE - INTERVAL :d DAY)
115
+ GROUP BY day
116
+ ORDER BY day ASC
117
+ " );
118
+ $ stmt ->bindValue ('d ' , $ days , \PDO ::PARAM_INT );
119
+
120
+ return $ stmt ->executeQuery ()->fetchAllAssociative ();
121
+ }
122
+
123
+ public function successVsFailedByDay (int $ days = 30 ): array
124
+ {
125
+ $ sql = "
126
+ SELECT DATE(login_date) AS day,
127
+ SUM(CASE WHEN success = 1 THEN 1 ELSE 0 END) AS success_cnt,
128
+ SUM(CASE WHEN success = 0 THEN 1 ELSE 0 END) AS failed_cnt
129
+ FROM track_e_login_record
130
+ WHERE login_date >= (CURRENT_DATE - INTERVAL :d DAY)
131
+ GROUP BY day
132
+ ORDER BY day ASC " ;
133
+ $ stmt = $ this ->getEntityManager ()->getConnection ()->prepare ($ sql );
134
+ $ stmt ->bindValue ('d ' , $ days , \PDO ::PARAM_INT );
135
+
136
+ return $ stmt ->executeQuery ()->fetchAllAssociative ();
137
+ }
138
+
139
+ public function failedByHourOfDay (int $ days = 7 ): array
140
+ {
141
+ $ sql = "
142
+ SELECT HOUR(login_date) AS hour, COUNT(*) AS failed
143
+ FROM track_e_login_record
144
+ WHERE success = 0
145
+ AND login_date >= (CURRENT_DATE - INTERVAL :d DAY)
146
+ GROUP BY hour ORDER BY hour " ;
147
+ $ stmt = $ this ->getEntityManager ()->getConnection ()->prepare ($ sql );
148
+ $ stmt ->bindValue ('d ' , $ days , \PDO ::PARAM_INT );
149
+ return $ stmt ->executeQuery ()->fetchAllAssociative ();
150
+ }
151
+
152
+ public function uniqueIpsByDay (int $ days = 30 ): array
153
+ {
154
+ $ sql = "
155
+ SELECT DATE(login_date) AS day, COUNT(DISTINCT user_ip) AS unique_ips
156
+ FROM track_e_login_record
157
+ WHERE success = 0
158
+ AND login_date >= (CURRENT_DATE - INTERVAL :d DAY)
159
+ GROUP BY day ORDER BY day " ;
160
+ $ stmt = $ this ->getEntityManager ()->getConnection ()->prepare ($ sql );
161
+ $ stmt ->bindValue ('d ' , $ days , \PDO ::PARAM_INT );
162
+ return $ stmt ->executeQuery ()->fetchAllAssociative ();
163
+ }
34
164
}
0 commit comments