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
|
use sqlx::error::Error;
use sqlx::sqlite::{Sqlite, SqliteArguments};
use sqlx::sqlite::{SqlitePool, SqliteRow};
use sqlx::FromRow;
use sqlx_core::row::Row;
use std::collections::HashMap;
use std::iter::FromIterator;
use crate::db::utils;
use crate::model::frequency::Frequency;
use crate::model::payment;
use crate::model::report::Report;
use crate::queries;
use crate::utils::text;
#[derive(FromRow)]
pub struct Count {
pub count: i64,
pub total_cost: i64,
}
pub async fn count(
pool: &SqlitePool,
payment_query: &queries::Payments,
) -> Count {
let query = format!(
r#"
SELECT
COUNT(*) AS count,
SUM(payments.cost) AS total_cost
FROM
payments
INNER JOIN
users ON users.id = payments.user_id
INNER JOIN
categories ON categories.id = payments.category_id
WHERE
payments.deleted_at IS NULL
AND payments.frequency = ?
{} {} {} {} {} {}
"#,
name_query(payment_query.name.clone()),
cost_query(payment_query.cost.clone()),
user_query(payment_query.user),
category_query(payment_query.category),
date_query(
"payments.date >=".to_string(),
payment_query.start_date.clone()
),
date_query(
"payments.date <=".to_string(),
payment_query.end_date.clone()
)
);
let res = bind_date(
bind_date(
bind_category(
bind_user(
bind_cost(
bind_name(
sqlx::query_as::<_, Count>(&query).bind(
payment_query
.frequency
.unwrap_or(Frequency::Punctual),
),
payment_query.name.clone(),
),
payment_query.cost.clone(),
),
payment_query.user,
),
payment_query.category,
),
payment_query.start_date.clone(),
),
payment_query.end_date.clone(),
)
.fetch_one(pool)
.await;
match res {
Ok(count) => count,
Err(err) => {
log::error!("Error counting payments: {:?}", err);
Count {
count: 0,
total_cost: 0,
}
}
}
}
pub async fn list_for_table(
pool: &SqlitePool,
payment_query: &queries::Payments,
per_page: i64,
) -> Vec<payment::Table> {
let offset = (payment_query.page.unwrap_or(1) - 1) * per_page;
let query = format!(
r#"
SELECT
payments.id,
payments.name,
payments.cost,
users.name AS user,
categories.name AS category_name,
categories.color AS category_color,
strftime('%d/%m/%Y', date) AS date,
payments.frequency AS frequency
FROM
payments
INNER JOIN
users ON users.id = payments.user_id
INNER JOIN
categories ON categories.id = payments.category_id
WHERE
payments.deleted_at IS NULL
AND payments.frequency = ?
{} {} {} {} {} {}
ORDER BY
payments.date DESC
LIMIT ?
OFFSET ?
"#,
name_query(payment_query.name.clone()),
cost_query(payment_query.cost.clone()),
user_query(payment_query.user),
category_query(payment_query.category),
date_query(
"payments.date >=".to_string(),
payment_query.start_date.clone()
),
date_query(
"payments.date <=".to_string(),
payment_query.end_date.clone()
)
);
let res = bind_date(
bind_date(
bind_category(
bind_user(
bind_cost(
bind_name(
sqlx::query_as::<_, payment::Table>(&query).bind(
payment_query
.frequency
.unwrap_or(Frequency::Punctual),
),
payment_query.name.clone(),
),
payment_query.cost.clone(),
),
payment_query.user,
),
payment_query.category,
),
payment_query.start_date.clone(),
),
payment_query.end_date.clone(),
)
.bind(per_page)
.bind(offset)
.fetch_all(pool)
.await;
match res {
Ok(payments) => payments,
Err(err) => {
log::error!("Error listing payments: {:?}", err);
vec![]
}
}
}
fn name_query(name: Option<String>) -> String {
if name.map_or_else(|| false, |str| !str.is_empty()) {
format!(
"AND {} LIKE ?",
utils::format_key_for_search("payments.name")
)
} else {
"".to_string()
}
}
fn bind_name<'a, Row: FromRow<'a, SqliteRow>>(
query: sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>>,
name: Option<String>,
) -> sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>> {
match name {
Some(str) => {
if str.is_empty() {
query
} else {
query.bind(text::format_search(&str))
}
}
_ => query,
}
}
fn cost_query(cost: Option<String>) -> String {
if cost.map_or_else(|| false, |str| !str.is_empty()) {
"AND payments.cost = ?".to_string()
} else {
"".to_string()
}
}
fn bind_cost<'a, Row: FromRow<'a, SqliteRow>>(
query: sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>>,
cost: Option<String>,
) -> sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>> {
match cost {
Some(str) => {
if str.is_empty() {
query
} else {
query.bind(str)
}
}
_ => query,
}
}
fn user_query(user: Option<i64>) -> String {
if user.is_some() {
"AND payments.user_id = ?".to_string()
} else {
"".to_string()
}
}
fn bind_user<'a, Row: FromRow<'a, SqliteRow>>(
query: sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>>,
user: Option<i64>,
) -> sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>> {
match user {
Some(id) => query.bind(id),
_ => query,
}
}
fn category_query(category: Option<i64>) -> String {
if category.is_some() {
"AND payments.category_id = ?".to_string()
} else {
"".to_string()
}
}
fn bind_category<'a, Row: FromRow<'a, SqliteRow>>(
query: sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>>,
category: Option<i64>,
) -> sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>> {
match category {
Some(id) => query.bind(id),
_ => query,
}
}
fn date_query(name_and_op: String, date: Option<String>) -> String {
if date.map_or_else(|| false, |str| !str.is_empty()) {
format!("AND {} ?", name_and_op)
} else {
"".to_string()
}
}
fn bind_date<'a, Row: FromRow<'a, SqliteRow>>(
query: sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>>,
date: Option<String>,
) -> sqlx::query::QueryAs<'a, Sqlite, Row, SqliteArguments<'a>> {
match date {
Some(d) => {
if d.is_empty() {
query
} else {
query.bind(d)
}
}
_ => query,
}
}
pub async fn list_for_stats(pool: &SqlitePool) -> Vec<payment::Stat> {
let query = r#"
SELECT
strftime('%Y-%m-01', payments.date) AS start_date,
SUM(payments.cost) AS cost,
payments.category_id AS category_id
FROM
payments
WHERE
payments.deleted_at IS NULL
AND payments.frequency = 'Punctual'
GROUP BY
start_date,
payments.category_id;
"#;
let result = sqlx::query_as::<_, payment::Stat>(query)
.fetch_all(pool)
.await;
match result {
Ok(payments) => payments,
Err(err) => {
log::error!("Error listing payments for statistics: {:?}", err);
vec![]
}
}
}
pub async fn get_row(pool: &SqlitePool, id: i64, frequency: Frequency) -> i64 {
let query = r#"
SELECT
row
FROM (
SELECT
ROW_NUMBER () OVER (ORDER BY date DESC) AS row,
id
FROM
payments
WHERE
deleted_at IS NULL
AND frequency = ?
)
WHERE
id = ?
"#;
let res = sqlx::query(query)
.bind(frequency)
.bind(id)
.map(|row: SqliteRow| row.get("row"))
.fetch_one(pool)
.await;
match res {
Ok(count) => count,
Err(err) => {
log::error!("Error getting payment row: {:?}", err);
1
}
}
}
pub async fn get_for_form(pool: &SqlitePool, id: i64) -> Option<payment::Form> {
let query = r#"
SELECT
id,
name,
cost,
user_id,
category_id,
strftime('%Y-%m-%d', date) AS date,
frequency AS frequency
FROM
payments
WHERE
id = ?
AND deleted_at IS NULL
"#;
let res = sqlx::query_as::<_, payment::Form>(query)
.bind(id)
.fetch_one(pool)
.await;
match res {
Ok(p) => Some(p),
Err(err) => {
log::error!("Error looking for payment {}: {:?}", id, err);
None
}
}
}
pub async fn create(pool: &SqlitePool, p: &payment::Create) -> Option<i64> {
let res = sqlx::query(
r#"
INSERT INTO
payments(name, cost, user_id, category_id, date, frequency)
VALUES
(?, ?, ?, ?, ?, ?)
"#,
)
.bind(p.name.clone())
.bind(p.cost)
.bind(p.user_id)
.bind(p.category_id)
.bind(p.date)
.bind(p.frequency)
.execute(pool)
.await;
match res {
Ok(x) => Some(x.last_insert_rowid()),
Err(err) => {
log::error!("Error creating payment: {:?}", err);
None
}
}
}
pub async fn update(pool: &SqlitePool, id: i64, p: &payment::Update) -> bool {
let res = sqlx::query(
r#"
UPDATE
payments
SET
name = ?,
cost = ?,
user_id = ?,
category_id = ?,
date = ?,
updated_at = datetime()
WHERE
id = ?
"#,
)
.bind(p.name.clone())
.bind(p.cost)
.bind(p.user_id)
.bind(p.category_id)
.bind(p.date)
.bind(id)
.execute(pool)
.await;
match res {
Ok(_) => true,
Err(err) => {
log::error!("Error updating payment {}: {:?}", id, err);
false
}
}
}
pub async fn delete(pool: &SqlitePool, id: i64) -> bool {
let res = sqlx::query(
r#"
UPDATE
payments
SET
deleted_at = datetime()
WHERE
id = ?
"#,
)
.bind(id)
.execute(pool)
.await;
match res {
Ok(_) => true,
Err(err) => {
log::error!("Error deleting payment {}: {:?}", id, err);
false
}
}
}
pub async fn search_category(
pool: &SqlitePool,
payment_name: String,
) -> Option<i64> {
let query = format!(
r#"
SELECT
category_id
FROM
payments
WHERE
deleted_at IS NULL
AND {} LIKE ?
ORDER BY
updated_at, created_at
"#,
utils::format_key_for_search("name")
);
let res = sqlx::query(&query)
.bind(text::format_search(&payment_name))
.map(|row: SqliteRow| row.get("category_id"))
.fetch_one(pool)
.await;
match res {
Ok(category) => Some(category),
Err(Error::RowNotFound) => None,
Err(err) => {
log::error!(
"Error looking for the category of {}: {:?}",
payment_name, err
);
None
}
}
}
pub async fn is_category_used(pool: &SqlitePool, category_id: i64) -> bool {
let query = r#"
SELECT
1
FROM
payments
WHERE
category_id = ?
AND deleted_at IS NULL
LIMIT
1
"#;
let res = sqlx::query(query).bind(category_id).fetch_one(pool).await;
match res {
Ok(_) => true,
Err(Error::RowNotFound) => false,
Err(err) => {
log::error!(
"Error looking if category {} is used: {:?}",
category_id, err
);
false
}
}
}
pub async fn repartition(pool: &SqlitePool) -> HashMap<i64, i64> {
let query = r#"
SELECT
users.id AS user_id,
COALESCE(payments.sum, 0) AS sum
FROM
users
LEFT OUTER JOIN (
SELECT
user_id,
SUM(cost) AS sum
FROM
payments
WHERE
deleted_at IS NULL
AND frequency = 'Punctual'
GROUP BY
user_id
) payments
ON
users.id = payments.user_id"#;
let res = sqlx::query(query)
.map(|row: SqliteRow| (row.get("user_id"), row.get("sum")))
.fetch_all(pool)
.await;
match res {
Ok(costs) => HashMap::from_iter(costs),
Err(err) => {
log::error!("Error getting payments repartition: {:?}", err);
HashMap::new()
}
}
}
pub async fn create_monthly_payments(pool: &SqlitePool) {
let query = r#"
INSERT INTO
payments(name, cost, user_id, category_id, date, frequency)
SELECT
name,
cost,
user_id,
category_id,
date() AS date,
'Punctual' AS frequency
FROM
payments
WHERE
frequency = 'Monthly'
AND deleted_at IS NULL
"#;
let res = sqlx::query(query).execute(pool).await;
match res {
Ok(_) => (),
Err(err) => log::error!("Error creating monthly payments: {:?}", err),
}
}
pub async fn last_week(pool: &SqlitePool) -> Vec<Report> {
let query = r#"
SELECT
strftime('%d/%m/%Y', payments.date) AS date,
(payments.name || ' (' || users.name || ')') AS name,
payments.cost AS amount,
(CASE
WHEN
payments.deleted_at IS NOT NULL
THEN
'Deleted'
WHEN
payments.updated_at IS NOT NULL
AND payments.created_at < date('now', 'weekday 0', '-13 days')
THEN
'Updated'
ELSE
'Created'
END) AS action
FROM
payments
INNER JOIN
users
ON
payments.user_id = users.id
WHERE
payments.frequency = 'Punctual'
AND (
(
payments.created_at >= date('now', 'weekday 0', '-13 days')
AND payments.created_at < date('now', 'weekday 0', '-6 days')
) OR (
payments.updated_at >= date('now', 'weekday 0', '-13 days')
AND payments.updated_at < date('now', 'weekday 0', '-6 days')
) OR (
payments.deleted_at >= date('now', 'weekday 0', '-13 days')
AND payments.deleted_at < date('now', 'weekday 0', '-6 days')
)
)
ORDER BY
payments.date
"#;
let res = sqlx::query_as::<_, Report>(query).fetch_all(pool).await;
match res {
Ok(payments) => payments,
Err(err) => {
log::error!("Error listing payments for report: {:?}", err);
vec![]
}
}
}
|