aboutsummaryrefslogtreecommitdiff
path: root/src/db/incomes.rs
blob: f2eaf1c0cb5043cefca23f3a4a14b7ae2fa0a161 (plain)
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
use chrono::NaiveDate;
use sqlx::error::Error;
use sqlx::sqlite::{SqlitePool, SqliteRow};
use sqlx_core::row::Row;
use std::collections::HashMap;
use std::iter::FromIterator;

use crate::model::income::{Create, Form, Stat, Table, Update};
use crate::model::report::Report;

pub async fn count(pool: &SqlitePool) -> i64 {
    let query = r#"
SELECT
    COUNT(*) AS count
FROM
    incomes
WHERE
    incomes.deleted_at IS NULL
        "#;

    let res = sqlx::query(&query)
        .map(|row: SqliteRow| row.get("count"))
        .fetch_one(pool)
        .await;

    match res {
        Ok(count) => count,
        Err(err) => {
            error!("Error counting incomes: {:?}", err);
            0
        }
    }
}

pub async fn list(pool: &SqlitePool, page: i64, per_page: i64) -> Vec<Table> {
    let query = r#"
SELECT
    incomes.id,
    users.name AS user,
    strftime('%m/%Y', incomes.date) AS date,
    incomes.amount
FROM
    incomes
INNER JOIN
    users
ON
    incomes.user_id = users.id
WHERE
    incomes.deleted_at IS NULL
ORDER BY
    incomes.date DESC
LIMIT ?
OFFSET ?
    "#;

    let res = sqlx::query_as::<_, Table>(query)
        .bind(per_page)
        .bind((page - 1) * per_page)
        .fetch_all(pool)
        .await;

    match res {
        Ok(incomes) => incomes,
        Err(err) => {
            error!("Error listing incomes: {:?}", err);
            vec![]
        }
    }
}

pub async fn get_row(pool: &SqlitePool, id: i64) -> i64 {
    let query = r#"
SELECT
    row
FROM (
    SELECT 
        ROW_NUMBER () OVER (ORDER BY date DESC) AS row,
        id
    FROM
        incomes
    WHERE
        deleted_at IS NULL
)
WHERE
    id = ?
    "#;

    let res = sqlx::query(query)
        .bind(id)
        .map(|row: SqliteRow| row.get("row"))
        .fetch_one(pool)
        .await;

    match res {
        Ok(count) => count,
        Err(err) => {
            error!("Error getting income row: {:?}", err);
            1
        }
    }
}

pub async fn get(pool: &SqlitePool, id: i64) -> Option<Form> {
    let query = r#"
SELECT
    id,
    amount,
    user_id,
    CAST(strftime('%m', date) AS INTEGER) as month,
    CAST(strftime('%Y', date) AS INTEGER) as year
FROM
    incomes
WHERE
    id = ?
    AND deleted_at IS NULL
    "#;

    let res = sqlx::query_as::<_, Form>(query)
        .bind(id)
        .fetch_one(pool)
        .await;

    match res {
        Ok(p) => Some(p),
        Err(err) => {
            error!("Error looking for income {}: {:?}", id, err);
            None
        }
    }
}

pub async fn create(pool: &SqlitePool, i: &Create) -> Option<i64> {
    let res = sqlx::query(
        r#"
INSERT INTO
    incomes(user_id, date, amount)
VALUES
    (?, ?, ?)
    "#,
    )
    .bind(i.user_id)
    .bind(NaiveDate::from_ymd_opt(i.year, i.month, 1)?)
    .bind(i.amount)
    .execute(pool)
    .await;

    match res {
        Ok(x) => Some(x.last_insert_rowid()),
        Err(err) => {
            error!("Error creating income: {:?}", err);
            None
        }
    }
}

pub async fn defined_at(
    pool: &SqlitePool,
    user_id: i64,
    month: u32,
    year: i32,
) -> Vec<i64> {
    let query = r#"
SELECT
    id
FROM
    incomes
WHERE
    user_id = ?
    AND date = ?
    AND deleted_at IS NULL
    "#;

    let res = sqlx::query(&query)
        .bind(user_id)
        .bind(NaiveDate::from_ymd(year, month, 1))
        .map(|row: SqliteRow| row.get("id"))
        .fetch_all(pool)
        .await;

    match res {
        Ok(ids) => ids,
        Err(Error::RowNotFound) => vec![],
        Err(err) => {
            error!("Error looking if income is defined: {:?}", err);
            vec![]
        }
    }
}

pub async fn update(pool: &SqlitePool, id: i64, i: &Update) -> bool {
    let res = sqlx::query(
        r#"
UPDATE
    incomes
SET
    user_id = ?,
    date = ?,
    amount = ?,
    updated_at = datetime()
WHERE
    id = ?
    "#,
    )
    .bind(i.user_id)
    .bind(NaiveDate::from_ymd(i.year, i.month, 1))
    .bind(i.amount)
    .bind(id)
    .execute(pool)
    .await;

    match res {
        Ok(_) => true,
        Err(err) => {
            error!("Error updating income {}: {:?}", id, err);
            false
        }
    }
}

pub async fn delete(pool: &SqlitePool, id: i64) -> bool {
    let res = sqlx::query(
        r#"
UPDATE
    incomes
SET
    deleted_at = datetime()
WHERE
    id = ?
    "#,
    )
    .bind(id)
    .execute(pool)
    .await;

    match res {
        Ok(_) => true,
        Err(err) => {
            error!("Error deleting income {}: {:?}", id, err);
            false
        }
    }
}

pub async fn defined_for_all(pool: &SqlitePool) -> Option<NaiveDate> {
    let res = sqlx::query(
        r#"
SELECT
    (CASE COUNT(users.id) == COUNT(min_income.date)
        WHEN 1 THEN MIN(min_income.date)
        ELSE NULL
    END) AS date
FROM
    users
LEFT OUTER JOIN (
    SELECT
        user_id,
        MIN(date) AS date
    FROM
        incomes
    WHERE
        deleted_at IS NULL
    GROUP BY
        user_id
) min_income
ON
    users.id = min_income.user_id;
    "#,
    )
    .map(|row: SqliteRow| row.get("date"))
    .fetch_one(pool)
    .await;

    match res {
        Ok(d) => d,
        Err(err) => {
            error!("Error looking for incomes defined for all: {:?}", err);
            None
        }
    }
}

pub async fn cumulative(
    pool: &SqlitePool,
    from: NaiveDate,
) -> HashMap<i64, i64> {
    let res = sqlx::query(&cumulative_query(from))
        .map(|row: SqliteRow| (row.get("user_id"), row.get("income")))
        .fetch_all(pool)
        .await;

    match res {
        Ok(incomes) => HashMap::from_iter(incomes),
        Err(err) => {
            error!("Error computing cumulative income: {:?}", err);
            HashMap::new()
        }
    }
}

/// Select cumulative income of users from the given date and until now.
///
/// Associate each month income to its start and end bounds,
/// then compute the total income of each period,
/// sum it to get the final result.
///
/// Considering each month to be 365 / 12 days long.
fn cumulative_query(from: NaiveDate) -> String {
    format!(
        r#"
SELECT
    users.id AS user_id,
    COALESCE(incomes.income, 0) AS income
FROM
    users
LEFT OUTER JOIN (
    SELECT
        user_id,
        CAST(ROUND(SUM(count)) AS INTEGER) AS income
    FROM (
        SELECT
            I1.user_id,
            ((JULIANDAY(MIN(I2.date)) - JULIANDAY(I1.date)) * I1.amount * 12 / 365) AS count
        FROM
            ({}) AS I1
        INNER JOIN
            ({}) AS I2
        ON
            I2.date > I1.date
            AND I2.user_id == I1.user_id
        GROUP BY
            I1.date, I1.user_id
    )
    GROUP BY
        user_id
) incomes
ON
    users.id = incomes.user_id
    "#,
        bounded_query(">".to_string(), from.format("%Y-%m-%d").to_string()),
        bounded_query("<".to_string(), "date()".to_string())
    )
}

/// Select bounded incomes to the operator and date.
///
/// It filters incomes according to the operator and date,
/// and adds the income at this date.
fn bounded_query(op: String, date: String) -> String {
    format!(
        r#"
SELECT
    user_id,
    date,
    amount
FROM (
    SELECT
        user_id,
        {} AS date,
        amount,
        MAX(date) AS max_date
    FROM
        incomes
    WHERE
        date <= {}
        AND deleted_at IS NULL
    GROUP BY
        user_id
) UNION
SELECT
    user_id,
    date,
    amount
FROM
    incomes
WHERE
    date {} {}
    AND deleted_at IS NULL
    "#,
        date, date, op, date
    )
}

/// Select total income each month.
///
/// For each month, from the first defined income and until now,
/// compute the total income of the users.
pub async fn total_each_month(pool: &SqlitePool) -> Vec<Stat> {
    let query = r#"
WITH RECURSIVE dates(date) AS (
    VALUES((
        SELECT
            strftime('%Y-%m-01', MIN(date))
        FROM
            incomes
        WHERE
            deleted_at IS NULL
    ))
    UNION ALL
    SELECT
        date(date, '+1 month')
    FROM
        dates
    WHERE
        date < date(date(), '-1 month')
)
SELECT
    strftime('%Y-%m-01', dates.date) AS date,
    (
        SELECT
            SUM(amount) AS amount
        FROM (
            SELECT (
                SELECT
                    amount
                FROM
                    incomes
                WHERE
                    user_id = users.id
                    AND date < date(dates.date, '+1 month')
                    AND deleted_at IS NULL
                ORDER BY
                    date DESC
                LIMIT
                    1
            ) AS amount
            FROM
                users
        )
    ) AS amount
FROM
    dates;
    "#;

    let res = sqlx::query_as::<_, Stat>(query).fetch_all(pool).await;

    match res {
        Ok(xs) => xs,
        Err(err) => {
            error!("Error listing incomes for statistics: {:?}", err);
            vec![]
        }
    }
}

pub async fn last_week(pool: &SqlitePool) -> Vec<Report> {
    let query = r#"
SELECT
    strftime('%m/%Y', incomes.date) AS date,
    users.name AS name,
    incomes.amount AS amount,
    (CASE
        WHEN
            incomes.deleted_at IS NOT NULL
        THEN
            'Deleted'
        WHEN
            incomes.updated_at IS NOT NULL
            AND incomes.created_at < date('now', 'weekday 0', '-13 days')
        THEN
            'Updated'
        ELSE
            'Created'
    END) AS action
FROM
    incomes
INNER JOIN
    users
ON
    incomes.user_id = users.id
WHERE
    (
        incomes.created_at >= date('now', 'weekday 0', '-13 days')
        AND incomes.created_at < date('now', 'weekday 0', '-6 days')
    ) OR (
        incomes.updated_at >= date('now', 'weekday 0', '-13 days')
        AND incomes.updated_at < date('now', 'weekday 0', '-6 days')
    ) OR (
        incomes.deleted_at >= date('now', 'weekday 0', '-13 days')
        AND incomes.deleted_at < date('now', 'weekday 0', '-6 days')
    )
ORDER BY
    incomes.date
    "#;

    let res = sqlx::query_as::<_, Report>(query).fetch_all(pool).await;

    match res {
        Ok(payments) => payments,
        Err(err) => {
            error!("Error listing payments for report: {:?}", err);
            vec![]
        }
    }
}