1. Dan Connolly
  2. quacken

Source

quacken / trx_explore.py

The default branch has multiple heads

  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
'''trx_explore -- migrate Mint transactions to gnucash

.. todo:: migrate notes
.. todo:: migrate edited descriptions

Things about Mint that I'm likely to miss:
  - simple, comprehensive search
  - budget report showing difference
  - trends by month
    - not to mention 2d breakdowns from Quicken
'''

import json
import pprint
import logging
import datetime
import warnings

import sqlalchemy
from sqlalchemy import Column
from sqlalchemy.ext.declarative import declarative_base
from sqlalchemy.types import Integer, String, Boolean, Date, DECIMAL

log = logging.getLogger(__name__)

Money = DECIMAL(precision=8, scale=2)
FreeText = String(250)
TagList = String(250)
Name = String(80)

Base = declarative_base()
Session = sqlalchemy.orm.sessionmaker()


def explore(fp):
    data = json.load(fp)
    pprint.pprint(data)
    #all_cols(data)
    #show_labels(data)


def load(fp, engine):
    data = json.load(fp)

    try:
        MintTrx.__table__.drop(bind=engine)
    except:
        pass

    try:
        MintTag.__table__.drop(bind=engine)
    except:
        pass

    Base.metadata.create_all(engine)
    s = Session(bind=engine)

    # parents may be repeated in data, so convert to dict
    for o in dict([(o['id'], o) for o in data]).values():
        s.add(mktrx(o))

    for trx, label, name in [(tx['id'], l['id'], l['name'])
                             for tx in data
                             for l in tx['labels']]:
        s.add(MintTag(trx=trx, label=label, name=name))

    s.commit()

    return s


def show_stats(s, limit=15):
    pprint.pprint(s.execute('''
        select count(*), merchant
        from minttrx
        group by merchant
        order by 1 desc
        ''').fetchmany(limit))
    pprint.pprint(s.execute('''
        select count(*), label, name
        from minttag
        group by label, name
        order by 1 desc
        ''').fetchmany(limit))



def show_labels(data):
    print "Labels:"
    pprint.pprint([(tx['id'], l['id'], l['name'])
                   for tx in data
                   for l in tx['labels']])


MONTHS = [datetime.date(2011, m, 1).strftime('%b') for m in range(1, 13)]

def mktrx(o):
    fields = dict([(str(k), v)  # **args can't be unicode
                   for k, v in o.iteritems()
                   if k in MintTrx.__dict__.keys()])

    amount=float(o['amount'].replace('$', '').replace(',', ''))

    this_year = datetime.date.today().year
    return MintTrx(**dict(fields,
                          date=mkdate(o['date'], this_year),
                          amount=amount,
                          children=len(o.get('children', [])) or None))


def mkdate(txt, this_year):
    '''
    >>> mkdate('Nov 21', 2011)
    datetime.date(2011, 11, 21)

    >>> mkdate('12/30/10', 2011)
    datetime.date(2010, 12, 30)

    >>> mkdate('12/30/56', 2011)
    datetime.date(1956, 12, 30)
    '''
    if txt[0].isdigit():
        m, d, yy = [int(numeral) for numeral in txt.split('/')]
        century = this_year - (this_year % 100) - (100 if yy > 50 else 0)
        y = century + yy
    else:
        y = this_year
        m = MONTHS.index(txt[:3]) + 1
        d = int(txt[4:])
    return datetime.date(y, m, d)


def explore_db(fn):
    e = sqlalchemy.create_engine('sqlite:///' + fn)
    show_tables(e)


def show_tables(engine):
    meta = sqlalchemy.MetaData()

    with warnings.catch_warnings():
        warnings.simplefilter("module")
        # "Did not recognize type 'BIGINT' of column .*")
        meta.reflect(bind=engine)
    for t in meta.tables:
        print t


class MintTrx(Base):
    __tablename__ = 'minttrx'

    id = Column(Integer, primary_key=True)

    account = Column(Name)
    amount = Column(Money, nullable=False)
    category = Column(Name, nullable=False)
    categoryId = Column(Integer, nullable=False)
    date = Column(Date, nullable=False)
    fi = Column(Name)
    #inlineadviceid = Column(String)
    #isAfterFiCreationTime = Column(String)
    isCheck = Column(Boolean)
    isChild = Column(Boolean, nullable=False)
    parent = Column(Integer)
    children = Column(Integer)  # normalized a bit
    isDebit = Column(Boolean, nullable=False)
    isDuplicate = Column(Boolean, nullable=False)
    isEdited = Column(Boolean)
    #isFirstDate = Column(String)
    #isLinkedToRule = Column(String)
    #isMatched = Column(String)
    isPending = Column(Boolean)
    isSpending = Column(Boolean)
    isTransfer = Column(Boolean)
    #labels = Column(String)
    #manualType = Column(String)
    mcategory = Column(Name)
    merchant = Column(FreeText)
    mmerchant = Column(FreeText)
    note = Column(FreeText)
    #numberMatchedByRule = Column(String)
    odate = Column(Name)
    omerchant = Column(FreeText, nullable=False)
    #ruleCategory = Column(String)
    #ruleCategoryId = Column(String)
    #ruleMerchant = Column(String)
    #txnType = Column(String)


class MintAcct(Base):
    __tablename__ = 'mintacct'
    id = Column(Integer, primary_key=True)
    #kind = Column(Enum('A', 'L', 'I', 'E', 'Q'), primary_key=True)
    name = Column(Name)


class MintTag(Base):
    __tablename__ = 'minttag'
    id = Column(Integer, primary_key=True)
    trx = Column(Integer)  # ForeignKey...
    label = Column(Integer)  # ForeignKey...
    name = Column(Name)


def all_cols(data):
    cols = set([k for item in data for k in item.keys()])
    print "columns"
    pprint.pprint(cols)


def mk_cols():
    names = [u'account',
             u'amount',
             u'category',
             u'categoryId',
             u'date',
             u'fi',
             u'id',
             u'inlineadviceid',
             u'isAfterFiCreationTime',
             u'isCheck',
             u'isChild',
             u'isDebit',
             u'isDuplicate',
             u'isEdited',
             u'isFirstDate',
             u'isLinkedToRule',
             u'isMatched',
             u'isPending',
             u'isSpending',
             u'isTransfer',
             u'labels',
             u'manualType',
             u'mcategory',
             u'merchant',
             u'mmerchant',
             u'note',
             u'numberMatchedByRule',
             u'odate',
             u'omerchant',
             u'ruleCategory',
             u'ruleCategoryId',
             u'ruleMerchant',
             u'txnType']
    for n in names:
        print "    %s = Column(String)" % n


def main_(argv):
    dbfn = argv[1]
    print "dbfn:", dbfn
    explore_db(dbfn)


def match(engine):
    with warnings.catch_warnings():
        #warnings.filterwarnings("once",
        #                        "Did not recognize type 'BIGINT' of column .*")
        warnings.simplefilter("ignore")
        Base.metadata.reflect(bind=engine)

    # TODO: consider matching on account id rather than name.

    engine.execute('drop table if exists acctmatch')
    engine.execute('''
    create table acctmatch as
    select sp.guid split_guid, tx.guid tx_guid, mtx.id mint_tx_id
         , mtx.amount_num, mtx.categoryId, mtx.category
    from splits sp
    join transactions tx on sp.tx_guid = tx.guid
    join accounts acct on sp.account_guid = acct.guid,
    minttrx mtx
    where mtx.account = acct.name
      and mtx.isChild = 0 and mtx.isDuplicate = 0
      and mtx.amount_num = sp.quantity_num
      and substr(tx.post_date, 5, 4) = mtx.date_yymm
    ''')
#      and substr(mtx.omerchant, 1, 20) = substr(tx.description, 1, 20)

    engine.execute('drop table if exists catmatch')
    engine.execute('''
    create table catmatch as
    select sp.guid split_guid, acct.guid account_guid, acctmatch.mint_tx_id
    from transactions tx
    join acctmatch on acctmatch.tx_guid = tx.guid
    join splits sp on sp.tx_guid = tx.guid
     and sp.quantity_num = -acctmatch.amount_num
    join accounts acct on acctmatch.category = acct.name
    ''')

    ans = engine.execute('''
        select count(*), split_guid
        from catmatch
        group by catmatch.split_guid
        having count(*) > 1
        ''')
    dups = ans.fetchall()
    log.warn('dups: %d\n %s', len(dups), pprint.pformat(dups))
    if len(dups) > 0:
        log.warn('catmatch:\n%s', pprint.pformat(
            engine.execute('''
                select mtx.*
                from minttrx mtx
                join catmatch on mtx.id = catmatch.mint_tx_id
                join (
                  select count(*), split_guid
                  from catmatch
                  group by catmatch.split_guid
                  having count(*) > 1) dups
                  on dups.split_guid = catmatch.split_guid
                order by mtx.id''') \
            .fetchall()))
        
    ans = engine.execute(
    '''
    select mtx.date, tx.post_date, tx.description, sp.quantity_num
         , acct_old.name, acct_new.name
    from catmatch
    join splits sp on sp.guid = catmatch.split_guid
    join transactions tx on sp.tx_guid = tx.guid
    join accounts acct_old on acct_old.guid = sp.account_guid
    join accounts acct_new on acct_new.guid = catmatch.account_guid
    join minttrx mtx on mtx.id = catmatch.mint_tx_id
    order by tx.post_date
    ''')
    rows = ans.fetchall()
    log.info('matches: %d\n %s', len(rows), pprint.pformat(rows))

    if len(dups) == 0:
        engine.execute('''
        update splits
        set account_guid = (
          select account_guid from catmatch
          where catmatch.split_guid = guid )
        where guid in (select split_guid from catmatch)
        ''')

    engine.execute('drop table if exists splitmatch')
    engine.execute('''
        create table splitmatch as
        select ms.date, tx.post_date
             , sp.quantity_num, mtx.amount_num, mtx.category
             , mtx.id mint_tx_id
             , sp.guid split_guid
             , tx.guid tx_guid
        from (
          select mtx.date, mtx.date_yymm, mtx.account, sum(mtx.amount_num) tot
          from minttrx mtx
          where mtx.isChild = 1
          group by account, date) ms

        join splits sp on sp.quantity_num = ms.tot
        join transactions tx on sp.tx_guid = tx.guid
         and substr(tx.post_date, 5, 4) = ms.date_yymm
        join accounts acct_old on acct_old.guid = sp.account_guid
        join minttrx mtx
          on mtx.date = ms.date
         and mtx.account = ms.account
         and mtx.isChild = 1
        ''')
    ans = engine.execute('''select * from splitmatch order by post_date''')
    log.warn('split matches:\n%s', pprint.pformat(ans.fetchall()))

    ans = engine.execute(
    '''
    select mtx.date,mtx.omerchant,mtx.category,mtx.amount
         , mtx.isChild, mtx.isTransfer, mtx.isPending
    from minttrx mtx
    left join catmatch on catmatch.mint_tx_id = mtx.id
    left join splitmatch on splitmatch.mint_tx_id = mtx.id
    where catmatch.split_guid is null
      and splitmatch.split_guid is null
      and mtx.category != 'Exclude From Mint'
      and mtx.isPending != 1 and mtx.isDuplicate != 1
    order by mtx.id
    ''')
    rows = ans.fetchall()
    log.warn('mismatches: %d\n %s', len(rows), pprint.pformat(rows))

    ans = engine.execute('''
        select distinct mtx.categoryId as id, mtx.category as name
        from minttrx mtx
        left join catmatch on catmatch.mint_tx_id = mtx.id
        left join splitmatch on splitmatch.mint_tx_id = mtx.id
        where catmatch.split_guid is null
          and splitmatch.split_guid is null
          and mtx.category != 'Exclude From Mint'
          and mtx.isPending != 1 and mtx.isDuplicate != 1
        order by mtx.category
        ''')
    log.warn('missing categories: %s', pprint.pformat(ans.fetchall()))


def main(argv):
    logging.basicConfig(level=logging.WARN)

    if '--explore' in argv:
        trxfn = argv[2]
        explore(open(trxfn))
    elif '--load' in argv:
        trxfn, dburl = argv[2:4]
        s = load(open(trxfn),
                 sqlalchemy.create_engine(dburl))
        show_stats(s)
    elif '--match' in argv:
        dbfn = argv[2]
        match(sqlalchemy.create_engine('sqlite:///' + dbfn))

if __name__ == '__main__':
    import sys
    main(sys.argv)