|
| 1 | +{% macro sqlserver__get_catalog(information_schemas, schemas) -%} |
| 2 | + {% set query_label = apply_label() %} |
| 3 | + {%- call statement('catalog', fetch_result=True) -%} |
| 4 | + |
| 5 | + with |
| 6 | + principals as ( |
| 7 | + select |
| 8 | + name as principal_name, |
| 9 | + principal_id as principal_id |
| 10 | + from |
| 11 | + sys.database_principals {{ information_schema_hints() }} |
| 12 | + ), |
| 13 | + |
| 14 | + schemas as ( |
| 15 | + select |
| 16 | + name as schema_name, |
| 17 | + schema_id as schema_id, |
| 18 | + principal_id as principal_id |
| 19 | + from |
| 20 | + sys.schemas {{ information_schema_hints() }} |
| 21 | + ), |
| 22 | + |
| 23 | + tables as ( |
| 24 | + select |
| 25 | + object_id, |
| 26 | + name as table_name, |
| 27 | + schema_id as schema_id, |
| 28 | + principal_id as principal_id, |
| 29 | + 'BASE TABLE' as table_type |
| 30 | + from |
| 31 | + sys.tables {{ information_schema_hints() }} |
| 32 | + ), |
| 33 | + |
| 34 | + tables_with_metadata as ( |
| 35 | + select |
| 36 | + object_id, |
| 37 | + table_name, |
| 38 | + schema_name, |
| 39 | + coalesce(tables.principal_id, schemas.principal_id) as owner_principal_id, |
| 40 | + table_type |
| 41 | + from |
| 42 | + tables |
| 43 | + join schemas on tables.schema_id = schemas.schema_id |
| 44 | + ), |
| 45 | + |
| 46 | + views as ( |
| 47 | + select |
| 48 | + object_id, |
| 49 | + name as table_name, |
| 50 | + schema_id as schema_id, |
| 51 | + principal_id as principal_id, |
| 52 | + 'VIEW' as table_type |
| 53 | + from |
| 54 | + sys.views {{ information_schema_hints() }} |
| 55 | + ), |
| 56 | + |
| 57 | + views_with_metadata as ( |
| 58 | + select |
| 59 | + object_id, |
| 60 | + table_name, |
| 61 | + schema_name, |
| 62 | + coalesce(views.principal_id, schemas.principal_id) as owner_principal_id, |
| 63 | + table_type |
| 64 | + from |
| 65 | + views |
| 66 | + join schemas on views.schema_id = schemas.schema_id |
| 67 | + ), |
| 68 | + |
| 69 | + tables_and_views as ( |
| 70 | + select |
| 71 | + object_id, |
| 72 | + table_name, |
| 73 | + schema_name, |
| 74 | + principal_name, |
| 75 | + table_type |
| 76 | + from |
| 77 | + tables_with_metadata |
| 78 | + join principals on tables_with_metadata.owner_principal_id = principals.principal_id |
| 79 | + union all |
| 80 | + select |
| 81 | + object_id, |
| 82 | + table_name, |
| 83 | + schema_name, |
| 84 | + principal_name, |
| 85 | + table_type |
| 86 | + from |
| 87 | + views_with_metadata |
| 88 | + join principals on views_with_metadata.owner_principal_id = principals.principal_id |
| 89 | + ), |
| 90 | + |
| 91 | + cols as ( |
| 92 | + |
| 93 | + select |
| 94 | + c.object_id, |
| 95 | + c.name as column_name, |
| 96 | + c.column_id as column_index, |
| 97 | + t.name as column_type |
| 98 | + from sys.columns as c {{ information_schema_hints() }} |
| 99 | + left join sys.types {{ information_schema_hints() }} as t on c.system_type_id = t.system_type_id |
| 100 | + ) |
| 101 | + |
| 102 | + select |
| 103 | + DB_NAME() as table_database, |
| 104 | + tv.schema_name as table_schema, |
| 105 | + tv.table_name, |
| 106 | + tv.table_type, |
| 107 | + null as table_comment, |
| 108 | + tv.principal_name as table_owner, |
| 109 | + cols.column_name, |
| 110 | + cols.column_index, |
| 111 | + cols.column_type, |
| 112 | + null as column_comment |
| 113 | + from tables_and_views tv |
| 114 | + join cols on tv.object_id = cols.object_id |
| 115 | + where ({%- for schema in schemas -%} |
| 116 | + upper(tv.schema_name) = upper('{{ schema }}'){%- if not loop.last %} or {% endif -%} |
| 117 | + {%- endfor -%}) |
| 118 | + |
| 119 | + order by column_index |
| 120 | + {{ query_label }} |
| 121 | + |
| 122 | + {%- endcall -%} |
| 123 | + |
| 124 | + {{ return(load_result('catalog').table) }} |
| 125 | + |
| 126 | +{%- endmacro %} |
| 127 | + |
| 128 | +{% macro sqlserver__get_catalog_relations(information_schema, relations) -%} |
| 129 | + {% set query_label = apply_label() %} |
| 130 | + {%- call statement('catalog', fetch_result=True) -%} |
| 131 | + |
| 132 | + with |
| 133 | + principals as ( |
| 134 | + select |
| 135 | + name as principal_name, |
| 136 | + principal_id as principal_id |
| 137 | + from |
| 138 | + sys.database_principals {{ information_schema_hints() }} |
| 139 | + ), |
| 140 | + |
| 141 | + schemas as ( |
| 142 | + select |
| 143 | + name as schema_name, |
| 144 | + schema_id as schema_id, |
| 145 | + principal_id as principal_id |
| 146 | + from |
| 147 | + sys.schemas {{ information_schema_hints() }} |
| 148 | + ), |
| 149 | + |
| 150 | + tables as ( |
| 151 | + select |
| 152 | + object_id, |
| 153 | + name as table_name, |
| 154 | + schema_id as schema_id, |
| 155 | + principal_id as principal_id, |
| 156 | + 'BASE TABLE' as table_type |
| 157 | + from |
| 158 | + sys.tables {{ information_schema_hints() }} |
| 159 | + ), |
| 160 | + |
| 161 | + tables_with_metadata as ( |
| 162 | + select |
| 163 | + object_id, |
| 164 | + table_name, |
| 165 | + schema_name, |
| 166 | + coalesce(tables.principal_id, schemas.principal_id) as owner_principal_id, |
| 167 | + table_type |
| 168 | + from |
| 169 | + tables |
| 170 | + join schemas on tables.schema_id = schemas.schema_id |
| 171 | + ), |
| 172 | + |
| 173 | + views as ( |
| 174 | + select |
| 175 | + object_id, |
| 176 | + name as table_name, |
| 177 | + schema_id as schema_id, |
| 178 | + principal_id as principal_id, |
| 179 | + 'VIEW' as table_type |
| 180 | + from |
| 181 | + sys.views {{ information_schema_hints() }} |
| 182 | + ), |
| 183 | + |
| 184 | + views_with_metadata as ( |
| 185 | + select |
| 186 | + object_id, |
| 187 | + table_name, |
| 188 | + schema_name, |
| 189 | + coalesce(views.principal_id, schemas.principal_id) as owner_principal_id, |
| 190 | + table_type |
| 191 | + from |
| 192 | + views |
| 193 | + join schemas on views.schema_id = schemas.schema_id |
| 194 | + ), |
| 195 | + |
| 196 | + tables_and_views as ( |
| 197 | + select |
| 198 | + object_id, |
| 199 | + table_name, |
| 200 | + schema_name, |
| 201 | + principal_name, |
| 202 | + table_type |
| 203 | + from |
| 204 | + tables_with_metadata |
| 205 | + join principals on tables_with_metadata.owner_principal_id = principals.principal_id |
| 206 | + union all |
| 207 | + select |
| 208 | + object_id, |
| 209 | + table_name, |
| 210 | + schema_name, |
| 211 | + principal_name, |
| 212 | + table_type |
| 213 | + from |
| 214 | + views_with_metadata |
| 215 | + join principals on views_with_metadata.owner_principal_id = principals.principal_id |
| 216 | + ), |
| 217 | + |
| 218 | + cols as ( |
| 219 | + |
| 220 | + select |
| 221 | + c.object_id, |
| 222 | + c.name as column_name, |
| 223 | + c.column_id as column_index, |
| 224 | + t.name as column_type |
| 225 | + from sys.columns as c {{ information_schema_hints() }} |
| 226 | + left join sys.types as t on c.system_type_id = t.system_type_id |
| 227 | + ) |
| 228 | + |
| 229 | + select |
| 230 | + DB_NAME() as table_database, |
| 231 | + tv.schema_name as table_schema, |
| 232 | + tv.table_name, |
| 233 | + tv.table_type, |
| 234 | + null as table_comment, |
| 235 | + tv.principal_name as table_owner, |
| 236 | + cols.column_name, |
| 237 | + cols.column_index, |
| 238 | + cols.column_type, |
| 239 | + null as column_comment |
| 240 | + from tables_and_views tv |
| 241 | + join cols on tv.object_id = cols.object_id |
| 242 | + where ( |
| 243 | + {%- for relation in relations -%} |
| 244 | + {% if relation.schema and relation.identifier %} |
| 245 | + ( |
| 246 | + upper(tv.schema_name) = upper('{{ relation.schema }}') |
| 247 | + and upper(tv.table_name) = upper('{{ relation.identifier }}') |
| 248 | + ) |
| 249 | + {% elif relation.schema %} |
| 250 | + ( |
| 251 | + upper(tv.schema_name) = upper('{{ relation.schema }}') |
| 252 | + ) |
| 253 | + {% else %} |
| 254 | + {% do exceptions.raise_compiler_error( |
| 255 | + '`get_catalog_relations` requires a list of relations, each with a schema' |
| 256 | + ) %} |
| 257 | + {% endif %} |
| 258 | + |
| 259 | + {%- if not loop.last %} or {% endif -%} |
| 260 | + {%- endfor -%} |
| 261 | + ) |
| 262 | + |
| 263 | + order by column_index |
| 264 | + {{ query_label }} |
| 265 | + {%- endcall -%} |
| 266 | + |
| 267 | + {{ return(load_result('catalog').table) }} |
| 268 | + |
| 269 | +{%- endmacro %} |
0 commit comments