|
| 1 | +#!/usr/bin/env python |
| 2 | +# -*- coding: utf-8 -*- |
| 3 | + |
| 4 | +import logging |
| 5 | +import MySQLdb |
| 6 | + |
| 7 | +class TableBuilder(object): |
| 8 | + |
| 9 | + connection = None |
| 10 | + cursor = None |
| 11 | + |
| 12 | + def template(self, host, user, password=None, db=None, tables=None): |
| 13 | + # sanity check |
| 14 | + if db is None and tables is None: |
| 15 | + return None |
| 16 | + |
| 17 | + # MySQL connections |
| 18 | + self.connection = MySQLdb.connect( |
| 19 | + host=host, |
| 20 | + user=user, |
| 21 | + passwd=password, |
| 22 | + db=db, |
| 23 | + ) |
| 24 | + self.cursor = self.connection.cursor() |
| 25 | + |
| 26 | + # in case to tables specified - list all tables of the DB specified |
| 27 | + if db is not None and tables is None: |
| 28 | + self.cursor.execute("USE " + db) |
| 29 | + tables = [] |
| 30 | + self.cursor.execute("SHOW TABLES") # execute 'SHOW TABLES' (but data is not returned) |
| 31 | + for (table_name,) in self.cursor: |
| 32 | + tables.append(table_name) |
| 33 | + |
| 34 | + # tables can be something like 'db1, db2, db3' |
| 35 | + # make [db1, db2, db3] |
| 36 | + if isinstance(tables, str): |
| 37 | + tables = [table.strip() for table in tables.split(',')] |
| 38 | + |
| 39 | + for table in tables: |
| 40 | + print(self.table(table, db)) |
| 41 | + |
| 42 | + def table(self, table_name, db=None): |
| 43 | + |
| 44 | + # `db`.`table` or just `table` |
| 45 | + name = '`{0}`.`{1}`'.format(db, table_name) if db else '`{0}`'.format(table_name) |
| 46 | + |
| 47 | + # list of ready-to-sql CH columns |
| 48 | + ch_columns = [] |
| 49 | + |
| 50 | + # issue 'DESCRIBE table' statement |
| 51 | + self.cursor.execute("DESC {0}".format(name)) |
| 52 | + for (_field, _type, _null, _key, _default, _extra,) in self.cursor: |
| 53 | + # Field | Type | Null | Key | Default | Extra |
| 54 | + |
| 55 | + # build ready-to-sql column specification |
| 56 | + # `integer_1` Nullable(Int32) |
| 57 | + # `u_integer_1` Nullable(UInt32) |
| 58 | + ch_columns.append('`{0}` {1}'.format(_field, self.map(mysql_type=_type, null=_null,))) |
| 59 | + |
| 60 | + sql = """ |
| 61 | +CREATE TABLE {0} ( |
| 62 | + {1} |
| 63 | +) ENGINE = MergeTree(_SPECIFY_DateField_HERE, (SPECIFY_INDEX_FIELD1, SPECIFY_INDEX_FIELD2, ...etc...), 8192) |
| 64 | +""".format( |
| 65 | + name, |
| 66 | + ",\n ".join(ch_columns) |
| 67 | + ) |
| 68 | + return sql |
| 69 | + |
| 70 | + def map(self, mysql_type, null=False): |
| 71 | + mysql_type = mysql_type.upper() |
| 72 | + |
| 73 | + # Numeric Types |
| 74 | + if mysql_type.startswith('BIT'): |
| 75 | + ch_type = 'String' |
| 76 | + elif mysql_type.startswith('TINYINT'): |
| 77 | + ch_type = 'UInt8' if mysql_type.endswith('UNSIGNED') else 'Int8' |
| 78 | + elif mysql_type.startswith('BOOL') or mysql_type.startswith('BOOLEAN'): |
| 79 | + ch_type = 'UInt8' |
| 80 | + elif mysql_type.startswith('SMALLINT'): |
| 81 | + ch_type = 'UInt16' if mysql_type.endswith('UNSIGNED') else 'Int16' |
| 82 | + elif mysql_type.startswith('MEDIUMINT'): |
| 83 | + ch_type = 'UInt32' if mysql_type.endswith('UNSIGNED') else 'Int32' |
| 84 | + elif mysql_type.startswith('INT') or mysql_type.startswith('INTEGER'): |
| 85 | + ch_type = 'UInt32' if mysql_type.endswith('UNSIGNED') else 'Int32' |
| 86 | + elif mysql_type.startswith('BIGINT'): |
| 87 | + ch_type = 'UInt64' if mysql_type.endswith('UNSIGNED') else 'Int64' |
| 88 | + elif mysql_type.startswith('SERIAL'): |
| 89 | + ch_type = 'UInt64' |
| 90 | + elif mysql_type.startswith('DEC') or mysql_type.startswith('DECIMAL') or mysql_type.startswith('FIXED') or mysql_type.startswith('NUMERIC'): |
| 91 | + ch_type = 'String' |
| 92 | + elif mysql_type.startswith('FLOAT'): |
| 93 | + ch_type = 'Float32' |
| 94 | + elif mysql_type.startswith('DOUBLE') or mysql_type.startswith('REAL'): |
| 95 | + ch_type = 'Float64' |
| 96 | + |
| 97 | + # Date and Time Types |
| 98 | + elif mysql_type.startswith('DATE'): |
| 99 | + ch_type = 'Date' |
| 100 | + elif mysql_type.startswith('DATETIME'): |
| 101 | + ch_type = 'DateTime' |
| 102 | + elif mysql_type.startswith('TIMESTAMP'): |
| 103 | + ch_type = 'DateTime' |
| 104 | + elif mysql_type.startswith('TIME'): |
| 105 | + ch_type = 'String' |
| 106 | + elif mysql_type.startswith('YEAR'): |
| 107 | + ch_type = 'UInt16' |
| 108 | + |
| 109 | + # String Types |
| 110 | + elif mysql_type.startswith('CHAR'): |
| 111 | + ch_type = 'String' |
| 112 | + elif mysql_type.startswith('VARCHAR'): |
| 113 | + ch_type = 'String' |
| 114 | + elif mysql_type.startswith('BINARY'): |
| 115 | + ch_type = 'String' |
| 116 | + elif mysql_type.startswith('VARBINARY'): |
| 117 | + ch_type = 'String' |
| 118 | + elif mysql_type.startswith('TINYBLOB'): |
| 119 | + ch_type = 'String' |
| 120 | + elif mysql_type.startswith('TINYTEXT'): |
| 121 | + ch_type = 'String' |
| 122 | + elif mysql_type.startswith('BLOB'): |
| 123 | + ch_type = 'String' |
| 124 | + elif mysql_type.startswith('TEXT'): |
| 125 | + ch_type = 'String' |
| 126 | + elif mysql_type.startswith('MEDIUMBLOB'): |
| 127 | + ch_type = 'String' |
| 128 | + elif mysql_type.startswith('MEDIUMTEXT'): |
| 129 | + ch_type = 'String' |
| 130 | + elif mysql_type.startswith('LONGBLOB'): |
| 131 | + ch_type = 'String' |
| 132 | + elif mysql_type.startswith('LONGTEXT'): |
| 133 | + ch_type = 'String' |
| 134 | + |
| 135 | + # Set Types |
| 136 | + elif mysql_type.startswith('ENUM'): |
| 137 | + ch_type = 'Enum16' |
| 138 | + elif mysql_type.startswith('SET'): |
| 139 | + ch_type = 'Array(Int8)' |
| 140 | + |
| 141 | + # Custom Types |
| 142 | + elif mysql_type.startswith('JSON'): |
| 143 | + ch_type = 'String' |
| 144 | + |
| 145 | + else: |
| 146 | + ch_type = 'UNKNOWN' |
| 147 | + |
| 148 | + # Deal with NULLs |
| 149 | + if isinstance(null, bool): |
| 150 | + if null: |
| 151 | + ch_type = 'Nullable(' + ch_type + ')' |
| 152 | + elif isinstance(null, str): |
| 153 | + if null.upper() == "YES": |
| 154 | + ch_type = 'Nullable(' + ch_type + ')' |
| 155 | + |
| 156 | + return ch_type |
| 157 | + |
| 158 | +if __name__ == '__main__': |
| 159 | + tb = TableBuilder() |
| 160 | + tb.template( |
| 161 | + host='127.0.0.1', |
| 162 | + user='reader', |
| 163 | + password='qwerty', |
| 164 | + db='db', |
| 165 | +# tables='datatypes, enum_datatypes, json_datatypes', |
| 166 | + tables=['datatypes', 'enum_datatypes', 'json_datatypes'], |
| 167 | + ) |
0 commit comments