1
+ // RawExcel
2
+ let
3
+ // table layout from the question: https://www.reddit.com/r/PowerBI/comments/1echatp/best_way_to_ingest_data_from_excel_with_varying/
4
+ Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjbQMzFW0lEyNtGztATSJiC2oYkpkLK0NDIG0aZm5kDSSM8QrE4PpEIpNhYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Jan - Plan" = _t, #"Jan - Actual" = _t, Variance = _t, #"Feb - Plan" = _t, #"Feb - Actual" = _t, Variance2 = _t, Mar = _t, Apr = _t, May = _t]),
5
+ #"Changed Type" = Table.TransformColumnTypes(Source,{
6
+ {"Jan - Plan", type number}, {"Jan - Actual", type number}, {"Variance", Int64.Type},
7
+ {"Feb - Plan", Int64.Type}, {"Feb - Actual", Int64.Type}, {"Variance2", Int64.Type},
8
+ {"Mar", type number}, {"Apr", type number}, {"May", type text}})
9
+ in
10
+ #"Changed Type"
11
+
12
+ // SplitTermsTable
13
+ let
14
+ readme = "
15
+ question: <https://www.reddit.com/r/PowerBI/comments/1echatp/best_way_to_ingest_data_from_excel_with_varying/>
16
+
17
+ their example input table:
18
+
19
+ | Jan - Plan | Jan - Actual | Variance | Feb - Plan | Feb - Actual | Variance2 | Mar | Apr | May |
20
+ |:----------: |:------------: |:--------: |:----------: |:------------: |:---------: |:----: |:---: |:---: |
21
+ | 30.43 | 34.99 | 4 | 3145 | 99235 | 567 | 2.13 | 3.4 | |
22
+
23
+ Split terms output: I made it output extra columns so that you can see how it's evaluated each step of the way
24
+
25
+ | RawName | Crumbs | Name | Type | Kind | MonthAsDate | AsMonth |
26
+ |:------------: |:------: |:---------: |:------: |:--------: |:-----------: |:-------: |
27
+ | Jan - Plan | [List] | Jan | Plan | Month | 2024-01-01 | 1 |
28
+ | Jan - Actual | [List] | Jan | Actual | Month | 2024-01-01 | 1 |
29
+ | Variance | [List] | Variance | null | Variance | null | null |
30
+ | Feb - Plan | [List] | Feb | Plan | Month | 2024-02-01 | 2 |
31
+ | Feb - Actual | [List] | Feb | Actual | Month | 2024-02-01 | 2 |
32
+ | Variance2 | [List] | Variance2 | null | Variance | null | null |
33
+ | Mar | [List] | Mar | null | Variance | 2024-03-01 | 3 |
34
+ | Apr | [List] | Apr | null | Variance | 2024-04-01 | 4 |
35
+ | May | [List] | May | null | Variance | 2024-05-01 | 5 |
36
+
37
+ ",
38
+ Source = Table.ColumnNames( RawExcel ),
39
+ SplitCol = ( source as text ) => [
40
+ RawName = source,
41
+ Crumbs = Text.Split( source, "-" ),
42
+ Name = Text.Trim( Crumbs{0}? ),
43
+ Type = Text.Trim( Crumbs{1}? ),
44
+ Kind =
45
+ if Type <> null and not Text.Contains( Type, "Variance", Comparer.OrdinalIgnoreCase )
46
+ then "Month" else "Variance",
47
+ MonthAsDate =
48
+ try Date.FromText( Name, [
49
+ Format = "MMM", Culture = "en-US"] )
50
+ catch (e) =>
51
+ null,
52
+
53
+ AsMonth = Date.Month( MonthAsDate )
54
+ ],
55
+ ColInfoList = List.Transform( Source, each SplitCol(_) ),
56
+ schema = type table [
57
+ RawName = nullable text,
58
+ Crumbs = (type nullable { text } ),
59
+ Name = nullable text,
60
+ Type = nullable text,
61
+ Kind = nullable text,
62
+ MonthAsDate = nullable date,
63
+ AsMonth = nullable number
64
+ ],
65
+ Final = Table.FromRecords( ColInfoList, schema, MissingField.UseNull )
66
+ in
67
+ Final
0 commit comments