Skip to content

Commit

Permalink
Merge pull request #17 from onaio/fuad_utils
Browse files Browse the repository at this point in the history
modified translate macro to accomodate edge case
  • Loading branch information
Ahmad-Fuad authored Aug 24, 2023
2 parents 2ba0e76 + 94b4828 commit 6469b8e
Showing 1 changed file with 59 additions and 38 deletions.
97 changes: 59 additions & 38 deletions macros/generate_translated_table.sql
Original file line number Diff line number Diff line change
@@ -1,43 +1,64 @@
{#-- Macro to generate a translated table from the submissions and choices table pushed by Airbyte Ona Data connector and remove group names recursively with column exclusion parameter --#}
{#-- Optional parameters and their defaults: default value of labelstable = "chc__" ~ rawtable[5:], default value of language = "English (en)", exclude_column = [] --#}
{#-- Example of minimum usage in a model, this utilizes defaults specified above: {{ generate_translated_table('airbyte', 'sbm__table_name'}} --#}
{#-- Example of usage in a model with specified language: {{ generate_translated_table('airbyte', 'sbm__table_name', language='French (fr)' }} --#}
{#-- Optional parameters and their defaults: default value of labelstable = "chc" ~ rawtable[3:], default value of language = "English (en)", exclude_column = [] --#}
{#-- Example of minimum usage in a model, this utilizes defaults specified above: {{ generate_translated_table('airbyte', 'sbm_table_name'}} --#}
{#-- Example of usage in a model with specified language: {{ generate_translated_table('airbyte', 'sbm_table_name', language='French (fr)' }} --#}

{% macro generate_translated_table(source_name, rawtable, labelstable=None, language=None, exclude_columns=[]) %}

{%- set labelstable = "chc__" ~ rawtable[5:] if labelstable is none else labelstable -%}
{%- set language = "English (en)" if language is none else language -%}
{%- set fieldlist = dbt_utils.get_filtered_columns_in_relation(from=source(source_name, rawtable)) -%}
{%- set optionslist = dbt_utils.get_column_values(table=source(source_name, labelstable), column='field') |list %}

select
{% for field in fieldlist %}
{%- if field in optionslist -%}
t{{optionslist.index(field)}}.label as
{% if field not in exclude_columns and '/' in field %}
"{{ field[field.rfind('/')+1:] }}"
{% else %}
"{{ field }}"
{% endif %}
{%- else -%}
r."{{field}}" as
{% if field not in exclude_columns and '/' in field %}
"{{ field[field.rfind('/')+1:] }}"
{% else %}
"{{ field }}"
{% endif %}
{%- endif %}
{%- if not loop.last -%}
,
{%- endif %}
{% endfor %}

from {{ source(source_name, rawtable) }} as r

{% for option in optionslist -%}
{% if option in fieldlist %}
left join {{ source(source_name, labelstable) }} as t{{ optionslist.index(option) }} on t{{ optionslist.index(option) }}.field = '{{ option }}'
and r."{{ option }}"::varchar = t{{ optionslist.index(option) }}.value and t{{ optionslist.index(option) }}.language = '{{ language }}'
{% endif %}
{% endfor %}
{# Set default values for labelstable and language if not provided #}
{%- set labelstable = "chc" ~ rawtable[3:] if labelstable is none else labelstable -%}
{%- set language = "English (en)" if language is none else language -%}

{# Retrieve a list of column names from the source table #}
{% set colnames = dbt_utils.get_filtered_columns_in_relation(from=source(source_name, rawtable)) %}

{# Initialize an empty list to store transformed field names #}
{% set fieldlist = [] %}

{# Iterate through each column name and process field names #}
{% for column in colnames %}
{% set fieldname = column %}
{% if column not in exclude_columns and '/' in column %}
{% set fieldname = fieldname[fieldname.rfind('/')+1:] %}
{% endif %}
{% do fieldlist.append(fieldname) %}
{% endfor %}

{# Create a mapping of modified field names to their original column names #}
{% set fieldname_mapping = {} %}
{% for column in colnames %}
{% set fieldname = column %}
{% if column not in exclude_columns and '/' in column %}
{% set fieldname = fieldname[fieldname.rfind('/')+1:] %}
{% endif %}
{% do fieldname_mapping.update({fieldname: column}) %}
{% endfor %}

{# Retrieve a list of values for the "field" column from the labelstable #}
{%- set optionslist = dbt_utils.get_column_values(table=source(source_name, labelstable), column='field') |list %}

{# Generate the SELECT clause using fieldlist and optionslist #}
select
{% for field in fieldlist %}
{%- if field in optionslist -%}
t{{optionslist.index(field)}}.label as "{{ field }}"
{%- else -%}
r."{{ fieldname_mapping[field] }}" as "{{ field }}"
{%- endif %}
{%- if not loop.last -%}
,
{%- endif %}
{% endfor %}

{# Generate the main query using rawtable, labelstable, language, and join conditions #}
from {{ source(source_name, rawtable) }} as r

{# Generate left join conditions for translated labels #}
{% for option in optionslist -%}
{% if option in fieldlist %}
left join {{ source(source_name, labelstable) }} as t{{ optionslist.index(option) }} on t{{ optionslist.index(option) }}.field = '{{ option }}'
and r."{{ fieldname_mapping[option] }}"::varchar = t{{ optionslist.index(option) }}.value and t{{ optionslist.index(option) }}.language = '{{ language }}'
{% endif %}
{% endfor %}

{% endmacro %}

0 comments on commit 6469b8e

Please sign in to comment.