|
| 1 | +from contextlib import closing |
| 2 | + |
| 3 | +import ibis |
| 4 | + |
| 5 | +from app.model import SnowflakeConnectionInfo |
| 6 | +from app.model.data_source import DataSource |
| 7 | +from app.model.metadata.dto import ( |
| 8 | + Column, |
| 9 | + Constraint, |
| 10 | + ConstraintType, |
| 11 | + Table, |
| 12 | + TableProperties, |
| 13 | + WrenEngineColumnType, |
| 14 | +) |
| 15 | +from app.model.metadata.metadata import Metadata |
| 16 | + |
| 17 | + |
| 18 | +class SnowflakeMetadata(Metadata): |
| 19 | + def __init__(self, connection_info: SnowflakeConnectionInfo): |
| 20 | + super().__init__(connection_info) |
| 21 | + self.connection = DataSource.snowflake.get_connection(connection_info) |
| 22 | + |
| 23 | + def get_table_list(self) -> list[Table]: |
| 24 | + schema = self._get_schema_name() |
| 25 | + sql = f""" |
| 26 | + SELECT |
| 27 | + c.TABLE_CATALOG AS TABLE_CATALOG, |
| 28 | + c.TABLE_SCHEMA AS TABLE_SCHEMA, |
| 29 | + c.TABLE_NAME AS TABLE_NAME, |
| 30 | + c.COLUMN_NAME AS COLUMN_NAME, |
| 31 | + c.DATA_TYPE AS DATA_TYPE, |
| 32 | + c.IS_NULLABLE AS IS_NULLABLE, |
| 33 | + c.COMMENT AS COLUMN_COMMENT, |
| 34 | + t.COMMENT AS TABLE_COMMENT |
| 35 | + FROM |
| 36 | + INFORMATION_SCHEMA.COLUMNS c |
| 37 | + JOIN |
| 38 | + INFORMATION_SCHEMA.TABLES t |
| 39 | + ON c.TABLE_SCHEMA = t.TABLE_SCHEMA |
| 40 | + AND c.TABLE_NAME = t.TABLE_NAME |
| 41 | + WHERE |
| 42 | + c.TABLE_SCHEMA = '{schema}'; |
| 43 | + """ |
| 44 | + response = self.connection.sql(sql).to_pandas().to_dict(orient="records") |
| 45 | + |
| 46 | + unique_tables = {} |
| 47 | + for row in response: |
| 48 | + # generate unique table name |
| 49 | + schema_table = self._format_compact_table_name( |
| 50 | + row["TABLE_SCHEMA"], row["TABLE_NAME"] |
| 51 | + ) |
| 52 | + # init table if not exists |
| 53 | + if schema_table not in unique_tables: |
| 54 | + unique_tables[schema_table] = Table( |
| 55 | + name=schema_table, |
| 56 | + description=row["TABLE_COMMENT"], |
| 57 | + columns=[], |
| 58 | + properties=TableProperties( |
| 59 | + schema=row["TABLE_SCHEMA"], |
| 60 | + catalog=row["TABLE_CATALOG"], |
| 61 | + table=row["TABLE_NAME"], |
| 62 | + ), |
| 63 | + primaryKey="", |
| 64 | + ) |
| 65 | + |
| 66 | + # table exists, and add column to the table |
| 67 | + unique_tables[schema_table].columns.append( |
| 68 | + Column( |
| 69 | + name=row["COLUMN_NAME"], |
| 70 | + type=self._transform_column_type(row["DATA_TYPE"]), |
| 71 | + notNull=row["IS_NULLABLE"].lower() == "no", |
| 72 | + description=row["COLUMN_COMMENT"], |
| 73 | + properties=None, |
| 74 | + ) |
| 75 | + ) |
| 76 | + return list(unique_tables.values()) |
| 77 | + |
| 78 | + def get_constraints(self) -> list[Constraint]: |
| 79 | + database = self._get_database_name() |
| 80 | + schema = self._get_schema_name() |
| 81 | + sql = f""" |
| 82 | + SHOW IMPORTED KEYS IN SCHEMA {database}.{schema}; |
| 83 | + """ |
| 84 | + with closing(self.connection.raw_sql(sql)) as cur: |
| 85 | + fields = [field[0] for field in cur.description] |
| 86 | + result = [dict(zip(fields, row)) for row in cur.fetchall()] |
| 87 | + res = ( |
| 88 | + ibis.memtable(result).to_pandas().to_dict(orient="records") |
| 89 | + if len(result) > 0 |
| 90 | + else [] |
| 91 | + ) |
| 92 | + constraints = [] |
| 93 | + for row in res: |
| 94 | + constraints.append( |
| 95 | + Constraint( |
| 96 | + constraintName=self._format_constraint_name( |
| 97 | + row["pk_table_name"], |
| 98 | + row["pk_column_name"], |
| 99 | + row["fk_table_name"], |
| 100 | + row["fk_column_name"], |
| 101 | + ), |
| 102 | + constraintTable=self._format_compact_table_name( |
| 103 | + row["pk_schema_name"], row["pk_table_name"] |
| 104 | + ), |
| 105 | + constraintColumn=row["pk_column_name"], |
| 106 | + constraintedTable=self._format_compact_table_name( |
| 107 | + row["fk_schema_name"], row["fk_table_name"] |
| 108 | + ), |
| 109 | + constraintedColumn=row["fk_column_name"], |
| 110 | + constraintType=ConstraintType.FOREIGN_KEY, |
| 111 | + ) |
| 112 | + ) |
| 113 | + return constraints |
| 114 | + |
| 115 | + def get_version(self) -> str: |
| 116 | + return self.connection.sql("SELECT CURRENT_VERSION()").to_pandas().iloc[0, 0] |
| 117 | + |
| 118 | + def _get_database_name(self): |
| 119 | + return self.connection_info.database.get_secret_value() |
| 120 | + |
| 121 | + def _get_schema_name(self): |
| 122 | + return self.connection_info.sf_schema.get_secret_value() |
| 123 | + |
| 124 | + def _format_compact_table_name(self, schema: str, table: str): |
| 125 | + return f"{schema}.{table}" |
| 126 | + |
| 127 | + def _format_constraint_name( |
| 128 | + self, table_name, column_name, referenced_table_name, referenced_column_name |
| 129 | + ): |
| 130 | + return f"{table_name}_{column_name}_{referenced_table_name}_{referenced_column_name}" |
| 131 | + |
| 132 | + def _transform_column_type(self, data_type): |
| 133 | + # all possible types listed here: https://docs.snowflake.com/en/sql-reference/intro-summary-data-types |
| 134 | + switcher = { |
| 135 | + # Numeric Types |
| 136 | + "number": WrenEngineColumnType.NUMERIC, |
| 137 | + "decimal": WrenEngineColumnType.NUMERIC, |
| 138 | + "numeric": WrenEngineColumnType.NUMERIC, |
| 139 | + "int": WrenEngineColumnType.INTEGER, |
| 140 | + "integer": WrenEngineColumnType.INTEGER, |
| 141 | + "bigint": WrenEngineColumnType.BIGINT, |
| 142 | + "smallint": WrenEngineColumnType.SMALLINT, |
| 143 | + "tinyint": WrenEngineColumnType.TINYINT, |
| 144 | + "byteint": WrenEngineColumnType.TINYINT, |
| 145 | + # Float |
| 146 | + "float4": WrenEngineColumnType.FLOAT4, |
| 147 | + "float": WrenEngineColumnType.FLOAT8, |
| 148 | + "float8": WrenEngineColumnType.FLOAT8, |
| 149 | + "double": WrenEngineColumnType.DOUBLE, |
| 150 | + "double precision": WrenEngineColumnType.DOUBLE, |
| 151 | + "real": WrenEngineColumnType.REAL, |
| 152 | + # String Types |
| 153 | + "varchar": WrenEngineColumnType.VARCHAR, |
| 154 | + "char": WrenEngineColumnType.CHAR, |
| 155 | + "character": WrenEngineColumnType.CHAR, |
| 156 | + "string": WrenEngineColumnType.STRING, |
| 157 | + "text": WrenEngineColumnType.TEXT, |
| 158 | + # Boolean |
| 159 | + "boolean": WrenEngineColumnType.BOOLEAN, |
| 160 | + # Date and Time Types |
| 161 | + "date": WrenEngineColumnType.DATE, |
| 162 | + "datetime": WrenEngineColumnType.TIMESTAMP, |
| 163 | + "timestamp": WrenEngineColumnType.TIMESTAMP, |
| 164 | + "timestamp_ntz": WrenEngineColumnType.TIMESTAMP, |
| 165 | + "timestamp_tz": WrenEngineColumnType.TIMESTAMPTZ, |
| 166 | + } |
| 167 | + |
| 168 | + return switcher.get(data_type.lower(), WrenEngineColumnType.UNKNOWN) |
0 commit comments