[B2B edition]{class="badge informative"} [B2P版本]{class="badge informative"}

帳戶設定檔深入分析

帳戶設定檔用於合併來自各種來源的帳戶資訊,包括多個行銷管道和組織系統。 此統一檢視可全面瞭解客戶帳戶,加強B2B行銷活動。 從資料模型分析衍生的深入解析可讓您的Adobe Real-Time CDP B2B資料更易於存取、理解,並更能對決策產生影響。

存取提供您深入分析能力的SQL,可以更瞭解您的B2B資料,並產生您自己的高度自訂且可重複使用的深入分析,以進一步探索您的客戶帳戶資訊。 使用現有的Real-Time CDP資料模型SQL作為靈感,根據您獨特的業務需求建立查詢,將原始資料轉換為可採取行動的新見解。

下列見解全部都可以用作帳戶設定檔儀表板自訂儀表板的一部分。 請參閱自訂總覽,瞭解如何自訂您的儀表板或🔗在Widget程式庫和使用者定義儀表板中建立及編輯新Widget的說明。

已新增的帳戶輪廓 account-profiles-added

此深入分析所回答的問題:

  • 在指定期間內新增了多少帳戶設定檔?
選取以顯示產生此深入分析的SQL
code language-sql
WITH accounts_by_mm_dd AS
(
          SELECT    d.date_key,
                    COALESCE(Sum(a.counts), 0) AS account_counts
          FROM      adwh_b2b_date d
          LEFT JOIN adwh_fact_account a
          ON        d.date_key = a.accounts_created_date
          WHERE     d.date_key BETWEEN Upper(COALESCE('$START_DATE', '')) AND       Upper(COALESCE('$END_DATE', ''))
          GROUP BY  d.date_key)
SELECT   date_key,
         account_counts
FROM     accounts_by_mm_dd
ORDER BY date_key limit 5000;

依產業的新帳戶 accounts-by-industry

此深入分析所回答的問題:

  • 帳戶設定檔所屬的前五大產業為何?
選取以顯示產生此深入分析的SQL
code language-sql
WITH rankedindustries AS
(
           SELECT     i.industry,
                      Sum(f.counts)                                   AS total_accounts,
                      Row_number() OVER (ORDER BY Sum(f.counts) DESC) AS industry_rank
           FROM       adwh_fact_account f
           INNER JOIN adwh_dim_industry i
           ON         f.industry_id = i.industry_id
           WHERE      f.accounts_created_date BETWEEN Upper(COALESCE('$START_DATE', '')) AND        Upper(COALESCE('$END_DATE', ''))
           GROUP BY   i.industry )
SELECT
         CASE
                  WHEN industry_rank <= 5 THEN industry
                  ELSE 'Others'
         END                 AS industry_group,
         Sum(total_accounts) AS total_accounts
FROM     rankedindustries
GROUP BY
         CASE
                  WHEN industry_rank <= 5 THEN industry
                  ELSE 'Others'
         END
ORDER BY total_accounts DESC limit 5000;

新帳戶(依型別) accounts-by-type

此深入分析所回答的問題:

  • 依帳戶型別區分的帳戶計數是多少?
選取以顯示產生此深入分析的SQL
code language-sql
SELECT t.account_type,
       Sum(f.counts) AS account_count
FROM   adwh_fact_account f
       JOIN adwh_dim_account_type t
         ON f.account_type_id = t.account_type_id
WHERE  accounts_created_date BETWEEN Upper(Coalesce('$START_DATE', '')) AND
                                     Upper(
                                     Coalesce('$END_DATE', ''))
GROUP  BY t.account_type
LIMIT  5000;

已新增的機會 opportunities-added

此深入分析所回答的問題:

  • 在指定期間內新增了多少商機?
選取以顯示產生此深入分析的SQL
code language-sql
SELECT d.date_key,
       Coalesce(Sum(o.counts), 0) AS opportunity_counts
FROM   adwh_b2b_date d
       LEFT JOIN adwh_fact_opportunity o
              ON d.date_key = o.opportunities_created_date
WHERE  d.date_key BETWEEN Upper(Coalesce('$START_DATE', '')) AND
                          Upper(Coalesce('$END_DATE', ''))
GROUP  BY d.date_key
ORDER  BY d.date_key
LIMIT  5000;

依個人角色的新機會 opportunities-by-person-role

此深入分析所回答的問題:

  • 機會中各種角色的相對大小和計數為何?
選取以顯示產生此深入分析的SQL
code language-sql
SELECT p.person_role,
       Sum(f.counts) AS opportunity_counts
FROM   adwh_fact_opportunity_person f
       JOIN adwh_dim_person_role p
         ON f.person_role_id = p.person_role_id
WHERE  f.opportunity_person_created_date BETWEEN
       Upper(Coalesce('$START_DATE', '')) AND Upper(Coalesce('$END_DATE', ''))
GROUP  BY p.person_role
LIMIT  5000;

按收入顯示的新商機 opportunities-by-revenue

此深入分析所回答的問題:

  • 依收入排名的20大商機為何(以美元計)?
選取以顯示產生此深入分析的SQL
code language-sql
WITH ranked_opportunities AS
(
           SELECT     n.opportunity_name,
                      a.expected_revenue,
                      t.source_type,
                      Row_number() OVER (ORDER BY a.expected_revenue DESC) AS rank
           FROM       adwh_opportunity_amount a
           INNER JOIN adwh_dim_opportunity_name n
           ON         a.name_id = n.name_id
           INNER JOIN adwh_dim_opportunity_source_type t
           ON         n.source_type_id = t.source_type_id
           WHERE      a.opportunity_created_date BETWEEN Upper(COALESCE('$START_DATE', '')) AND        Upper(COALESCE('$END_DATE', ''))
           AND        a.isclosed='false' )
SELECT
         CASE
                  WHEN rank <= 20 THEN opportunity_name
                  ELSE 'Others'
         END                   AS opportunity_name,
         Sum(expected_revenue) AS total_expected_revenue
FROM     ranked_opportunities
GROUP BY
         CASE
                  WHEN rank <= 20 THEN opportunity_name
                  ELSE 'Others'
         END,
         source_type
ORDER BY total_expected_revenue DESC limit 5000;

按狀態和階段的新機會 opportunities-by-status-and-stage

此深入分析所回答的問題:

  • 有哪些商機,在銷售或行銷漏斗的哪個階段?
  • 有哪些已結束的商機?在銷售或行銷漏斗的哪個階段?
選取以顯示產生此深入分析的SQL
code language-sql
WITH opportunities_by_isclosed AS
(
         SELECT   f.isclosed,
                  Sum(f.counts)             AS opportunity_counts,
                  COALESCE(s.stage, 'null') AS stage
         FROM     adwh_fact_opportunity f
         JOIN     adwh_dim_opportunity_stage s
         ON       f.stage_id = s.stage_id
         WHERE    opportunities_created_date BETWEEN Upper(COALESCE('$START_DATE', '')) AND      Upper(COALESCE('$END_DATE', ''))
         GROUP BY f.isclosed,
                  s.stage)
SELECT
       CASE
              WHEN isclosed='true' THEN 'Closed'
              ELSE 'Open'
       END AS opportunity_closed,
       stage,
       opportunity_counts
FROM   opportunities_by_isclosed limit 5000;

贏得新商機 opportunities-won

此深入分析所回答的問題:

  • 已順利關閉或完成的商機數目為何?
選取以顯示產生此深入分析的SQL
code language-sql
WITH opportunities_by_iswon AS
(
         SELECT   iswon,
                  Sum(counts) AS opportunity_counts
         FROM     adwh_fact_opportunity
         WHERE    opportunities_created_date BETWEEN Upper(COALESCE('$START_DATE', '')) AND      Upper(COALESCE('$END_DATE', ''))
         GROUP BY iswon)
SELECT
       CASE
              WHEN iswon ='true' THEN 'True'
              ELSE 'False'
       END AS opportunity_won,
       opportunity_counts
FROM   opportunities_by_iswon limit 5000;

贏得的機會(折線圖) opportunities-won-line-graph

此深入分析所回答的問題:

  • 在指定期間內,有多少機會已成功關閉或完成(成功)?
選取以顯示產生此深入分析的SQL
code language-sql
WITH opportunities_won_counts AS
(
         SELECT   opportunities_created_date,
                  Sum(counts) AS opportunities_counts
         FROM     adwh_fact_opportunity
         WHERE    iswon='true'
         AND      opportunities_created_date BETWEEN Upper(COALESCE('$START_DATE', '')) AND      Upper(COALESCE('$END_DATE', ''))
         GROUP BY opportunities_created_date)
SELECT    d.date_key,
          COALESCE(o.opportunities_counts, 0) AS opportunity_won_counts
FROM      adwh_b2b_date d
LEFT JOIN opportunities_won_counts o
ON        d.date_key = o.opportunities_created_date
WHERE     d.date_key BETWEEN Upper(COALESCE('$START_DATE', '')) AND       Upper(COALESCE('$END_DATE', ''))
ORDER BY  d.date_key limit 5000;

每個帳戶的客戶概覽 customers-per-account-overview

NOTE
每個帳戶的客戶總覽圖表包含三個鑽研深入分析:每個帳戶的客戶詳細資料、每個帳戶的機會總覽和每個帳戶的機會詳細資料。 這些深入研究可提供更細微的深入分析,並依類別(例如直接和間接客戶)和範圍(例如客戶和機會計數範圍)劃分客戶和機會計數。 這些圖表不受您可能已設定的任何全域日期篩選條件影響。

此深入分析所回答的問題:

  • 根據客戶是否有直接或間接客戶,客戶分配情況如何?
選取以顯示產生此深入分析的SQL
code language-sql
WITH LatestDate AS (SELECT MAX(inserted_date) AS max_inserted_date FROM adwh_b2b_account_person_association),
     CategorizedData AS (
         SELECT CASE
                    WHEN is_direct = 'true' AND person_count = 0 THEN 'Accounts without Direct Customers'
                    WHEN is_direct = 'false' AND person_count = 0 THEN 'Accounts without Indirect Customers'
                    WHEN is_direct = 'true' AND person_count > 0 THEN 'Accounts with Direct Customers'
                    WHEN is_direct = 'false' AND person_count > 0 THEN 'Accounts with Indirect Customers'
                END AS Account_Category,
                account_count
         FROM adwh_b2b_account_person_association
         WHERE inserted_date = (SELECT max_inserted_date FROM LatestDate)
     ),
     AggregatedData AS (
         SELECT Account_Category, SUM(account_count) AS Accounts
         FROM CategorizedData
         GROUP BY Account_Category
     ),
     AllCategories AS (
         SELECT 'Accounts without Direct Customers' AS Account_Category
         UNION ALL SELECT 'Accounts without Indirect Customers'
         UNION ALL SELECT 'Accounts with Direct Customers'
         UNION ALL SELECT 'Accounts with Indirect Customers'
     )
SELECT ac.Account_Category AS Account_Category, COALESCE(ad.Accounts, 0) AS Accounts
FROM AllCategories ac
LEFT JOIN AggregatedData ad ON ac.Account_Category = ad.Account_Category
ORDER BY ac.Account_Category;

每個帳戶的客戶詳細資料 customers-per-account-detail

NOTE
此深入分析不受全域日期篩選的影響。

此深入分析所回答的問題:

  • 有多少帳戶擁有不同範圍的直接或間接客戶?
選取以顯示產生此深入分析的SQL
code language-sql
WITH customer_ranges AS (
    SELECT 'Direct Customer' AS customer_type, '1-10 Customers' AS person_range
    UNION ALL
    SELECT 'Direct Customer', '11-100 Customers'
    UNION ALL
    SELECT 'Direct Customer', '101-1000 Customers'
    UNION ALL
    SELECT 'Direct Customer', '1000+ Customers'
    UNION ALL
    SELECT 'Indirect Customer', '1-10 Customers'
    UNION ALL
    SELECT 'Indirect Customer', '11-100 Customers'
    UNION ALL
    SELECT 'Indirect Customer', '101-1000 Customers'
    UNION ALL
    SELECT 'Indirect Customer', '1000+ Customers'
)
SELECT
    cr.customer_type,
    cr.person_range,
    COALESCE(SUM(ap.account_count), 0) AS Accounts
FROM customer_ranges cr
LEFT JOIN (
    SELECT
        CASE
            WHEN is_direct = 'true' THEN 'Direct Customer'
            ELSE 'Indirect Customer'
        END AS customer_type,
        CASE
            WHEN person_count BETWEEN 1 AND 10 THEN '1-10 Customers'
            WHEN person_count BETWEEN 11 AND 100 THEN '11-100 Customers'
            WHEN person_count BETWEEN 101 AND 1000 THEN '101-1000 Customers'
            WHEN person_count > 1000 THEN '1000+ Customers'
        END AS person_range,
        SUM(account_count) AS account_count
    FROM adwh_b2b_account_person_association
    WHERE inserted_date = (SELECT MAX(inserted_date) FROM adwh_b2b_account_person_association)
    GROUP BY
        CASE
            WHEN is_direct = 'true' THEN 'Direct Customer'
            ELSE 'Indirect Customer'
        END,
        CASE
            WHEN person_count BETWEEN 1 AND 10 THEN '1-10 Customers'
            WHEN person_count BETWEEN 11 AND 100 THEN '11-100 Customers'
            WHEN person_count BETWEEN 101 AND 1000 THEN '101-1000 Customers'
            WHEN person_count > 1000 THEN '1000+ Customers'
        END
) ap ON cr.customer_type = ap.customer_type AND cr.person_range = ap.person_range
GROUP BY cr.customer_type, cr.person_range
ORDER BY cr.customer_type,
    CASE cr.person_range
        WHEN '1-10 Customers' THEN 1
        WHEN '11-100 Customers' THEN 2
        WHEN '101-1000 Customers' THEN 3
        WHEN '1000+ Customers' THEN 4
    END;

每個客戶的機會概覽 opportunities-per-account-overview

NOTE
此深入分析不受全域日期篩選的影響。

此深入分析所回答的問題:

  • 根據帳戶是否具有相關的商機,帳戶分配情況如何?
選取以顯示產生此深入分析的SQL
code language-sql
WITH LatestDate AS (
    SELECT MAX(inserted_date) AS max_inserted_date
    FROM adwh_b2b_account_opportunity_association
),
CategorizedData AS (
    SELECT
        CASE
            WHEN opportunity_count = 0 THEN 'Accounts without Opportunities'
            WHEN opportunity_count > 0 THEN 'Accounts with Opportunities'
        END AS Opportunity_Category,
        account_count
    FROM adwh_b2b_account_opportunity_association
    WHERE inserted_date = (SELECT max_inserted_date FROM LatestDate)
),
AggregatedData AS (
    SELECT
        Opportunity_Category,
        SUM(account_count) AS Accounts
    FROM CategorizedData
    GROUP BY Opportunity_Category
),
AllCategories AS (
    SELECT 'Accounts without Opportunities' AS Opportunity_Category
    UNION ALL
    SELECT 'Accounts with Opportunities'
)
SELECT
    ac.Opportunity_Category AS Opportunity_Category,
    COALESCE(ad.Accounts, 0) AS Accounts
FROM AllCategories ac
LEFT JOIN AggregatedData ad
    ON ac.Opportunity_Category = ad.Opportunity_Category
ORDER BY ac.Opportunity_Category;

每個客戶的商機詳細資料 opportunities-per-account-detail

NOTE
此深入分析不受全域日期篩選的影響。

此深入分析所回答的問題:

  • 有多少帳戶擁有不同範圍的相關商機?
選取以顯示產生此深入分析的SQL
code language-sql
WITH opportunity_ranges AS (
    SELECT '1-10 Opportunities' AS opportunity_range
    UNION ALL
    SELECT '11-50 Opportunities'
    UNION ALL
    SELECT '51-100 Opportunities'
    UNION ALL
    SELECT '100+ Opportunities'
)
SELECT opportunity_ranges.opportunity_range AS OPPORTUNITIES,
       COALESCE(SUM(accounts.total_accounts), 0) AS ACCOUNTS
FROM opportunity_ranges
LEFT JOIN (
    SELECT
        CASE
            WHEN opportunity_count BETWEEN 1 AND 10 THEN '1-10 Opportunities'
            WHEN opportunity_count BETWEEN 11 AND 50 THEN '11-50 Opportunities'
            WHEN opportunity_count BETWEEN 51 AND 100 THEN '51-100 Opportunities'
            WHEN opportunity_count > 100 THEN '100+ Opportunities'
        END AS opportunity_range,
        SUM(account_count) AS total_accounts
    FROM adwh_b2b_account_opportunity_association
    WHERE inserted_date = (SELECT MAX(inserted_date) FROM adwh_b2b_account_opportunity_association)
      AND opportunity_count > 0
    GROUP BY
        CASE
            WHEN opportunity_count BETWEEN 1 AND 10 THEN '1-10 Opportunities'
            WHEN opportunity_count BETWEEN 11 AND 50 THEN '11-50 Opportunities'
            WHEN opportunity_count BETWEEN 51 AND 100 THEN '51-100 Opportunities'
            WHEN opportunity_count > 100 THEN '100+ Opportunities'
        END
) AS accounts ON opportunity_ranges.opportunity_range = accounts.opportunity_range
GROUP BY opportunity_ranges.opportunity_range
ORDER BY CASE opportunity_ranges.opportunity_range
            WHEN '1-10 Opportunities' THEN 1
            WHEN '11-50 Opportunities' THEN 2
            WHEN '51-100 Opportunities' THEN 3
            WHEN '100+ Opportunities' THEN 4
        END;

後續步驟

閱讀本檔案後,您現在瞭解產生帳戶設定檔儀表板深入分析的SQL,以及此分析解決哪些常見問題。 您現在可以編輯並反複處理SQL,以產生您自己的深入分析。 請參考Query Pro模式概觀,瞭解如何使用SQL產生自訂分析。

您也可以閱讀並瞭解產生設定檔對象目的地儀表板之深入分析的SQL。

recommendation-more-help
ececc77d-ff44-4382-85ee-a087c8834323