Source

quacken / budget_sync.py

The default branch has multiple heads

Full commit
  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
'''budget_sync -- load GnuCash budget from google docs spreadsheet
'''

import csv
import logging
from pprint import pformat

from sqlalchemy import (MetaData, Table, Column,
                        select, func, text)
from sqlalchemy.types import String, Date, Integer
from sqlalchemy.engine.url import URL

from gckey import findMaker

log = logging.getLogger(__name__)

Name = String(80)


def main(argv, open_arg, engine_arg,
         level=logging.DEBUG):
    logging.basicConfig(level=level)
    logging.getLogger('sqlalchemy.engine').setLevel(logging.INFO)

    gdoc_budget, engine, budget_name = open_arg(1), engine_arg(2), argv[3]

    budget = Budget(engine, budget_name)
    if '--by-parent' in argv:
        log.info('subtots:\n%s', pformat(budget.compare_subtots()))
    elif '--by-type' in argv:
        log.info('subtots:\n%s', pformat(budget.compare_by_acct_type()))
    elif '--load' in argv:
        budget.load(gdoc_budget)
        budget.check_dups()
        budget.sync_accounts(dry_run='--accounts' not in argv)
    elif [arg for arg in argv
          if arg != '--acounts' and arg.startswith('--')]:
        raise SystemExit('unrecognized arguments:' + str(argv[1:]))
    else:
        budget.load(gdoc_budget)
        budget.check_dups()
        budget.sync_accounts(dry_run='--accounts' not in argv)
        budget.sync_items()


GnuCashAux = MetaData()
BudgetItem = Table('gdocs_budget', GnuCashAux,
                   Column('id', Integer),
                   Column('guid', String(32)),
                   Column('budget_name', Name),
                   Column('budget_guid', String(32)),
                   Column('t_lo', String(40)),
                   Column('lo', Date),  # date
                   Column('period_num', Integer),
                   Column('account_type', Name),
                   Column('code', Name),
                   Column('parent', Name),
                   Column('name', Name),
                   Column('account_guid', String(32)),
                   Column('budget', String(20)),
                   Column('amount_num', Integer),
                   Column('amount_sign', Integer),
                   Column('slot_9', Integer),
                   Column('slot_3', Integer),
                   Column('notes', String(200)))

BudgetMatchUpdate = text('''
 update gdocs_budget
 set budget_guid = (
   select guid from budgets b
   where b.name = budget_name
 )
''')

AccountMatchUpdate = text('''
 update gdocs_budget bi
 join accounts a on a.code = bi.code
 join (
   select replace(uuid(), '-', '') guid, budget_name, code
   from (
     select distinct budget_name, code from gdocs_budget
   ) each_acct_budget
 ) ea on ea.code = bi.code and ea.budget_name = bi.budget_name
 set account_guid = a.guid,
     amount_sign =
         case a.account_type
           when 'INCOME' then 1
           when 'EXPENSE' then 1
           when 'ASSET' then -1
           when 'LIABILITY' then -1
           else 1/0
         end,
     bi.guid = ea.guid
 where bi.code > ''
''')

ItemMatchUpdate = text('''
 update gdocs_budget bi
 join budgets b on b.guid = bi.budget_guid
 join accounts a on a.guid = bi.account_guid
 join budget_amounts ba on ba.budget_guid = b.guid
              and ba.account_guid = a.guid
              and ba.period_num = bi.period_num
 set bi.id = ba.id
''')

SlotMatchUpdate = text('''
 update gdocs_budget bi
 join budgets b on b.guid = bi.budget_guid
 join accounts a on a.guid = bi.account_guid
 join slots s9 on s9.obj_guid = b.guid
              and s9.name = a.guid
              -- and s9.slot_type = 9
 join slots s3 on s3.obj_guid = s9.guid_val
              -- and s3.slot_type = 3
              and substr(s3.name, 34) = bi.period_num
 set bi.slot_9 = s9.id,
     bi.slot_3 = s3.id,
     bi.guid = s9.guid_val
''')

BudgetTypeUpdate = text('''
 update gdocs_budget
 set lo = STR_TO_DATE(t_lo,'%m/%d/%Y'),
     amount_num = 100 * replace(replace(budget, '$', ''), ',', '')
 where code > '' and t_lo > ''
''')

BudgetPeriodUpdate = text('''
 update gdocs_budget
 set period_num = mod(month(lo) - 1, 3)
''')


class Budget(object):
    def __init__(self, engine, name):
        self._engine = engine
        self._name = name

    def _prepare(self):
        log.info('dropping and creating %s',
                 [t.name for t in GnuCashAux.sorted_tables])
        GnuCashAux.drop_all(self._engine)
        GnuCashAux.create_all(self._engine)

    def load(self, infp):
        self._prepare()
        conn = self._engine.connect()
        sheet = csv.DictReader(infp)
        rows = [row for row in sheet
                if row['budget_name'] == self._name]
        log.info('inserting %d rows into %s', len(rows), BudgetItem)
        conn.execute(BudgetItem.insert(), rows)
        conn.execute(BudgetMatchUpdate)
        conn.execute(BudgetTypeUpdate)
        conn.execute(BudgetPeriodUpdate)
        conn.execute(AccountMatchUpdate)

    def sync_accounts(self, dry_run=True):
        conn = self._engine.connect()

        q = '''
select parent, name, count(name) from
(select distinct parent from gdocs_budget
where code > '' and t_lo > '') bi
left join accounts a
       on a.name=bi.parent
group by parent, name
having count(name) != 1
'''
        missing_acct = conn.execute(q).fetchall()

        log.debug('Ambiguous parents: %d', len(missing_acct))

        if missing_acct:
            log.error('Ambiguous parents:\n%s',
                      format_rows(missing_acct))
            raise IOError

        missing_acct_q = '''
select replace(uuid(), '-', '') as guid
     , bi.name, bi.account_type
     , usd.guid as commodity_guid
     , usd.fraction as commodity_scu, 0 as non_std_scu
     , ap.guid as parent_guid
     , bi.code
     , '' as description, 0 as hidden, 0 as placeholder
from (
  select distinct account_type, parent, name, code
  from gdocs_budget
  where code > '' ) bi
join accounts ap on ap.name = bi.parent
join commodities usd on usd.mnemonic = 'USD'
left join accounts a on a.code = bi.code
where a.guid is null
'''
        missing_acct = conn.execute(missing_acct_q).fetchall()

        log.debug('missing_acct: %d', len(missing_acct))

        if missing_acct:
            log.log(logging.ERROR if dry_run else logging.WARN,
                    'no such account code:\n%s',
                    format_rows(missing_acct))

            if dry_run:
                raise IOError

        log.info('inserting accounts...')
        result = conn.execute('insert into accounts ' + missing_acct_q)
        log.info('inserted %d rows', result.rowcount)

        conn.execute(AccountMatchUpdate)

    def check_dups(self):
        conn = self._engine.connect()
        q = select_dups(BudgetItem.select().
                        where(BudgetItem.c.code > '').alias('bi'),
                        key_cols=('budget_name', 't_lo', 'code'))
        dups = conn.execute(q).fetchall()
        log.debug('dups: %d', len(dups))

        if dups:
            log.error('duplicate keys in budget spreadsheet: %s',
                      format_rows(dups))
            raise IOError

    acct_type_q = '''select gcb.*, gdb.subtot,
      case when gcb.subtot = gdb.subtot then '' else 'MISMATCH' end ok
    from
    (select b.name budget_name, a.account_type,
    sum(ba.amount_num / ba.amount_denom) subtot
    from budgets b
    join budget_amounts ba on ba.budget_guid = b.guid
    join accounts a on a.guid = ba.account_guid
    where b.name in (%(budget_name)s)
    group by b.name, a.account_type) gcb
    join (
      select budget_name, account_type,
      sum(amount_num * amount_sign / 100.0) subtot
      from gdocs_budget bi
      where bi.code > ''
      and budget_name in (%(budget_name)s)
      group by budget_name, account_type
    ) gdb
      on gdb.budget_name = gcb.budget_name
      and gdb.account_type = gcb.account_type
    '''

    def compare_by_acct_type(self):
        conn = self._engine.connect()
        ans = conn.execute(self.acct_type_q, budget_name=self._name)
        return ans.fetchall()

    subtot_q = '''select gcb.*, gdb.subtot,
      case when gcb.subtot = gdb.subtot then '' else 'MISMATCH' end ok
    from
    (select b.name budget_name, a.account_type, p.name parent,
    sum(ba.amount_num / ba.amount_denom) subtot
    from budgets b
    join budget_amounts ba on ba.budget_guid = b.guid
    join accounts a on a.guid = ba.account_guid
    join accounts p on a.parent_guid = p.guid
    where b.name in (%(budget_name)s)
    group by b.name, a.account_type, p.name) gcb
    left join (
      select budget_name, account_type, parent,
      sum(amount_num * amount_sign / 100.0) subtot
      from gdocs_budget bi
      where bi.code > ''
      and budget_name in (%(budget_name)s)
      group by budget_name, account_type, parent
    ) gdb
      on gdb.budget_name = gcb.budget_name
      and gdb.account_type = gcb.account_type
      and gdb.parent = gcb.parent
    '''

    def compare_subtots(self):
        conn = self._engine.connect()
        ans = conn.execute(self.subtot_q, budget_name=self._name)
        return ans.fetchall()

    def sync_items(self):
        # TODO: update, rather than delete all and re-insert
        conn = self._engine.connect()

        log.info('matching slots...')
        result = conn.execute(SlotMatchUpdate)
        log.info('updated %d rows', result.rowcount)

        log.info('matching budget items...')
        result = conn.execute(ItemMatchUpdate)
        log.info('updated %d rows', result.rowcount)

        unmatched = conn.execute('''
select * from gdocs_budget
where code > '' and (budget_guid is null
   or account_guid is null
   or id is null
   or slot_9 is null
   or slot_3 is null)
''').fetchall()
        if unmatched:
            log.info('unmatched: %s', format_rows(unmatched))

        log.info('deleting budget_amounts...')
        result = conn.execute('''
delete from budget_amounts where budget_guid in (
  select distinct budget_guid
  from gdocs_budget where account_guid is not null
)
''')
        log.info('deleted %d rows', result.rowcount)

        log.info('inserting budget_amounts ...')
        conn.execute('''
insert into budget_amounts
select -- distinct bi.t_lo, bi.code, bi.name
       id,
       budget_guid,
       account_guid,
       period_num,
       amount_num * amount_sign amount_num,
       100 amount_denom
from gdocs_budget bi
join accounts a on a.guid=bi.account_guid
''')
        log.info('inserted %d rows', result.rowcount)

        log.info('deleting budget slots...')
        result = conn.execute('''
delete s3
from gdocs_budget bi
join slots s9 on bi.budget_guid = s9.obj_guid
             and bi.account_guid = s9.name
join slots s3 on s3.obj_guid = s9.guid_val;
''')
        log.info('deleted %d rows', result.rowcount)
        result = conn.execute('''
delete s9
from gdocs_budget bi
join slots s9 on bi.budget_guid = s9.obj_guid
             and bi.account_guid = s9.name
''')
        log.info('deleted %d rows', result.rowcount)

        log.info('inserting budget slots type 9...')
        result = conn.execute('''
insert into slots (id, obj_guid, name, slot_type, guid_val)
select distinct slot_9, budget_guid, account_guid, 9, guid
from gdocs_budget bi
where bi.account_guid is not null
''')
        log.info('inserted %d rows', result.rowcount)

        log.info('inserting budget slots type 3...')
        result = conn.execute('''
insert into slots (id, obj_guid, name,
                   slot_type, numeric_val_num, numeric_val_denom)
select slot_3, guid, concat(account_guid, '/', period_num),
       3, amount_num * amount_sign, 100
from gdocs_budget bi
where bi.account_guid is not null
order by period_num
''')
        log.info('inserted %d rows', result.rowcount)


def select_dups(from_obj, key_cols,
                crit=func.count() > 1):
    '''
    >>> print select_dups(from_obj='t', key_cols=('a', 'b', 'c'))
    ... # doctest: +NORMALIZE_WHITESPACE
    SELECT a, b, c, count(*) AS count_1
    FROM t GROUP BY a, b, c
    HAVING count(*) > :count_2
    '''
    return select(key_cols + (func.count(), ), from_obj=from_obj).\
        group_by(*key_cols).having(crit)


def format_rows(rows):
    return '\n'.join([str(row) for row in rows])


if __name__ == '__main__':
    def _with_caps(host='localhost'):
        from sys import argv
        import gnomekeyring as gk
        from sqlalchemy import create_engine

        def open_arg(ix):
            return open(argv[ix])

        def engine_arg(ix):
            db = argv[ix]
            findcreds = findMaker(gk.find_network_password_sync)
            log.info('getting keyring info for %s', db)
            creds = findcreds(db)
            return create_engine(
                URL(drivername='mysql', host=host, database=db,
                    username=creds['user'],
                    password=creds['password']))

        return main(argv=argv,
                    open_arg=open_arg,
                    engine_arg=engine_arg)

    _with_caps()