diff --git a/connectors/source_recharge/README.md b/connectors/source_recharge/README.md index 9b4cd406..6f4f6d5d 100644 --- a/connectors/source_recharge/README.md +++ b/connectors/source_recharge/README.md @@ -1,9 +1,113 @@ -# Airbyte source_recharge dbt Package +# Recharge Airbyte dbt Package -This package contains dbt models for Airbyte source_recharge source. +--- -What it includes: +- This package contains dbt models to work with Airbyte Recharge connector. +- The package is compatible with latest version of Airbyte Recharge connector. +- Currently, it is limited to creating transformations compatible with [Fivetran's modeling dbt package](https://github.com/fivetran/dbt_recharge/tree/main). +- In the future, specific models will be applied directly to Airbyte connector output. If you have an idea or want to propose an analytical model for this source, please refer to the contributing guide, which explains how to propose a new transformation model. +- This package was tested with BigQuery, Snowflake, and Postgres data warehouses. -* A complete source description -* ERD model for the source -* Diagram documentation for the source +--- + +## 🎯 Intructions how to use + +### Airbyte dbt Package + +For now Airbyte dbt packages aren't versioned. You must configure using git and subdirectory. For now there isn't any transformation model directly applied to this package. But you can generate docs and tests with dbt. + +Create the following files: + +**`dbt_project.yml`** + +```yaml +vars: + using_fivetran_model: False + airbyte_database: "airbyte_db_default" + airbyte_schema: "airbyte_dbt_source_recharge" +``` + +**`packages.yml`** + +```yaml +packages: + - git: "https://github.com/airbytehq/airbyte-dbt-models.git" + subdirectory: "connectors/source_recharge" +``` + +After you can run `dbt tests` or `dbt docs generate` to have a preview of Airbyte output data. + +### Fivetran Recharge Modeling dbt package + +This package transforms Airbyte connector output data, making it compatible with Fivetran's Recharge dbt package. You can check the analytical models Fivetran creates [here](https://github.com/fivetran/dbt_recharge/tree/main?tab=readme-ov-file#-what-does-this-dbt-package-do). The link also provides information about how the package works and what is configurable. + +Create the require files to use Airbyte and Fivetran dbt packages: + +**`packages.yml`** + +```yaml +packages: + - git: "https://github.com/airbytehq/airbyte-dbt-models.git" + subdirectory: "connectors/source_recharge" + + - package: fivetran/recharge + version: [">=0.16.0", "<0.17.0"] +``` + +This is a default variable definition you must configure to have the models created. + +**`dbt_project.yml`** + +```yaml +vars: + # Required by Airbyte dbt model + using_fivetran_model: True + airbyte_database: "airbyte_db_default" + airbyte_schema: "airbyte_dbt_recharge" + + # Required by Fivetran dbt model + recharge_database: "airbyte_db_default" + recharge_schema: "airbyte_dbt_recharge" + + recharge__one_time_product_enabled: true # Disables if you do not have the ONE_TIME_PRODUCT table. Default is True. + recharge__charge_tax_line_enabled: true # Disables if you do not have the CHARGE_TAX_LINE table. Default is True. + recharge__checkout_enabled: false # Enables if you do have the CHECKOUT table. Default is False. + + recharge__standardized_billing_model_enabled: false # false by default. + + recharge__using_orders: true # default is true, which will use the `orders` version of the source. + + recharge_first_date: "yyyy-mm-dd" + recharge_last_date: "yyyy-mm-dd" + + recharge_address_identifier: "addresses" + recharge_address_discounts_identifier: "addresses" + recharge_address_shipping_line_identifier: "addresses" + recharge_charge_identifier: "charges" + recharge_charge_line_item_identifier: "charges" + recharge_charge_order_attribute_identifier: "charges" + recharge_charge_shipping_line_identifier: "charges" + recharge_charge_tax_line_identifier: "charges" + recharge_customer_identifier: "customers" + recharge_discount_identifier: "discounts" + recharge_one_time_product_identifier: "onetimes" + recharge_order_identifier: "orders" + recharge_order_line_item_identifier: "orders" + recharge_subscription_identifier: "subscriptions" + recharge_subscription_history_identifier: "subscriptions" +``` + +You need to run the models in steps: + +```shell +dbt run --model +source_recharge # create tables needed by Fivetran from Airbyte +dbt run --model +recharge_source # staging tables +dbt run --model +recharge # final analytical model. +``` + +--- + +## :package: Package Maintenance + +- This package is maintained by the Airbyte Community. +- You can contribute any time please read the Contributing Guidelines or enter the Airbyte Slack Channel `#airbyte-dbt-packages`. diff --git a/connectors/source_recharge/integration_tests/dbt_project.yml b/connectors/source_recharge/integration_tests/dbt_project.yml new file mode 100644 index 00000000..ace40df4 --- /dev/null +++ b/connectors/source_recharge/integration_tests/dbt_project.yml @@ -0,0 +1,48 @@ +name: integration_test_recharge + +config-version: 2 + +version: 0.1.0 + +profile: integration_tests + +model-paths: + - models + +macro-paths: + - macros + +target-path: target + +clean-targets: + - target + - dbt_modules + - logs + +require-dbt-version: + - ">=1.0.0" + - <2.0.0 + +models: + airbyte_dbt_source_recharge: + materialized: view + +schema: dbt_recharge + staging: + materialized: view + tmp: + materialized: view + +vars: + # Required by Airbyte dbt model + using_fivetran_model: True + airbyte_database: "airbyte_db_default" + airbyte_schema: "airbyte_dbt_source_recharge" + + # Required by Fivetran dbt model + recharge_database: "airbyte_db_default" + recharge_schema: "airbyte_dbt_source_recharge" + recharge_source: + order: "{{ ref('order_extended') }}" + orders: "{{ ref('order_extended') }}" + + recharge_first_date: "2021-01-01" diff --git a/connectors/source_recharge/integration_tests/package-lock.yml b/connectors/source_recharge/integration_tests/package-lock.yml new file mode 100644 index 00000000..21ae888d --- /dev/null +++ b/connectors/source_recharge/integration_tests/package-lock.yml @@ -0,0 +1,13 @@ +packages: + - local: ../ + - package: fivetran/recharge + version: 0.3.0 + - package: fivetran/recharge_source + version: 0.3.1 + - package: fivetran/fivetran_utils + version: 0.4.10 + - package: dbt-labs/spark_utils + version: 0.3.0 + - package: dbt-labs/dbt_utils + version: 1.2.0 +sha1_hash: 7e7cc8ea09f670fb388cbe069b5850d11625fe0f diff --git a/connectors/source_recharge/integration_tests/packages.yml b/connectors/source_recharge/integration_tests/packages.yml new file mode 100644 index 00000000..dc0d7afb --- /dev/null +++ b/connectors/source_recharge/integration_tests/packages.yml @@ -0,0 +1,5 @@ +packages: + - local: ../ + + - package: fivetran/recharge + version: ["0.3.0"] diff --git a/connectors/source_recharge/integration_tests/vars b/connectors/source_recharge/integration_tests/vars new file mode 100644 index 00000000..572abe60 --- /dev/null +++ b/connectors/source_recharge/integration_tests/vars @@ -0,0 +1 @@ +{airbyte_database: $AB_DB, zendesk_database: $AB_DB} \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/address.sql b/connectors/source_recharge/models/fivetran_converter/address.sql new file mode 100644 index 00000000..0363de54 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/address.sql @@ -0,0 +1,85 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as address_id, + customer_id, + first_name, + last_name, + cast(created_at as {{ dbt.type_timestamp() }}) as address_created_at, -- Snowflake: dbt.type_timestamp() should work as expected + cast(updated_at as {{ dbt.type_timestamp() }}) as address_updated_at, + address1 as address_line_1, + address2 as address_line_2, + city, + province, + zip, + country_code, + company, + phone + + FROM + {{ source('source_recharge', 'addresses') }} + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as address_id, + customer_id, + first_name, + last_name, + cast(created_at as {{ dbt.type_timestamp() }}) as address_created_at, -- BigQuery: dbt.type_timestamp() should work as expected + cast(updated_at as {{ dbt.type_timestamp() }}) as address_updated_at, + address1 as address_line_1, + address2 as address_line_2, + city, + province, + zip, + country_code, + company, + phone + + FROM + {{ source('source_recharge', 'addresses') }} + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as address_id, + customer_id, + first_name, + last_name, + cast(created_at as {{ dbt.type_timestamp() }}) as address_created_at, -- Postgres: dbt.type_timestamp() should work as expected + cast(updated_at as {{ dbt.type_timestamp() }}) as address_updated_at, + address1 as address_line_1, + address2 as address_line_2, + city, + province, + zip, + country_code, + company, + phone + + FROM + {{ source('source_recharge', 'addresses') }} + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/address.yml b/connectors/source_recharge/models/fivetran_converter/address.yml new file mode 100644 index 00000000..361b5e4f --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/address.yml @@ -0,0 +1,38 @@ +version: 2 + +models: + - name: address + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Address table aligned with the Fivetran dbt model." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: address_id + description: "address unique identifier" + - name: customer_id + description: "customer unique identifier" + - name: first_name + description: The customer's first name. + - name: last_name + description: The customer's last name. + - name: address_created_at + description: The date and time the customer address was recorded. + - name: address_updated_at + description: The date and time of when the customer's address record was last updated. + - name: address_line_1 + description: The first line of the customer's address. + - name: address_line_2 + description: Any additional address information associated with the customer. + - name: city + description: The city associated with the customer. + - name: province + description: The province or state name associated with the customer. + - name: zip + description: The zip or post code associated with the customer. + - name: country_code + description: The country code associated with the address. + - name: company + description: The company name associated with the customer. + - name: phone + description: The phone number associated with the customer. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/address_discounts.sql b/connectors/source_recharge/models/fivetran_converter/address_discounts.sql new file mode 100644 index 00000000..fabc61f0 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/address_discounts.sql @@ -0,0 +1,52 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + discount_id, + id as address_id, + NULL::integer as index -- Snowflake requires explicit type casting + + FROM + {{ source('source_recharge', 'addresses') }} + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + discount_id, + id as address_id, + NULL as index -- BigQuery syntax for a NULL value, implicitly typed + + FROM + {{ source('source_recharge', 'addresses') }} + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + discount_id, + id as address_id, + NULL::integer as index -- PostgreSQL requires explicit type casting for NULL + + FROM + {{ source('source_recharge', 'addresses') }} + +) + +select * +from tmp + +{% endif %} \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/address_discounts.yml b/connectors/source_recharge/models/fivetran_converter/address_discounts.yml new file mode 100644 index 00000000..09426129 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/address_discounts.yml @@ -0,0 +1,16 @@ +version: 2 + +models: + - name: address_discounts + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Address discounts aligned with the Fivetran dbt model." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: address_id + description: "Address unique identifier" + - name: index + description: A unique numeric row produced for every concurrent address_id. + - name: discount_id + description: "Discount unique identifier" diff --git a/connectors/source_recharge/models/fivetran_converter/address_shipping_line.sql b/connectors/source_recharge/models/fivetran_converter/address_shipping_line.sql new file mode 100644 index 00000000..e474732f --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/address_shipping_line.sql @@ -0,0 +1,58 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as address_id, + NULL::integer as index, -- Snowflake: NULL explicitly cast to integer + m.value:price::string as price, -- Snowflake: Use colon notation to extract JSON keys + m.value:code::string as code, -- Also ensure the correct data type with casting + m.value:title::string as title + FROM + {{ source('source_recharge', 'addresses') }}, + lateral flatten(input => ARRAY_CONSTRUCT(shipping_lines_override)) m -- Snowflake: Use LATERAL FLATTEN to unnest JSON array + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as address_id, + NULL as index, -- BigQuery: NULL without explicit type casting + JSON_VALUE(m, '$.price') as price, -- BigQuery: Extract JSON values with JSON_VALUE + JSON_VALUE(m, '$.code') as code, + JSON_VALUE(m, '$.title') as title + FROM + {{ source('source_recharge', 'addresses') }}, + UNNEST (JSON_QUERY_ARRAY(shipping_lines_override)) m -- BigQuery: Use UNNEST to expand JSON array + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as address_id, + NULL::integer as index, -- Postgres: NULL explicitly cast to integer + m.value ->> 'price' as price, -- Postgres: Use ->> operator to extract JSON key as text + m.value ->> 'code' as code, + m.value ->> 'title' as title + FROM + {{ source('source_recharge', 'addresses') }}, + jsonb_array_elements(shipping_lines_override::jsonb) as m(value) -- Postgres: Use jsonb_array_elements to expand JSON array + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/address_shipping_line.yml b/connectors/source_recharge/models/fivetran_converter/address_shipping_line.yml new file mode 100644 index 00000000..a42edbc0 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/address_shipping_line.yml @@ -0,0 +1,20 @@ +version: 2 + +models: + - name: address_shipping_line + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all addresses and corresponding associated shipping information." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: address_id + description: address unique identifier. + - name: index + description: A unique numeric row produced for every concurrent address_id, currently NULL. + - name: price + description: The price of the shipping amount. + - name: code + description: The type of the shipping, can contain geographical shipping information. + - name: title + description: The type of shipping consignment. diff --git a/connectors/source_recharge/models/fivetran_converter/charge.sql b/connectors/source_recharge/models/fivetran_converter/charge.sql new file mode 100644 index 00000000..cfcce08e --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge.sql @@ -0,0 +1,140 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id, + customer_id, + customer_hash, + email, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + type as charge_type, + status as charge_status, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + note, + subtotal_price, + tax_lines, + cast(total_discounts as {{ dbt.type_float() }}) as total_discounts, + total_line_items_price, + total_tax, + cast(total_price as {{ dbt.type_float() }}) as total_price, + cast(total_refunds as {{ dbt.type_float() }}) as total_refunds, + cast(total_weight_grams as {{ dbt.type_float() }}) as total_weight_grams, + cast(scheduled_at as {{ dbt.type_timestamp() }}) as scheduled_at, + cast(processed_at as {{ dbt.type_timestamp() }}) as processed_at, + payment_processor, + to_variant(external_transaction_id):payment_processor as external_transaction_id_payment_processor, + to_variant(external_order_id):ecommerce as external_order_id_ecommerce, + orders_count, + has_uncommitted_changes, + cast(retry_date as {{ dbt.type_timestamp() }}) as retry_date, + error_type, + charge_attempts as times_retried, + address_id, + to_variant(client_details):browser_ip as client_details_browser_ip, + to_variant(client_details):user_agent as client_details_user_agent, + tags, + error, + external_variant_id_not_found + from + {{ source('source_recharge', 'charges') }} +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + + select + id, + customer_id, + customer_hash, + email, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + type as charge_type, + status as charge_status, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + note, + cast(null as {{dbt.type_float()}}) as tax_lines, + cast(subtotal_price as {{ dbt.type_float() }}) as subtotal_price, + cast(total_discounts as {{ dbt.type_float() }}) as total_discounts, + cast(total_line_items_price as {{ dbt.type_float() }}) as total_line_items_price, + cast(total_tax as {{ dbt.type_float() }}) as total_tax, + cast(total_price as {{ dbt.type_float() }}) as total_price, + cast(total_refunds as {{ dbt.type_float() }}) as total_refunds, + cast(total_weight_grams as {{ dbt.type_float() }}) as total_weight_grams, + cast(scheduled_at as {{ dbt.type_timestamp() }}) as scheduled_at, + cast(processed_at as {{ dbt.type_timestamp() }}) as processed_at, + payment_processor, + JSON_VALUE(external_transaction_id, '$.payment_processor') as external_transaction_id_payment_processor, + JSON_VALUE(external_order_id, '$.ecommerce') as external_order_id_ecommerce, + orders_count, + has_uncommitted_changes, + cast(retry_date as {{ dbt.type_timestamp() }}) as retry_date, + error_type, + charge_attempts as times_retried, + address_id, + JSON_VALUE(client_details, '$.browser_ip')as client_details_browser_ip, + JSON_VALUE(client_details, '$.user_agent') as client_details_user_agent, + tags, + error, + external_variant_id_not_found + + FROM + {{ source('source_recharge', 'charges') }} + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id, + customer_id, + customer_hash, + email, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + type as charge_type, + status as charge_status, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + note, + cast(null as {{ dbt.type_float() }}) as tax_lines, + cast(subtotal_price as {{ dbt.type_float() }}) as subtotal_price, + cast(total_discounts as {{ dbt.type_float() }}) as total_discounts, + cast(total_line_items_price as {{ dbt.type_float() }}) as total_line_items_price, + cast(total_tax as {{ dbt.type_float() }}) as total_tax, + cast(total_price as {{ dbt.type_float() }}) as total_price, + cast(total_refunds as {{ dbt.type_float() }}) as total_refunds, + cast(total_weight_grams as {{ dbt.type_float() }}) as total_weight_grams, + cast(scheduled_at as {{ dbt.type_timestamp() }}) as scheduled_at, + cast(processed_at as {{ dbt.type_timestamp() }}) as processed_at, + payment_processor, + external_transaction_id->>'payment_processor' as external_transaction_id_payment_processor, + external_order_id->>'ecommerce' as external_order_id_ecommerce, + orders_count, + has_uncommitted_changes, + cast(retry_date as {{ dbt.type_timestamp() }}) as retry_date, + error_type, + charge_attempts, + address_id, + client_details->>'browser_ip' as client_details_browser_ip, + client_details->>'user_agent' as client_details_user_agent, + tags, + error, + external_variant_id_not_found + + from + {{ source('source_recharge', 'charges') }} +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/charge.yml b/connectors/source_recharge/models/fivetran_converter/charge.yml new file mode 100644 index 00000000..bae59b3d --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge.yml @@ -0,0 +1,76 @@ +version: 2 + +models: + - name: charge + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Address table aligned with the Fivetran dbt model." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: charge_id + description: "Charge unique identifier" + - name: customer_id + description: "Customer unique identifier" + - name: customer_hash + description: The hash of the customer associated with the charge. + - name: email + description: The email address of the customer. + - name: charge_created_at + description: Date and time when the charge was created. + - name: charge_type + description: "{{ doc('type') }}" + - name: charge_status + description: "{{ doc('charge_status') }}" + - name: charge_updated_at + description: Date and time when the charge was last updated. + - name: note + description: Shows the next order in sequence. + - name: subtotal_price + description: The combined price of all line_items without taxes and shipping. + - name: tags + description: A comma-separated list of tags on the charge. + - name: error + description: Error reason as sentence text (typically returned directly from the payment processor - e.g. "customer needs to update credit card"). + - name: external_variant_id_not_found + description: Indicates if Recharge was able to find the external_variant_id_ecommerce from the charge. + - name: tax_lines + description: An array of tax lines that apply to the charge. + - name: total_discounts + description: The sum of the discounts applied to the charge. + - name: total_line_items_price + description: The sum of all the prices of all the items in the charge. + - name: total_tax + description: The total tax due associated with the charge. + - name: total_price + description: The sum of all the prices of all the items in the charge, taxes and discounts included (must be positive). + - name: total_refunds + description: The sum of all refunds that were applied to the charge. + - name: total_weight_grams + description: The total weight of all items in the charge in grams. + - name: charge_scheduled_at + description: The date time of when the associated charge is/was scheduled to process. + - name: charge_processed_at + description: Date and time when the charge was processed. + - name: payment_processor + description: The payment processor used on the charge. + - name: external_transaction_id_payment_processor + description: The unique alphanumeric identifier of the transaction. + - name: external_order_id_ecommerce + description: The unique numeric identifier within your external ecommerce platform for the charge. + - name: orders_count + description: The number of orders generated from this charge (Will be >1 for prepaid). + - name: has_uncommitted_changes + description: Specifies whether the charge is scheduled for regeneration (if the subscription is related to the charge was updated in the last 5 seconds using "commit_update":false). + - name: retry_date + description: The date when the next attempt will be placed. + - name: error_type + description: Structured reason why the charge failed such as customer_needs_to_updated_card. + - name: times_retried + description: Shows how many times an attempt to charge was placed. + - name: address_id + description: "{{ doc('address_id') }}" + - name: client_details_browser_ip + description: The IP address of the buyer detected in checkout. + - name: client_details_user_agent + description: The user agent detected during checkout. diff --git a/connectors/source_recharge/models/fivetran_converter/charge_discount.sql b/connectors/source_recharge/models/fivetran_converter/charge_discount.sql new file mode 100644 index 00000000..670849d9 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_discount.sql @@ -0,0 +1,61 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Snowflake: Explicitly cast NULL to integer + m.value:id::string as discount_id, -- Snowflake: Extract JSON key using colon notation + m.value:code::string as code, + cast(m.value:value as {{ dbt.type_float() }}) as discount_value, -- Snowflake: Cast JSON value to float + m.value:value_type::string as value_type + FROM + {{ source('source_recharge', 'charges') }}, + lateral flatten(input => ARRAY_CONSTRUCT(discounts)) m -- Snowflake: Use LATERAL FLATTEN to unnest JSON array + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as charge_id, + NULL as index, -- BigQuery: NULL without explicit type casting + JSON_VALUE(m, '$.id') as discount_id, -- BigQuery: Extract JSON values with JSON_VALUE + JSON_VALUE(m, '$.code') as code, + cast(JSON_VALUE(m, '$.value') as {{ dbt.type_float() }}) as discount_value, -- BigQuery: Cast JSON value to float + JSON_VALUE(m, '$.value_type') as value_type + FROM + {{ source('source_recharge', 'charges') }}, + UNNEST (JSON_QUERY_ARRAY(discounts)) m -- BigQuery: Use UNNEST to expand JSON array + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Postgres: Explicitly cast NULL to integer + m.value ->> 'id' as discount_id, -- Postgres: Extract JSON key as text using ->> + m.value ->> 'code' as code, + cast(m.value ->> 'value' as {{ dbt.type_float() }}) as discount_value, -- Postgres: Cast JSON value to float + m.value ->> 'value_type' as value_type + FROM + {{ source('source_recharge', 'charges') }}, + jsonb_array_elements(discounts::jsonb) as m(value) -- Postgres: Use jsonb_array_elements to unnest JSON array + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/charge_discount.yml b/connectors/source_recharge/models/fivetran_converter/charge_discount.yml new file mode 100644 index 00000000..e7e7c89d --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_discount.yml @@ -0,0 +1,22 @@ +version: 2 + +models: + - name: charge_discount + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all charge discount codes." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: charge_id + description: "{{ doc('charge_id') }}" + - name: index + description: A unique numeric row produced for every concurrent charge_id. + - name: discount_id + description: The ID of the discount associated with the charge. + - name: code + description: The code used to apply the discount. + - name: discount_value + description: The discounted value to be applied. + - name: value_type + description: Possible values - FIXED_AMOUNT, PERCENTAGE, SHIPPING \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/charge_line_item.sql b/connectors/source_recharge/models/fivetran_converter/charge_line_item.sql new file mode 100644 index 00000000..7fcb2c6e --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_line_item.sql @@ -0,0 +1,100 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Snowflake: Explicitly cast NULL to integer + m.value:vendor::string as vendor, -- Snowflake: Extract JSON keys using colon notation and cast to appropriate types + m.value:title::string as title, + m.value:variant_title::string as variant_title, + m.value:sku::string as sku, + m.value:grams::number as grams, + m.value:quantity::number as quantity, + CAST(m.value:total_price::string AS {{ dbt.type_float() }}) as total_price, -- Snowflake: Cast JSON value to float + m.value:unit_price::string as unit_price, + m.value:tax_due::string as tax_due, + m.value:taxable::string as taxable, + m.value:taxable_amount::string as taxable_amount, + m.value:unit_price_includes_tax::string as unit_price_includes_tax, + m.value:external_product_id_ecommerce::string as external_product_id_ecommerce, + m.value:external_variant_id_ecommerce::string as external_variant_id_ecommerce, + m.value:purchase_item_id::string as purchase_item_id, + m.value:purchase_item_type::string as purchase_item_type + + FROM + {{ source('source_recharge', 'charges') }}, + lateral flatten(input => ARRAY_CONSTRUCT(line_items)) m -- Snowflake: Use LATERAL FLATTEN to unnest JSON array + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as charge_id, + null as index, + JSON_VALUE(m, '$.vendor') as vendor, + JSON_VALUE(m, '$.title') as title, + JSON_VALUE(m, '$.variant_title') as variant_title, + JSON_VALUE(m, '$.sku') as sku, + JSON_VALUE(m, '$.grams') as grams, + JSON_VALUE(m, '$.quantity') as quantity, + CAST(JSON_VALUE(m, '$.total_price') as {{ dbt.type_float() }}) as total_price, + JSON_VALUE(m, '$.unit_price') as unit_price, + JSON_VALUE(m, '$.tax_due') as tax_due, + JSON_VALUE(m, '$.taxable') as taxable, + JSON_VALUE(m, '$.taxable_amount') as taxable_amount, + JSON_VALUE(m, '$.unit_price_includes_tax') as unit_price_includes_tax, + JSON_VALUE(m, '$.external_product_id_ecommerce') as external_product_id_ecommerce, + JSON_VALUE(m, '$.external_variant_id_ecommerce') as external_variant_id_ecommerce, + JSON_VALUE(m, '$.purchase_item_id') as purchase_item_id, + JSON_VALUE(m, '$.purchase_item_type') as purchase_item_type + + FROM + {{ source('source_recharge', 'charges') }}, + UNNEST (JSON_QUERY_ARRAY(line_items)) m -- BigQuery: Use UNNEST to expand JSON array + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id, + NULL::integer as index, -- Postgres: Explicitly cast NULL to integer + m.value ->> 'vendor' as vendor, -- Postgres: Extract JSON key as text using ->> + m.value ->> 'title' as title, + m.value ->> 'variant_title' as variant_title, + m.value ->> 'sku' as sku, + m.value ->> 'grams' as grams, + m.value ->> 'quantity' as quantity, + CAST(m.value ->> 'total_price' as {{ dbt.type_float() }}) as total_price, -- Postgres: Cast JSON value to float + m.value ->> 'unit_price' as unit_price, + m.value ->> 'tax_due' as tax_due, + m.value ->> 'taxable' as taxable, + m.value ->> 'taxable_amount' as taxable_amount, + m.value ->> 'unit_price_includes_tax' as unit_price_includes_tax, + m.value ->> 'external_product_id_ecommerce' as external_product_id_ecommerce, + m.value ->> 'external_variant_id_ecommerce' as external_variant_id_ecommerce, + cast(m.value ->> 'purchase_item_id' as {{ dbt.type_int() }}) as purchase_item_id, + m.value ->> 'purchase_item_type' as purchase_item_type + + FROM + {{ source('source_recharge', 'charges') }}, + jsonb_array_elements(line_items::jsonb) as m(value) -- Postgres: Use jsonb_array_elements to unnest JSON array + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/charge_line_item.yml b/connectors/source_recharge/models/fivetran_converter/charge_line_item.yml new file mode 100644 index 00000000..e9f64c3b --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_line_item.yml @@ -0,0 +1,46 @@ +version: 2 + +models: + - name: charge_line_item + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all charge line items, each containing information about a distinct purchase item." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: charge_id + description: "{{ doc('charge_id') }}" + - name: index + description: A unique numeric row produced for every concurrent charge_id. + - name: vendor + description: The name of the seller. + - name: title + description: The product title that links to your external ecommerce platform. + - name: variant_title + description: The name of the product variant. + - name: sku + description: The SKU (stock keeping unit) of the product associated with the charge's line item. + - name: grams + description: The weight of the charge's line item in grams. + - name: quantity + description: The quantity of the line_item. + - name: total_price + description: The total price of the line_item including tax. + - name: unit_price + description: The unit price of the line_item. + - name: tax_due + description: The total tax due associated with the line_item. + - name: taxable + description: A boolean indicating if the line_item is taxable or non-taxable. + - name: taxable_amount + description: The taxable revenue associated with the line_item. + - name: unit_price_includes_tax + description: A boolean indicator if tax is included in the price of an item. + - name: external_product_id_ecommerce + description: The product ID that links to your external ecommerce platform. + - name: external_variant_id_ecommerce + description: The variant ID that links to your external ecommerce platform. + - name: purchase_item_id + description: The subscription or onetime ID associated with the line_item. + - name: purchase_item_type + description: Possible values are SUBSCRIPTION, ONETIME. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/charge_order_attribute.sql b/connectors/source_recharge/models/fivetran_converter/charge_order_attribute.sql new file mode 100644 index 00000000..24e1e06f --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_order_attribute.sql @@ -0,0 +1,49 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Snowflake: Explicitly cast NULL to integer + order_attributes::string as order_attribute -- Snowflake: Cast order_attributes to string if needed + FROM + {{ source('source_recharge', 'charges') }} + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as charge_id, + null as index, -- BigQuery: NULL without explicit type casting + order_attributes as order_attribute -- BigQuery: Leave order_attributes unchanged + FROM + {{ source('source_recharge', 'charges') }} + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Postgres: Explicitly cast NULL to integer + order_attributes::text as order_attribute -- Postgres: Cast order_attributes to text if needed + FROM + {{ source('source_recharge', 'charges') }} + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/charge_order_attribute.yml b/connectors/source_recharge/models/fivetran_converter/charge_order_attribute.yml new file mode 100644 index 00000000..7d818c1c --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_order_attribute.yml @@ -0,0 +1,16 @@ +version: 2 + +models: + - name: charge_order_attribute + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of notes associated to their corresponding charges." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: charge_id + description: "{{ doc('charge_id') }}" + - name: index + description: A unique numeric row produced for every concurrent charge_id. + - name: order_attribute + description: An array of name-value pairs of order attributes on the charge. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/charge_shipping_line.sql b/connectors/source_recharge/models/fivetran_converter/charge_shipping_line.sql new file mode 100644 index 00000000..83b5d05f --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_shipping_line.sql @@ -0,0 +1,58 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Snowflake: Explicitly cast NULL to integer + cast(m.value:price::string as {{ dbt.type_float() }}) as price, -- Snowflake: Extract JSON keys using colon notation and cast to appropriate types + m.value:code::string as code, + m.value:title::string as title + FROM + {{ source('source_recharge', 'charges') }}, + lateral flatten(input => ARRAY_CONSTRUCT(shipping_lines)) m -- Snowflake: Use LATERAL FLATTEN to unnest JSON array + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as charge_id, + null as index, -- BigQuery: NULL without explicit type casting + cast(JSON_VALUE(m, '$.price') as {{ dbt.type_float() }}) as price, -- BigQuery: Extract JSON values with JSON_VALUE + JSON_VALUE(m, '$.code') as code, + JSON_VALUE(m, '$.title') as title + FROM + {{ source('source_recharge', 'charges') }}, + UNNEST (JSON_QUERY_ARRAY(shipping_lines)) m -- BigQuery: Use UNNEST to expand JSON array + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Postgres: Explicitly cast NULL to integer + cast(m.value ->> 'price' as {{ dbt.type_float() }}) as price, -- Postgres: Extract JSON key as text using ->> + m.value ->> 'code' as code, + m.value ->> 'title' as title + FROM + {{ source('source_recharge', 'charges') }}, + jsonb_array_elements(shipping_lines::jsonb) as m(value) -- Postgres: Use jsonb_array_elements to unnest JSON array + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/charge_shipping_line.yml b/connectors/source_recharge/models/fivetran_converter/charge_shipping_line.yml new file mode 100644 index 00000000..54563467 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_shipping_line.yml @@ -0,0 +1,20 @@ +version: 2 + +models: + - name: charge_shipping_line + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all shipping information associated to their corresponding charges." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: charge_id + description: "{{ doc('charge_id') }}" + - name: index + description: A unique numeric row produced for every concurrent charge_id. + - name: price + description: The price of th shipping line of a charge. + - name: code + description: The code associated with the shipping line of a charge. + - name: title + description: The title of the shipping line. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/charge_tax_line.sql b/connectors/source_recharge/models/fivetran_converter/charge_tax_line.sql new file mode 100644 index 00000000..710df0e5 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_tax_line.sql @@ -0,0 +1,59 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Snowflake: Explicitly cast NULL to integer + t.value:price::string as price, -- Snowflake: Extract JSON keys using colon notation and cast to appropriate types + t.value:rate::string as rate, + t.value:title::string as title + FROM + {{ source('source_recharge', 'charges') }} c, + lateral flatten(input => parse_json(c.tax_lines)) t -- Snowflake: Use LATERAL FLATTEN to unnest JSON objects + +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as charge_id, + null as index, -- BigQuery: NULL without explicit type casting + JSON_VALUE(f, '$.price') as price, -- BigQuery: Extract JSON values with JSON_VALUE + JSON_VALUE(f, '$.rate') as rate, + JSON_VALUE(f, '$.title') as title + FROM + {{ source('source_recharge', 'charges') }} c, + UNNEST(JSON_EXTRACT_ARRAY(c.tax_lines)) AS f + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as charge_id, + NULL::integer as index, -- Postgres: Explicitly cast NULL to integer + f.value ->> 'price' as price, -- Postgres: Extract JSON keys from text + f.value ->> 'rate' as rate, + f.value ->> 'title' as title + FROM + {{ source('source_recharge', 'charges') }} c, + LATERAL jsonb_array_elements(c.tax_lines::jsonb) AS f(value) + + +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/charge_tax_line.yml b/connectors/source_recharge/models/fivetran_converter/charge_tax_line.yml new file mode 100644 index 00000000..9416d277 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/charge_tax_line.yml @@ -0,0 +1,20 @@ +version: 2 + +models: + - name: charge_tax_line + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of tax line information associated to their corresponding charges." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: charge_id + description: "{{ doc('charge_id') }}" + - name: index + description: A unique numeric row produced for every concurrent charge_id. + - name: price + description: The total tax associated with the listed jurisdiction. + - name: rate + description: The tax rate associated with the listed jurisdiction. + - name: title + description: The title/name of the taxing jurisdiction. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/checkout.yml b/connectors/source_recharge/models/fivetran_converter/checkout.yml new file mode 100644 index 00000000..723d1db8 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/checkout.yml @@ -0,0 +1,48 @@ +version: 2 + +models: + - name: checkout + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "checkouts" + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: checkout_id + description: Unique token for the Checkout + - name: charge_id + description: ID for the Charge resulting from processing the Checkout. + - name: buyer_accepts_marketing + description: Boolean if the buyer accept marketing, newsletters etc. + - name: checkout_completed_at + description: Timestamp for when the Checkout was processed. + - name: checkout_created_at + description: Timestamp for when the Checkout was created. + - name: currency + description: Currency of the Checkout. + - name: discount_code + description: Discount code to be used on the checkout, e.g. “DISCOUNT20”. + - name: email + description: Email address for the customer. + - name: external_checkout_id + description: Represents the external cart token. + - name: external_checkout_source + description: Represents the source for external_checkout_id. + - name: external_transaction_id_payment_processor + description: Transaction ID of the external payment processor. + - name: order_attributes + description: Structured custom notes. + - name: phone + description: Customer phone number. + - name: requires_shipping + description: Boolean if the Checkout contains items that require shipping. + - name: subtotal_price + description: Value of the Checkout minus shipping and tax. + - name: taxes_included + description: Boolean if the tax is included in the price of the items. + - name: total_price + description: Full price of the Checkout including shipping and tax. + - name: total_tax + description: Tax charged on the Checkout. + - name: checkout_updated_at + description: Timestamp for the latest Checkout update. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/customer.sql b/connectors/source_recharge/models/fivetran_converter/customer.sql new file mode 100644 index 00000000..66684428 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/customer.sql @@ -0,0 +1,96 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as customer_id, + hash as customer_hash, + to_variant(external_customer_id):ecommerce as external_customer_id_ecommerce, + email, + first_name, + last_name, + cast(created_at as {{ dbt.type_timestamp() }}) as customer_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as customer_updated_at, + cast(first_charge_processed_at as {{ dbt.type_timestamp() }}) as first_charge_processed_at, + subscriptions_active_count, + subscriptions_total_count, + has_valid_payment_method, + has_payment_method_in_dunning, + tax_exempt, + billing_first_name, + billing_last_name, + billing_company, + billing_city, + billing_country + from + {{ source('source_recharge', 'customers') }} +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + + select + id as customer_id, + "hash" as customer_hash, + JSON_VALUE(external_customer_id, '$.ecommerce') as external_customer_id_ecommerce, + email, + first_name, + last_name, + cast(created_at as {{ dbt.type_timestamp() }}) as customer_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as customer_updated_at, + cast(first_charge_processed_at as {{ dbt.type_timestamp() }}) as first_charge_processed_at, + subscriptions_active_count, + subscriptions_total_count, + has_valid_payment_method, + has_payment_method_in_dunning, + tax_exempt, + billing_first_name, + billing_last_name, + billing_company, + billing_city, + billing_country + FROM + {{ source('source_recharge', 'customers') }} + +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as customer_id, + hash as customer_hash, + external_customer_id->>'ecommerce' as external_customer_id_ecommerce, + email, + first_name, + last_name, + cast(created_at as {{ dbt.type_timestamp() }}) as customer_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as customer_updated_at, + cast(first_charge_processed_at as {{ dbt.type_timestamp() }}) as first_charge_processed_at, + subscriptions_active_count, + subscriptions_total_count, + has_valid_payment_method, + has_payment_method_in_dunning, + tax_exempt, + billing_first_name, + billing_last_name, + billing_company, + billing_city, + billing_country + from + {{ source('source_recharge', 'customers') }} +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/customer.yml b/connectors/source_recharge/models/fivetran_converter/customer.yml new file mode 100644 index 00000000..8f7b1d6d --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/customer.yml @@ -0,0 +1,38 @@ +version: 2 + +models: + - name: customer + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all customer details holding account and billing information. Email is unique on the customer, no two customers for a store can have the same email." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: customer_id + description: "{{ doc('customer_id') }}" + - name: customer_hash + description: The unique string identifier used in a customer portal link. + - name: external_customer_id_ecommerce + description: External platform's identifier for the customer. + - name: email + description: The email address of the customer. + - name: first_name + description: The customer's first name. + - name: last_name + description: The customer's last name. + - name: customer_created_at + description: The date and time when the customer was created. + - name: customer_updated_at + description: The date and time when the customer was last updated. + - name: first_charge_processed_at + description: Date when first charge was processed for the customer. + - name: subscriptions_active_count + description: The number of active subscriptions associated with the customer. + - name: subscriptions_total_count + description: The total number of subscriptions associated with the customer. + - name: has_valid_payment_method + description: Boolean indicating if the payment value is valid. + - name: has_payment_method_in_dunning + description: Boolean indicating if the customer has a credit card in dunning. + - name: tax_exempt + description: Boolean indicating if the customer is tax exempt. diff --git a/connectors/source_recharge/models/fivetran_converter/discount.sql b/connectors/source_recharge/models/fivetran_converter/discount.sql new file mode 100644 index 00000000..c70d92e1 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/discount.sql @@ -0,0 +1,79 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as discount_id, + cast(created_at as {{ dbt.type_timestamp() }}) as discount_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as discount_updated_at, + cast(starts_at as {{ dbt.type_timestamp() }}) as discount_starts_at, + cast(ends_at as {{ dbt.type_timestamp() }}) as discount_ends_at, + code, + value, + status, + usage_limit as usage_limits, + applies_to, + applies_to_resource, + applies_to_id, + applies_to_product_type, + null as minimum_order_amount + from + {{ source('source_recharge', 'discounts') }} +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as discount_id, + cast(created_at as {{ dbt.type_timestamp() }}) as discount_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as discount_updated_at, + cast(starts_at as {{ dbt.type_timestamp() }}) as discount_starts_at, + cast(ends_at as {{ dbt.type_timestamp() }}) as discount_ends_at, + code, + value, + status, + usage_limit as usage_limits, + applies_to, + applies_to_resource, + applies_to_id, + applies_to_product_type, + null as minimum_order_amount + FROM + {{ source('source_recharge', 'discounts') }} +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as discount_id, + cast(created_at as {{ dbt.type_timestamp() }}) as discount_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as discount_updated_at, + cast(starts_at as {{ dbt.type_timestamp() }}) as discount_starts_at, + cast(ends_at as {{ dbt.type_timestamp() }}) as discount_ends_at, + code, + value, + status, + usage_limit as usage_limits, + applies_to, + applies_to_resource, + applies_to_id, + applies_to_product_type, + null as minimum_order_amount + from + {{ source('source_recharge', 'discounts') }} +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/discount.yml b/connectors/source_recharge/models/fivetran_converter/discount.yml new file mode 100644 index 00000000..991a342b --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/discount.yml @@ -0,0 +1,38 @@ +version: 2 + +models: + - name: discount + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of discounts that can be applied to a checkout, or that can be directly applied to an address." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: discount_id + description: Unique numeric identifier for the discount in Recharge. + - name: discount_created_at + description: The date and time when the discount was created. + - name: discount_updated_at + description: The date and time when the discount was last updated. + - name: discount_starts_at + description: The date when the discount becomes active. + - name: discount_ends_at + description: The expiration time of the discount, past this time the discount can no longer be redeemed, once the time of the discount has passed the status of the discount will go from 'active' to 'disabled'. + - name: code + description: The code used to apply the discount. + - name: value + description: The discounted value to be applied. + - name: status + description: The status of the discount. Possible values are ENABLED, DISABLED, or FULLY_DISABLED. + - name: usage_limits + description: An integer indicating how many times the discount can been used. + - name: applies_to + description: Indicates where the discount applies. + - name: applies_to_resource + description: An indicator of the type of resource which applies_to_id refers. + - name: applies_to_id + description: A list of ids of the type indicated in applies_to_resource for which the discount can be applied. + - name: applies_to_product_type + description: Indicates which product types the discount applies to. + - name: minimum_order_amount + description: The minimum cart subtotal needed for the discount to be applicable. `duration` has to be `single_use` and the discount must apply to the entire order. diff --git a/connectors/source_recharge/models/fivetran_converter/one_time_product.sql b/connectors/source_recharge/models/fivetran_converter/one_time_product.sql new file mode 100644 index 00000000..820b80c2 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/one_time_product.sql @@ -0,0 +1,79 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as one_time_product_id, + address_id, + customer_id, + null as is_deleted, + cast(created_at as {{ dbt.type_timestamp() }}) as one_time_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as one_time_updated_at, + next_charge_scheduled_at as one_time_next_charge_scheduled_at, + product_title, + variant_title, + price, + quantity, + shopify_product_id as external_product_id_ecommerce, + shopify_variant_id as external_variant_id_ecommerce, + sku + from + {{ source('source_recharge', 'onetimes') }} +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as one_time_product_id, + address_id, + customer_id, + null as is_deleted, + cast(created_at as {{ dbt.type_timestamp() }}) as one_time_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as one_time_updated_at, + next_charge_scheduled_at as one_time_next_charge_scheduled_at, + product_title, + variant_title, + price, + quantity, + shopify_product_id as external_product_id_ecommerce, + shopify_variant_id as external_variant_id_ecommerce, + sku + from + {{ source('source_recharge', 'onetimes') }} +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id as one_time_product_id, + address_id, + customer_id, + null as is_deleted, + cast(created_at as {{ dbt.type_timestamp() }}) as one_time_created_at, + cast(updated_at as {{ dbt.type_timestamp() }}) as one_time_updated_at, + next_charge_scheduled_at as one_time_next_charge_scheduled_at, + product_title, + variant_title, + price, + quantity, + shopify_product_id as external_product_id_ecommerce, + shopify_variant_id as external_variant_id_ecommerce, + sku + from + {{ source('source_recharge', 'onetimes') }} +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/one_time_product.yml b/connectors/source_recharge/models/fivetran_converter/one_time_product.yml new file mode 100644 index 00000000..c80fec74 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/one_time_product.yml @@ -0,0 +1,38 @@ +version: 2 + +models: + - name: one_time_product + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all one-times which represent non-recurring line items on a queued charges." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: one_time_product_id + description: The unique numeric identifier for the onetime purchase. + - name: address_id + description: The unique identifier of the address. Cannot be used with `next_charge_scheduled_at`. + - name: customer_id + description: Unique numeric identifier for the customer the onetime purchase is tied to. + - name: is_deleted + description: Boolean indicating if the onetime is deleted. + - name: one_time_created_at + description: The time the onetime item was first created. + - name: one_time_updated_at + description: The time the onetime item was last updated. + - name: one_time_next_charge_scheduled_at + description: Date of the onetime purchase execution. + - name: product_title + description: The name of the product in a shop's catalog. + - name: variant_title + description: The name of the variant in a shop's catalog. + - name: price + description: The price of the item before discounts, taxes, or shipping have been applied. + - name: quantity + description: The number of items in the onetime purchase. + - name: external_product_id_ecommerce + description: The product ID that links to your external ecommerce platform. + - name: external_variant_id_ecommerce + description: The variant ID that links to your external ecommerce platform. + - name: sku + description: The unique identifier of the item in fulfillment. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/order_extended.sql b/connectors/source_recharge/models/fivetran_converter/order_extended.sql new file mode 100644 index 00000000..09a74486 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/order_extended.sql @@ -0,0 +1,92 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id, + customer_id, + email, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + status as order_status, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + charge_id, + transaction_id, + charge_status, + is_prepaid, + cast(total_price as {{ dbt.type_float() }}) as total_price, + type, + cast(processed_at as {{ dbt.type_timestamp() }}) as processed_at, + cast(scheduled_at as {{ dbt.type_timestamp() }}) as scheduled_at, + cast(shipped_date as {{ dbt.type_timestamp() }}) as shipped_date, + address_id, + null as is_deleted + from + {{ source('source_recharge', 'orders') }} +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as order_id, + JSON_VALUE(external_order_id, '$.ecommerce') as external_order_id_ecommerce, + JSON_VALUE(external_order_number, '$.ecommerce') as external_order_number_ecommerce, + customer_id, + email, + cast(created_at as {{ dbt.type_timestamp() }}) as order_created_at, + status as order_status, + cast(updated_at as {{ dbt.type_timestamp() }}) as order_updated_at, + charge_id, + transaction_id, + charge_status, + is_prepaid, + cast(total_price as {{ dbt.type_float() }}) as order_total_price, + type as order_type, + cast(processed_at as {{ dbt.type_timestamp() }}) as order_processed_at, + cast(scheduled_at as {{ dbt.type_timestamp() }}) as order_scheduled_at, + cast(shipped_date as {{ dbt.type_timestamp() }}) as order_shipped_date, + address_id, + null as is_deleted + from + {{ source('source_recharge', 'orders') }} +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id, + external_order_id->>'ecommerce' as external_order_id_ecommerce, + external_order_number->>'ecommerce' as external_order_number_ecommerce, + customer_id, + email, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + status, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + charge_id, + transaction_id, + charge_status, + case when is_prepaid = 0 then false else true end as is_prepaid, + cast(total_price as {{ dbt.type_float() }}) as total_price, + type as order_type, + cast(processed_at as {{ dbt.type_timestamp() }}) as processed_at, + cast(scheduled_at as {{ dbt.type_timestamp() }}) as scheduled_at, + cast(shipped_date as {{ dbt.type_timestamp() }}) as shipped_date, + address_id, + null as is_deleted + from + {{ source('source_recharge', 'orders') }} +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/order_extended.yml b/connectors/source_recharge/models/fivetran_converter/order_extended.yml new file mode 100644 index 00000000..5065eef1 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/order_extended.yml @@ -0,0 +1,48 @@ +version: 2 + +models: + - name: order_extended + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all orders after a charge is successfully processed." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: order_id + description: "{{ doc('charge_id') }}" + - name: external_order_id_ecommerce + description: Unique numeric identifier within your external ecommerce platform for the order. + - name: external_order_number_ecommerce + description: The unique order number within your external ecommerce platform. + - name: customer_id + description: The unique numeric identifier of the customer. + - name: email + description: The email address of the customer. + - name: order_created_at + description: The date and time when the order was created. + - name: order_status + description: The status of the order. Possible values are SUCCESS, ERROR, QUEUED, or CANCELLED + - name: order_updated_at + description: The date and time when the order was last updated. + - name: charge_id + description: The unique numeric identifier of the charge. + - name: transaction_id + description: The unique alphanumeric identifier of the transaction. + - name: charge_status + description: "{{ doc('charge_status') }}" + - name: is_prepaid + description: Boolean indicating if the Order is prepaid. + - name: order_total_price + description: The total amount due of the Order. + - name: order_type + description: "{{ doc('type') }}" + - name: order_processed_at + description: The date and time when the order was submitted. + - name: order_scheduled_at + description: The date and time when the order will be shipped. + - name: order_shipped_date + description: The date when the order will be processed. + - name: address_id + description: "{{ doc('address_id') }}" + - name: is_deleted + description: Boolean indicating if the order (record) is deleted. diff --git a/connectors/source_recharge/models/fivetran_converter/order_line_item.sql b/connectors/source_recharge/models/fivetran_converter/order_line_item.sql new file mode 100644 index 00000000..0c4a9cc3 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/order_line_item.sql @@ -0,0 +1,91 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as order_id, + null as index, + m.value:shopify_product_id::string as external_product_id_ecommerce, + m.value:shopify_product_id::string as external_variant_id_ecommerce, + m.value:title::string as order_line_item_title, + m.value:variant_title::string as product_variant_title, + m.value:sku::string as sku, + m.value:quantity::integer as quantity, + m.value:grams::integer as grams, + cast(m.value:total_price::float as {{ dbt.type_float() }}) as total_price, + m.value:unit_price::float as unit_price, + m.value:tax_due::float as tax_due, + m.value:taxable::boolean as taxable, + m.value:taxable_amount::float as taxable_amount, + m.value:unit_price_includes_tax::boolean as unit_price_includes_tax, + m.value:purchase_item_id::string as purchase_item_id, + m.value:purchase_item_type::string as purchase_item_type + from + {{ source('source_recharge', 'orders') }} o, + lateral flatten(input => o.line_items) m -- Unnesting the JSON array +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as order_id, + null as index, + JSON_VALUE(line_items, '$.shopify_product_id') as external_product_id_ecommerce, + JSON_VALUE(line_items, '$.shopify_product_id') as external_variant_id_ecommerce, + JSON_VALUE(line_items, '$.title') as order_line_item_title, + JSON_VALUE(line_items, '$.variant_title') as product_variant_title, + JSON_VALUE(line_items, '$.sku') as sku, + JSON_VALUE(line_items, '$.quantity') as quantity, + JSON_VALUE(line_items, '$.grams') as grams, + cast(JSON_VALUE(line_items, '$.total_price') as {{ dbt.type_float() }}) as total_price, + JSON_VALUE(line_items, '$.unit_price') as unit_price, + JSON_VALUE(line_items, '$.tax_due') as tax_due, + JSON_VALUE(line_items, '$.taxable') as taxable, + JSON_VALUE(line_items, '$.taxable_amount') as taxable_amount, + JSON_VALUE(line_items, '$.unit_price_includes_tax') as unit_price_includes_tax, + JSON_VALUE(line_items, '$.purchase_item_id') as purchase_item_id, + JSON_VALUE(line_items, '$.purchase_item_type') as purchase_item_type + from + {{ source('source_recharge', 'orders') }} o, + UNNEST (JSON_QUERY_ARRAY(o.line_items)) line_items +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + o.id order_id, + null as index, + f.value->>'shopify_product_id' as external_product_id_ecommerce, + f.value->>'shopify_variant_id' as external_variant_id_ecommerce, + f.value->>'title' as order_line_item_title, + f.value->>'variant_title' as product_variant_title, + f.value->>'sku' as sku, + (f.value->>'quantity')::int as quantity, + (f.value->>'grams')::int as grams, + cast((f.value->>'total_price')::float as {{ dbt.type_float() }}) as total_price, + f.value->>'unit_price' as unit_price, + f.value->>'tax_due' as tax_due, + (f.value->>'taxable')::boolean as taxable, + f.value->>'taxable_amount' as taxable_amount, + (f.value->>'unit_price_includes_tax')::boolean as unit_price_includes_tax, + f.value->>'purchase_item_id' as purchase_item_id, + f.value->>'purchase_item_type' as purchase_item_type + from + {{ source('source_recharge', 'orders') }} o, + LATERAL jsonb_array_elements(o.line_items::jsonb) AS f(value) +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/order_line_item.yml b/connectors/source_recharge/models/fivetran_converter/order_line_item.yml new file mode 100644 index 00000000..12c2c8e7 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/order_line_item.yml @@ -0,0 +1,44 @@ +version: 2 + +models: + - name: order_line_item + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all order line items. Each line containing information about an item in the order." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: order_id + description: "{{ doc('charge_id') }}" + - name: index + description: A unique numeric row produced for every concurrent order_id. + - name: external_product_id_ecommerce + description: The unique numeric identifier for your external ecommerce platform product in the fulfillment. + - name: external_variant_id_ecommerce + description: Unique numeric identifier of the product variant in your external ecommerce platform. + - name: order_line_item_title + description: The title of the product. + - name: product_variant_title + description: The title of the product variant. + - name: sku + description: A unique identifier of the item in the fulfillment. + - name: quantity + description: The number of products that were purchased. + - name: grams + description: Weight in grams of the item. + - name: total_price + description: The total price of the line_item including tax. + - name: unit_price + description: The unit price of the line_item. + - name: tax_due + description: The total tax due associated with the line_item. + - name: taxable + description: A boolean indicating if the line_item is taxable or non-taxable. + - name: taxable_amount + description: The taxable revenue associated with the line_item. + - name: unit_price_includes_tax + description: A boolean indicator if tax is included in the price of an item. + - name: purchase_item_id + description: The subscription or onetime ID associated with the line_item. + - name: purchase_item_type + description: Possible values are SUBSCRIPTION, ONETIME. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/subscription.sql b/connectors/source_recharge/models/fivetran_converter/subscription.sql new file mode 100644 index 00000000..9746b9f8 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/subscription.sql @@ -0,0 +1,108 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id as subscription_id, + customer_id, + address_id, + cast(created_at as {{ dbt.type_timestamp() }}) as subscription_created_at, + product_title, + variant_title, + sku, + cast(price as {{ dbt.type_float() }}) as price, + quantity, + status, + next_charge_scheduled_at as subscription_next_charge_scheduled_at, + charge_interval_frequency, + expire_after_specific_number_of_charges, + order_interval_frequency, + order_interval_unit, + order_day_of_week, + order_day_of_month, + cast(updated_at as {{ dbt.type_timestamp() }}) as subscription_updated_at, + to_variant(external_product_id):ecommerce as external_product_id_ecommerce, + to_variant(external_variant_id):ecommerce as external_variant_id_ecommerce, + cast(cancelled_at as {{ dbt.type_timestamp() }}) as subscription_cancelled_at, + cancellation_reason, + cancellation_reason_comments + from + {{ source('source_recharge', 'subscriptions') }}, + lateral flatten(input => to_variant(external_product_id)) m +) + +select * +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id as subscription_id, + customer_id, + address_id, + cast(created_at as {{ dbt.type_timestamp() }}) as subscription_created_at, + product_title, + variant_title, + sku, + cast(price as {{ dbt.type_float() }}) as price, + quantity, + status as subscription_status, + next_charge_scheduled_at as subscription_next_charge_scheduled_at, + charge_interval_frequency, + expire_after_specific_number_of_charges, + order_interval_frequency, + order_interval_unit, + order_day_of_week, + order_day_of_month, + cast(updated_at as {{ dbt.type_timestamp() }}) as subscription_updated_at, + JSON_VALUE(external_product_id, '$.ecommerce') as external_product_id_ecommerce, + JSON_VALUE(external_variant_id, '$.ecommerce') as external_variant_id_ecommerce, + cast(cancelled_at as {{ dbt.type_timestamp() }}) as subscription_cancelled_at, + cancellation_reason, + cancellation_reason_comments + from + {{ source('source_recharge', 'subscriptions') }}, + UNNEST (JSON_QUERY_ARRAY(external_product_id)) m +) + +select * +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id, + customer_id, + address_id, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + product_title, + variant_title, + sku, + cast(price as {{ dbt.type_float() }}) as price, + quantity, + status as subscription_status, + next_charge_scheduled_at as next_charge_scheduled_at, + charge_interval_frequency, + expire_after_specific_number_of_charges, + order_interval_frequency, + order_interval_unit, + order_day_of_week, + order_day_of_month, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + external_product_id ->> 'ecommerce' as external_product_id_ecommerce, + external_variant_id ->> 'ecommerce' as external_variant_id_ecommerce, + cast(cancelled_at as {{ dbt.type_timestamp() }}) as cancelled_at, + cancellation_reason, + cancellation_reason_comments + from + {{ source('source_recharge', 'subscriptions') }} +) + +select * +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/subscription.yml b/connectors/source_recharge/models/fivetran_converter/subscription.yml new file mode 100644 index 00000000..8105ac5b --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/subscription.yml @@ -0,0 +1,56 @@ +version: 2 + +models: + - name: subscription + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "Table of all subscriptions for the merchant. Subscriptions are individual items a customer receives on a recurring basis." + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: subscription_id + description: "{{ doc('subscription_id') }}" + - name: customer_id + description: "{{ doc('customer_id') }}" + - name: address_id + description: "{{ doc('address_id') }}" + - name: subscription_created_at + description: The date and time when the subscription was created. + - name: product_title + description: The name of the product in a shop's catalog. + - name: variant_title + description: The name of the variant in a shop's catalog. + - name: sku + description: A unique identifier of the item in fulfillment. + - name: price + description: The price of the item before discounts, taxes, or shipping have been applied. + - name: quantity + description: The number of items in the subscription. + - name: subscription_status + description: The status of the subscription; active = the subscription is active, cancelled = the subscription has been cancelled, expired = the subscription has expired - this occurs when the maximum number of charges for product have been reached. + - name: subscription_next_charge_scheduled_at + description: Date of the next charge for the subscription. + - name: charge_interval_frequency + description: The number of units (specified in order_interval_unit) between each charge. + - name: expire_after_specific_number_of_charges + description: Set the number of charges until subscription expires. + - name: order_interval_frequency + description: The number of units (specified in order_interval_unit) between each order, e.g. order_interval_unit = 'month' and order_interval frequency = 3 indicates an order every 3 months. + - name: order_interval_unit + description: The frequency with which a subscription should have the order created with (valid values are “day”, “week”, and “month”). + - name: order_day_of_month + description: The set day of the month order is created. Default is that there isn’t a strict day of the month when the order is created. + - name: order_day_of_week + description: The set day of the week order is created. Default is that there isn’t a strict day of the week order is created. + - name: subscription_updated_at + description: The date and time when the subscription was created. + - name: external_product_id_ecommerce + description: Unique numeric identifier of the product in your external ecommerce platform. + - name: external_variant_id_ecommerce + description: Unique numeric identifier of the product variant in your external ecommerce platform. + - name: subscription_cancelled_at + description: The date and time when the subscription was cancelled. + - name: cancellation_reason + description: Reason provided for cancellation. + - name: cancellation_reason_comments + description: Additional comment for cancellation. \ No newline at end of file diff --git a/connectors/source_recharge/models/fivetran_converter/subscription_history.sql b/connectors/source_recharge/models/fivetran_converter/subscription_history.sql new file mode 100644 index 00000000..cb495425 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/subscription_history.sql @@ -0,0 +1,116 @@ +{% if target.type == "snowflake" %} + +with tmp as +( + select + id, + customer_id, + address_id, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + to_variant(external_product_id):ecommerce as external_product_id_ecommerce, + to_variant(external_variant_id):ecommerce as external_variant_id_ecommerce, + product_title, + variant_title, + sku, + cast(price as {{ dbt.type_float() }}) as price, + quantity, + status, + charge_interval_frequency, + order_interval_unit, + order_interval_frequency, + order_day_of_month, + order_day_of_week, + expire_after_specific_number_of_charges, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + cast(next_charge_scheduled_at as {{ dbt.type_timestamp() }}) as next_charge_scheduled_at, + cast(cancelled_at as {{ dbt.type_timestamp() }}) as cancelled_at, + cancellation_reason, + cancellation_reason_comments, + cast(_airbyte_extracted_at as {{ dbt.type_timestamp() }}) as _fivetran_synced + from + {{ source('source_recharge', 'subscriptions') }}, + lateral flatten(input => to_variant(external_product_id)) m +) + +select + *, + row_number() over (partition by id order by updated_at desc) = 1 as is_most_recent_record +from tmp + +{% elif target.type == "bigquery" %} + +with tmp as +( + select + id, + customer_id, + address_id, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + JSON_VALUE(external_product_id, '$.ecommerce') as external_product_id_ecommerce, + JSON_VALUE(external_variant_id, '$.ecommerce') as external_variant_id_ecommerce, + product_title, + variant_title, + sku, + cast(price as {{ dbt.type_float() }}) as price, + quantity, + status, + charge_interval_frequency, + order_interval_unit, + order_interval_frequency, + order_day_of_month, + order_day_of_week, + expire_after_specific_number_of_charges, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + cast(next_charge_scheduled_at as {{ dbt.type_timestamp() }}) as next_charge_scheduled_at, + cast(cancelled_at as {{ dbt.type_timestamp() }}) as cancelled_at, + cancellation_reason, + cancellation_reason_comments + from + {{ source('source_recharge', 'subscriptions') }}, + UNNEST (JSON_QUERY_ARRAY(external_product_id)) m +) + +select + *, + row_number() over (partition by id order by updated_at desc) = 1 as is_most_recent_record +from tmp + +{% elif target.type == "postgres" %} + +with tmp as +( + select + id, + customer_id, + address_id, + cast(created_at as {{ dbt.type_timestamp() }}) as created_at, + external_product_id->>'ecommerce' as external_product_id_ecommerce, + external_variant_id->>'ecommerce' as external_variant_id_ecommerce, + product_title, + variant_title, + sku, + cast(price as {{ dbt.type_float() }}) as price, + quantity, + status, + cast(charge_interval_frequency as {{ dbt.type_int() }}) as charge_interval_frequency, + order_interval_unit, + order_interval_frequency, + order_day_of_month, + order_day_of_week, + expire_after_specific_number_of_charges, + cast(updated_at as {{ dbt.type_timestamp() }}) as updated_at, + cast(next_charge_scheduled_at as {{ dbt.type_timestamp() }}) as next_charge_scheduled_at, + cast(cancelled_at as {{ dbt.type_timestamp() }}) as cancelled_at, + cancellation_reason, + cancellation_reason_comments, + cast(_airbyte_extracted_at as {{ dbt.type_timestamp() }}) as _fivetran_synced + from + {{ source('source_recharge', 'subscriptions') }} +) + +select + *, + row_number() over (partition by id order by updated_at desc) = 1 as is_most_recent_record +from tmp + +{% endif %} diff --git a/connectors/source_recharge/models/fivetran_converter/subscription_history.yml b/connectors/source_recharge/models/fivetran_converter/subscription_history.yml new file mode 100644 index 00000000..b6cfa205 --- /dev/null +++ b/connectors/source_recharge/models/fivetran_converter/subscription_history.yml @@ -0,0 +1,58 @@ +version: 2 + +models: + - name: subscription_history + schema: "{{ var('airbyte_schema', target.schema) }}" + database: "{{ var('airbyte_database', target.database) }}" + description: "History table that builds over time. Does not capture history prior to connecting" + config: + +enabled: "{{ var('using_fivetran_model', False) }}" + columns: + - name: subscription_id + description: "{{ doc('subscription_id') }}" + - name: customer_id + description: "{{ doc('customer_id') }}" + - name: address_id + description: "{{ doc('address_id') }}" + - name: subscription_created_at + description: The date and time the subscription was created. + - name: external_product_id_ecommerce + description: An object containing the product id as it appears in external platforms. + - name: product_title + description: The name of the product in a store’s catalog. + - name: external_variant_id_ecommerce + description: An object containing the variant id as it appears in external platforms. + - name: variant_title + description: The name of the variant in a shop’s catalog. + - name: sku + description: A unique identifier of the item in the fulfillment. In cases where SKU is blank, it will be dynamically pulled whenever it is used. + - name: price + description: The price of the item before discounts, taxes, or shipping have been applied. + - name: quantity + description: The number of items in the subscription. + - name: subscription_status + description: The status of the subscription. + - name: charge_interval_frequency + description: The number of units (specified in order_interval_unit) between each Charge. For example, order_interval_unit=month and charge_interval_frequency=3, indicate charge every 3 months. + - name: order_interval_unit + description: The frequency unit used to determine when a subscription’s order is created. + - name: order_interval_frequency + description: The number of units (specified in order_interval_unit) between each order. + - name: order_day_of_month + description: The set day of the month order is created. Default is that there isn’t a strict day of the month when the order is created. + - name: order_day_of_week + description: The set day of the week order is created. Default is that there isn’t a strict day of the week order is created. + - name: expire_after_specific_number_of_charges + description: Set number of charges until subscription expires. + - name: subscription_updated_at + description: The date time at which the purchase_item record was last updated. + - name: subscription_next_charge_scheduled_at + description: Date of the next charge for the subscription. + - name: subscription_cancelled_at + description: The date and time the subscription was cancelled. + - name: cancellation_reason + description: Reason provided for cancellation. + - name: cancellation_reason_comments + description: Additional comment for cancellation. + - name: is_most_recent_record + description: Boolean indicating whether record was the most recent instance.