├── README ├── sqlite2dot.tcl └── sqlite2dot.py /README: -------------------------------------------------------------------------------- 1 | This script aims at providing a visualization of a SQLite schema by creating a .dot file 2 | for use with the Graphwiz program. 3 | 4 | Requires: 5 | Tcl 6 | Sqlite package for Tcl 7 | 8 | Usage: tclsh sqlite2dot.tcl 9 | 10 | 11 | # Copyright (c) 2011, Fredrik Karlsson 12 | # All rights reserved. 13 | # 14 | # Redistribution and use in source and binary forms, with or without 15 | # modification, are permitted provided that the following conditions are met: 16 | # 1. Redistributions of source code must retain the above copyright 17 | # notice, this list of conditions and the following disclaimer. 18 | # 2. Redistributions in binary form must reproduce the above copyright 19 | # notice, this list of conditions and the following disclaimer in the 20 | # documentation and/or other materials provided with the distribution. 21 | # 3. All advertising materials mentioning features or use of this software 22 | # must display the following acknowledgement: 23 | # 4. Neither the name of the main author nor the 24 | # names of its contributors may be used to endorse or promote products 25 | # derived from this software without specific prior written permission. 26 | # 27 | # THIS SOFTWARE IS PROVIDED BY FREDRIK KARLSSON ''AS IS'' AND ANY 28 | # EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 29 | # WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 30 | # DISCLAIMED. IN NO EVENT SHALL FREDRIK KARLSSON BE LIABLE FOR ANY 31 | # DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES 32 | # (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; 33 | # LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND 34 | # ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT 35 | # (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS 36 | # SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 37 | 38 | -------------------------------------------------------------------------------- /sqlite2dot.tcl: -------------------------------------------------------------------------------- 1 | # Copyright (c) 2011, Fredrik Karlsson 2 | # All rights reserved. 3 | # 4 | # Redistribution and use in source and binary forms, with or without 5 | # modification, are permitted provided that the following conditions are met: 6 | # 1. Redistributions of source code must retain the above copyright 7 | # notice, this list of conditions and the following disclaimer. 8 | # 2. Redistributions in binary form must reproduce the above copyright 9 | # notice, this list of conditions and the following disclaimer in the 10 | # documentation and/or other materials provided with the distribution. 11 | # 3. All advertising materials mentioning features or use of this software 12 | # must display the following acknowledgement: 13 | # 4. Neither the name of the main author nor the 14 | # names of its contributors may be used to endorse or promote products 15 | # derived from this software without specific prior written permission. 16 | # 17 | # THIS SOFTWARE IS PROVIDED BY FREDRIK KARLSSON ''AS IS'' AND ANY 18 | # EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 19 | # WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 20 | # DISCLAIMED. IN NO EVENT SHALL FREDRIK KARLSSON BE LIABLE FOR ANY 21 | # DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES 22 | # (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; 23 | # LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND 24 | # ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT 25 | # (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS 26 | # SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 27 | 28 | 29 | package require sqlite3 30 | 31 | if {[llength $argv] != 1} { 32 | 33 | puts stderr "Wrong number of arguments" 34 | puts stderr "Should be: \n\nsqlite2dot.tcl " 35 | exit 36 | } 37 | 38 | sqlite3 db [lindex $argv 0] 39 | 40 | db eval {select name from sqlite_master where type = "table" and name NOT LIKE "%sqlite_%"} { 41 | lappend tables $name 42 | 43 | } 44 | 45 | 46 | 47 | append out "digraph structs \{\n" 48 | append out "\taspect=0.7;\n" 49 | append out "\tnode \[width=4,shape=plaintext\];\n" 50 | 51 | foreach currtab $tables { 52 | 53 | set isFirst 1 54 | set rows "" 55 | 56 | append out [format { subgraph cluster_%s %s} $currtab "\{" ] 57 | append out [format "\n\t\tlabel=\"%s\";\n" $currtab ] 58 | append out "\t\trank=same;\n" 59 | append out "\t\tclusterrank=local;\n" 60 | append out "\t\trankdir=LR;\n" 61 | append out "\t\tlabeljust=l;\n" 62 | append out "\t\tstyle=dotted;\n" 63 | db eval [format {PRAGMA table_info(%s);} $currtab] vals { 64 | append rows [format {%s%s} $vals(name) $vals(name) $vals(name) $vals(type)] 65 | append rows "\n" 66 | } 67 | 68 | 69 | append out [format { %s [weight=10,label=<%s
%s
>];} $currtab $currtab $currtab $rows] 70 | append out "\n" 71 | 72 | db eval [format {PRAGMA foreign_key_list(%s);} $currtab] vals { 73 | append out [format { %s:%s -> %s:%s [arrowhead=vee,style=dotted];} $currtab $vals(from) $vals(table) $vals(to) ] 74 | append out "\n" 75 | } 76 | 77 | 78 | #Index stuff 79 | set indexes [list] 80 | set rows "" 81 | 82 | db eval [format {PRAGMA index_list(%s);} $currtab] vals { 83 | lappend indexes $vals(name) 84 | append rows [format {%s} $vals(name) $vals(name) ] 85 | append rows "\n" 86 | } 87 | 88 | 89 | 90 | append out [format { %s_idx [weight=10,label=<%s
indicies
>];} $currtab $currtab $rows] 91 | append out "\n" 92 | 93 | foreach idx $indexes { 94 | db eval [format {PRAGMA index_info(%s);} $idx] idxinfo { 95 | append out [format { %s_idx:%s -> %s:%s_type [label="%d",style="dashed",arrowhead=diamond,arrowtail=diamond,dir=both, arrowsize=0.6];} $currtab $idx $currtab $idxinfo(name) $idxinfo(seqno)] 96 | append out "\n" 97 | 98 | } 99 | 100 | } 101 | append out "\t\}\n" 102 | 103 | } 104 | 105 | append out "\}" 106 | puts $out 107 | 108 | -------------------------------------------------------------------------------- /sqlite2dot.py: -------------------------------------------------------------------------------- 1 | # -*- coding: utf-8 -*- 2 | 3 | # Copyright (c) 2015, Françoise Conil 4 | # Copyright (c) 2011, Fredrik Karlsson 5 | # All rights reserved. 6 | # 7 | # Redistribution and use in source and binary forms, with or without modification, 8 | # are permitted provided that the following conditions are met: 9 | # 10 | # 1. Redistributions of source code must retain the above copyright notice, this 11 | # list of conditions and the following disclaimer. 12 | # 13 | # 2. Redistributions in binary form must reproduce the above copyright notice, 14 | # this list of conditions and the following disclaimer in the documentation 15 | # and/or other materials provided with the distribution. 16 | # 17 | # 3. Neither the name of the copyright holder nor the names of its contributors 18 | # may be used to endorse or promote products derived from this software without 19 | # specific prior written permission. 20 | # 21 | # THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND 22 | # ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 23 | # WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED. 24 | # IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, 25 | # INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, 26 | # BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE, 27 | # DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY 28 | # OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING 29 | # NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, 30 | # EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 31 | 32 | """ 33 | This is a python version of Fredrik Karlsson sqlite2dot TCL script. 34 | 35 | Those scripts aim at providing a visualization of a SQLite schema by creating a .dot file 36 | for use with the Graphwiz program. 37 | """ 38 | 39 | import sys 40 | import os 41 | 42 | import sqlite3 43 | 44 | def dict_factory(cursor, row): 45 | d = {} 46 | for idx, col in enumerate(cursor.description): 47 | d[col[0]] = row[idx] 48 | return d 49 | 50 | def sqlite_db_tables(c=None): 51 | """ 52 | List the tables of a sqlite database. 53 | How do I list all tables/indices contained in an SQLite database : 54 | https://www.sqlite.org/faq.html#q7 55 | """ 56 | db_tables = [] 57 | 58 | if c is not None: 59 | c.execute('select name from sqlite_master where type = "table" and name NOT LIKE "%sqlite_%"') 60 | 61 | rows = c.fetchall() 62 | 63 | for r in rows: 64 | db_tables.append(r['name']) 65 | 66 | return db_tables 67 | 68 | def sqlite_table_columns(c=None, table=None): 69 | """ 70 | The PRAGMA statement is an SQL extension specific to SQLite and used to modify the operation of the SQLite library or to query the SQLite library for internal (non-table) data. 71 | https://sqlite.org/pragma.html 72 | """ 73 | db_columns = [] 74 | 75 | if c is not None and table is not None: 76 | c.execute('PRAGMA table_info("{0}")'.format(table)) 77 | 78 | rows = c.fetchall() 79 | 80 | for r in rows: 81 | db_columns.append(r) 82 | 83 | return db_columns 84 | 85 | def sqlite_table_foreign_keys(c=None, table=None): 86 | """ 87 | """ 88 | db_fk = [] 89 | 90 | if c is not None and table is not None: 91 | c.execute('PRAGMA foreign_key_list({0})'.format(table)) 92 | 93 | rows = c.fetchall() 94 | 95 | for r in rows: 96 | db_fk.append(r) 97 | 98 | return db_fk 99 | 100 | def sqlite_table_indexes(c=None, table=None): 101 | """ 102 | """ 103 | db_index = {} 104 | 105 | if c is not None and table is not None: 106 | c.execute('PRAGMA index_list({0})'.format(table)) 107 | 108 | rows = c.fetchall() 109 | 110 | for r in rows: 111 | db_index[r['name']] = {} 112 | db_index[r['name']]['infos'] = r 113 | 114 | for idx in db_index.keys(): 115 | c.execute('PRAGMA index_info({0})'.format(idx)) 116 | 117 | rows = c.fetchall() 118 | 119 | db_index[idx]['composed_of'] = [] 120 | for r in rows: 121 | db_index[idx]['composed_of'].append(r) 122 | 123 | return db_index 124 | 125 | def write_graphiz_graph(db_struct=None, db_filename=None): 126 | """ 127 | http://graphviz.org/Documentation.php 128 | 129 | Would it be interesting to use the python graphviz package ? 130 | https://pypi.python.org/pypi/graphviz/ 131 | """ 132 | gviz_filename = None 133 | 134 | if db_struct is not None and db_filename is not None: 135 | # Generates a .dot filename from the db filename 136 | gviz_filename = '{0}.dot'.format(os.path.splitext(db_filename)[0]) 137 | 138 | with open(gviz_filename, 'w') as f: 139 | #f.write('digraph structs {\n') 140 | f.write('digraph {\n') 141 | f.write('\t\trankdir=LR;\n') 142 | f.write('\t\tlabel="{0}";\n'.format(os.path.split(db_filename)[1])) 143 | f.write('\t\tlabelloc="t";\n') 144 | 145 | for tname, tstruct in db_struct.items(): 146 | #f.write('\tsubgraph cluster_{0} {1}\n'.format(tname, '{')) 147 | f.write('\t\tnode [shape=none];\n') 148 | #f.write('\t\tlabel=\"{0}\";\n'.format(tname)) 149 | #f.write('\t\trank=same;\n') 150 | #f.write('\t\tclusterrank=local;\n') 151 | #f.write('\t\tlabeljust=l;\n') 152 | #f.write('\t\tstyle=dotted;\n') 153 | 154 | rows = [] 155 | for cols in tstruct['columns']: 156 | rows.append('{0}{1}'.format(cols['name'], cols['type'].lower())) 157 | 158 | irows = [] 159 | if len(tstruct['idx']) > 0: 160 | for idx in tstruct['idx'].keys(): 161 | if tstruct['idx'][idx]['infos']['unique']: 162 | rows.append('{0}'.format(idx)) 163 | else: 164 | rows.append('{0}'.format(idx)) 165 | 166 | f.write('\t\t{0} [label=<{1}{2}
{0}
>];\n'.format(tname, 167 | "".join(rows), 168 | "".join(irows))) 169 | 170 | if len(tstruct['idx']) > 0: 171 | for idx in tstruct['idx'].keys(): 172 | for idxinfo in tstruct['idx'][idx]['composed_of']: 173 | f.write('\t\t{0}:{1} -> {0}:{2} [label="{3:d}" style=solid color=steelblue arrowhead=normal arrowtail=diamond dir=both arrowsize=0.6];\n'.format(tname, idx, idxinfo['name'], idxinfo['seqno'])) 174 | 175 | for fk in tstruct['fk']: 176 | f.write('\t\t{0}:{1} -> {2}:{3} [arrowtype=open style=solid color=red];\n'.format(tname, fk['from'], fk['table'], fk['to'])) 177 | 178 | #f.write('\t}\n') 179 | 180 | f.write('}\n') 181 | f.close() 182 | 183 | return gviz_filename 184 | 185 | def generate_png(dot_filename=None): 186 | """ 187 | $ dot -T png -o netpredictions.png firefox_fc/netpredictions.dot 188 | """ 189 | if dot_filename is not None: 190 | png_filename = '{0}.png'.format(os.path.splitext(dot_filename)[0]) 191 | 192 | os.system('dot -Tpng -o {0} {1}'.format(png_filename, dot_filename)) 193 | 194 | if __name__ == '__main__': 195 | if len(sys.argv) < 2: 196 | sys.exit('Usage: {0} fullpath-to-database-file-to-analyse'.format(sys.argv[0])) 197 | 198 | db_filename = sys.argv[1] 199 | 200 | if not os.path.isfile(db_filename): 201 | sys.exit('ERROR: database file {0} was not found !'.format(db_filename)) 202 | 203 | # No error in sqlite3.connect() or conn.cursor() if the 204 | # file is not an sqlite file 205 | # There is just a DatabaseError exception when a query is made :/ 206 | valid_db = True 207 | conn = sqlite3.connect(db_filename) 208 | 209 | # To get a dictionary with column names when executing queries 210 | # https://docs.python.org/2/library/sqlite3.html#connection-objects 211 | conn.row_factory = dict_factory 212 | 213 | c = conn.cursor() 214 | 215 | try: 216 | c.execute('select name from sqlite_master') 217 | except sqlite3.DatabaseError: 218 | valid_db = False 219 | 220 | if valid_db: 221 | db_struct = {} 222 | tables = sqlite_db_tables(c) 223 | 224 | for t in tables: 225 | db_struct[t] = {} 226 | 227 | cols = sqlite_table_columns(c, t) 228 | db_struct[t]['columns'] = cols 229 | 230 | fk = sqlite_table_foreign_keys(c, t) 231 | db_struct[t]['fk'] = fk 232 | 233 | idx = sqlite_table_indexes(c, t) 234 | db_struct[t]['idx'] = idx 235 | 236 | dot_file = write_graphiz_graph(db_struct, db_filename) 237 | 238 | generate_png(dot_file) 239 | 240 | conn.close() 241 | 242 | print('End of analyze') 243 | --------------------------------------------------------------------------------