SELECTCOLUMNS https://interactivechaos.ovh/en en Cálculo del número de días entre compras https://interactivechaos.ovh/es/dax/scenario/calculo-del-numero-de-dias-entre-compras <span class="field field--name-title field--type-string field--label-hidden">Calculation of the number of days between purchases</span> <span class="field field--name-uid field--type-entity-reference field--label-hidden"><span lang="" about="/en/user/1" typeof="schema:Person" property="schema:name" datatype="">admin</span></span> <span class="field field--name-created field--type-created field--label-hidden">Tue, 07/02/2019 - 16:23</span> <div class="clearfix text-formatted field field--name-body field--type-text-with-summary field--label-hidden field__item"><p>We start from a list of sales (<span class="code">Sales</span>) in which, for example, the customer identifier and the dates of the purchases are indicated:</p> <img alt="Starting data" data-entity-type="file" data-entity-uuid="6e7ea336-e513-4349-a3ec-f7cc14d9cd1b" src="/sites/default/files/inline-images/escenario-dax-0042.png" class="align-center" width="238" height="198" loading="lazy" /><p>The objective is to add to this table a column that indicates the number of days elapsed since the previous purchase (earlier in time, since nothing assures us that the order of the data in the original table is chronological, and we already know that Power BI neither ensures the order of the rows).</p> <p>The resolution of this scenario is not easy. Although it could be solved in a single expression, its resolution is presented below step by step. The phases involved are the following:</p> <ol><li>It is necessary to obtain, for each purchase date of customer X, the date of the previous purchase.</li> <li>The previous purchase date is the highest date of all customer X's purchases (except for the purchase we are analyzing, of course).</li> <li>We can obtain all the previous purchases of customer X by cross-joining the table with itself, taking as common field the one corresponding to the customer's identifier and considering in the right table (see the documentation of the <a href="/en/dax/function/generate">GENERATE</a> function) only the dates before the purchase date being considered in the left table. Thus, for example, for the purchase that appears in the third line of the previous image (corresponding to customer 1, dated January 21, 2019), a cross joining with the same table in the aforementioned conditions would return a row for the combination of row 3 and row 1 (same customer and previous date) and another for the combination of row 3 and row 2 (again, same customer and previous date).</li> </ol><p>Finally, once the table mentioned in point 1 has been obtained, it would be enough to calculate the difference between each purchase date and the date of the last purchase.</p> <p>Let's do it step by step.</p> <p>First we want to obtain, for each row (that is, for each purchase), the set of previous purchases of the same customer. This, as mentioned, can be achieved with a cross join that allows us to specify the conditions of the join, that is, with the <a href="/en/dax/function/generate">GENERATE</a> function. As this function requires that the tables involved in the combination have fields with different names, we are going to modify the names of the fields of the second copy with the <a href="/en/dax/function/selectcolumns">SELECTCOLUMNS</a> function, adding a "_" symbol at the end of the names:</p> <div class="codigo"> <p>SelfJoin = <br />     GENERATE(<br />         Sales;<br />         FILTER(<br />             SELECTCOLUMNS(<br />                 Sales;<br />                 "Customer_"; Sales[Customer];<br />                 "Purchase Date_"; Sales[Purchase Date]<br />             );<br />             [Purchase Date_] &lt; Sales[Purchase Date] &amp;&amp; Sales[Customer] = [Customer_]<br />         )<br />     )<sales></sales></p> </div> <img alt="Self-join using the row context created by the GENERATE function" data-entity-type="file" data-entity-uuid="61138555-e1c0-45a5-9bbb-dcefc4489cf9" src="/sites/default/files/inline-images/escenario-dax-0044.png" class="align-center" width="670" height="514" loading="lazy" /><p>As we can see, we are obtaining the cross join by imposing the condition that the customer identifier is the same, and that the dates in the column on the right are lower than the date considered in each of the rows on the left (for simplicity, we are assuming that the same customer will not make two purchases on the same day).</p> <p>Note that the records in the first table for which there are no records in the second that meet the imposed conditions do not appear (that is, in the table that we have just created, only purchase dates for which there is a previous purchase are included).</p> <p>Obtaining, from here, the date before each purchase is easy: just group (with the <a href="/en/dax/function/groupby">GROUPBY</a> function) by customer and purchase date (<em>Customer</em> and <em>Purchase Date</em> fields) and select the maximum value (of each group) of the field <em>Purchase Date_</em> :</p> <div class="codigo"> <p>LastPurchases = <br />     GROUPBY(<br />         SelfJoin;<br />         SelfJoin[Customer];<br />         SelfJoin[Purchase Date];<br />         "Last Purchase"; MAXX(<br />                             CURRENTGROUP();<br />                             SelfJoin[Purchase Date_]<br />                         )<br />     )</p> </div> <img alt="Table with the dates of the last purchase" data-entity-type="file" data-entity-uuid="c7517dfc-1136-438b-b5c4-736188acc9ea" src="/sites/default/files/inline-images/escenario-dax-0045.png" class="align-center" width="459" height="348" loading="lazy" /><p>Now comes a somewhat complicated process: as the table only includes purchase dates for which there is a previous purchase, if we want all the original dates to appear in the final result we would have to perform a left outer join between the original date table and the new one. For this we would have to use the <a href="/en/dax/function/naturalleftouterjoin">NATURALLEFTOUTERJOIN</a> function, but this function requires that the tables to be joined have the same lineage (they come from the same source), which is not true in our case. As explained in the <a href="/en/dax/function/naturalleftouterjoin">documentation for this function</a>, it is possible to solve this problem by adding an empty text string to the end of the names:</p> <div class="codigo"> <p>Purchase and Last Purchase = <br />     NATURALLEFTOUTERJOIN(<br />         SELECTCOLUMNS(<br />             Sales;<br />             "Customer"; Sales[Customer] &amp; "";<br />             "Purchase Date"; Sales[Purchase Date] &amp; ""<br />         );<br />         SELECTCOLUMNS(<br />             LastPurchases;<br />             "Customer"; LastPurchases[SelfJoin_Customer] &amp; "";<br />             "Purchase Date"; LastPurchases[SelfJoin_Purchase Date] &amp; "";<br />             "Last Purchase"; LastPurchases[Last Purchase]<br />         )<br />     )</p> </div> <img alt="Initial table including the date of the last purchase (if any)" data-entity-type="file" data-entity-uuid="bd8c8912-3173-4504-886e-057331c10f2a" src="/sites/default/files/inline-images/escenario-dax-0046.png" class="align-center" width="590" height="461" loading="lazy" /><p>Finally, to calculate the number of days since the last purchase, simply add a new column that returns the difference (only if there is a last purchase):</p> <div class="codigo"> <p>Days since last purchase = <br />     ADDCOLUMNS(<br />         'Purchase and Last Purchase';<br />         "# days";<br />             VAR<br />                 NumberOfDays =<br />                     'Purchase and Last Purchase'[Purchase Date] - <br />                     'Purchase and Last Purchase'[Last Purchase]<br />             RETURN<br />                 IF(<br />                     ISBLANK('Purchase and Last Purchase'[Last Purchase]);<br />                     BLANK();<br />                     NumberOfDays<br />                 )<br />     )</p> </div> <img alt="Final table showing the number of days since the last purchase" data-entity-type="file" data-entity-uuid="98f6ede6-aae6-4e3b-89fa-9826e897310c" src="/sites/default/files/inline-images/escenario-dax-0047.png" class="align-center" width="595" height="479" loading="lazy" /><p>To return the day difference, we use the <a href="/en/dax/function/if">IF</a> function to confirm if the value of the field corresponding to the last purchase is a BLANK or not, for which we use the <a href="/en/dax/function/isblank">ISBLANK</a> function.</p> </div> <div class="field field--name-field-funciones-dax-involucradas field--type-entity-reference field--label-above"> <div class="field__label">DAX functions involved</div> <div class="field__items"> <div class="field__item"><a href="/es/taxonomy/term/79" hreflang="es">GENERATE</a></div> <div class="field__item"><a href="/es/taxonomy/term/69" hreflang="es">SELECTCOLUMNS</a></div> <div class="field__item"><a href="/es/taxonomy/term/48" hreflang="es">FILTER</a></div> <div class="field__item"><a href="/es/taxonomy/term/60" hreflang="es">GROUPBY</a></div> <div class="field__item"><a href="/es/taxonomy/term/39" hreflang="es">MAXX</a></div> <div class="field__item"><a href="/es/taxonomy/term/82" hreflang="es">CURRENTGROUP</a></div> <div class="field__item"><a href="/es/taxonomy/term/83" hreflang="es">NATURALLEFTOUTERJOIN</a></div> <div class="field__item"><a href="/es/taxonomy/term/68" hreflang="es">VAR</a></div> <div class="field__item"><a href="/es/taxonomy/term/29" hreflang="es">IF</a></div> <div class="field__item"><a href="/es/taxonomy/term/56" hreflang="es">ISBLANK</a></div> <div class="field__item"><a href="/es/taxonomy/term/31" hreflang="es">BLANK</a></div> <div class="field__item"><a href="/es/taxonomy/term/84" hreflang="es">ADDCOLUMNS</a></div> </div> </div> <div class="field field--name-field-dax-esc-dificultad field--type-list-string field--label-above"> <div class="field__label">Difficulty</div> <div class="field__item">High</div> </div> Tue, 02 Jul 2019 14:23:33 +0000 admin 1147 at https://interactivechaos.ovh Agregación de dos tablas con la misma estructura https://interactivechaos.ovh/es/dax/scenario/agregacion-de-dos-tablas-con-la-misma-estructura <span class="field field--name-title field--type-string field--label-hidden">Aggregation of two tables with the same structure</span> <span class="field field--name-uid field--type-entity-reference field--label-hidden"><span lang="" about="/en/user/1" typeof="schema:Person" property="schema:name" datatype="">admin</span></span> <span class="field field--name-created field--type-created field--label-hidden">Wed, 04/10/2019 - 10:58</span> <div class="clearfix text-formatted field field--name-body field--type-text-with-summary field--label-hidden field__item"><p>A frequent and easy to solve scenario is one in which we find ourselves with two tables with the same structure that we want to add according to some field. Let's see what it would be like. We assume that we have already obtained the data and we have loaded in Power BI the two tables that, in this case, contain sales information:</p> <img alt="Table 1" data-entity-type="file" data-entity-uuid="46d7b1ed-8bab-4fc1-8789-cbe6657b8ca5" src="/sites/default/files/inline-images/escenario-dax-0010.PNG" class="align-center" width="690" height="158" loading="lazy" /><img alt="Table 2" data-entity-type="file" data-entity-uuid="5c8295a5-d833-4a35-bf57-35e69a3f3cff" src="/sites/default/files/inline-images/escenario-dax-0011.PNG" class="align-center" width="698" height="157" loading="lazy" /><p>In this scenario we want to get the total sales by seller ("<em>Id Vendedor</em>" field). We are going to do it in two phases:</p> <ol><li>Union of the previous tables</li> <li>Aggregation of the complete table to show the sales ("<i>Precio final</i>" field) according to the field that identifies each seller</li> </ol><p>For the first step we are going to use the <a href="/en/dax/function/union">UNION</a> function. However, we are not going to join the tables directly because, as we see in the previous images, despite having the same structure (and, in the query editor, appearing with the columns in the same order) when imported into Power BI columns are not displayed in the same order (probably due to a software <em>bug</em> that has been around since at least late 2017). That is why we are going to apply the UNION function to the tables, specifying by hand the columns that interest us and the order that interests us, for which we will resort to the <a href="/en/dax/function/selectcolumns">SELECTCOLUMNS</a> function:</p> <div class="codigo"> <p>Ventas totales = <br />     VAR<br />         Tabla1 = SELECTCOLUMNS(<br />             Ventas1;<br />             "Vendedor"; Ventas1[Id Vendedor];<br />             "PVP"; Ventas1[Precio final]<br />         )<br />     VAR<br />         Tabla2 = SELECTCOLUMNS(<br />             Ventas2;<br />             "Vendedor"; Ventas2[Id Vendedor];<br />             "PVP"; Ventas2[Precio final]<br />         )<br />     RETURN<br />         UNION(Tabla1; Tabla2)</p> </div> <img alt="Total sales" data-entity-type="file" data-entity-uuid="2e9813ee-d18b-47e7-bc9f-46a4586d92a6" src="/sites/default/files/inline-images/escenario-dax-0012.PNG" class="align-center" width="164" height="282" loading="lazy" /><p>We have only selected the columns "<em>Vendedor</em>" ("<em>seller</em>") and "<em>Precio final</em>" ("<em>Final price</em>", with the name "<em>PVP</em>") but we could have selected other columns as well.</p> <p>Now, for the second step, we use the <a href="/en/dax/function/summarize">SUMMARIZE</a> function to add the above table:</p> <div class="codigo"> <p>Ventas totales por vendedor = <br />     SUMMARIZE(<br />         'Ventas totales';<br />         'Ventas totales'[Vendedor];<br />         "Ventas"; SUM('Ventas totales'[PVP]<br />         )<br />     )</p> </div> <img alt="Table of sales aggregated by seller" data-entity-type="file" data-entity-uuid="44dad59e-f058-470f-9c22-ceb2790c4512" src="/sites/default/files/inline-images/escenario-dax-0013.PNG" class="align-center" width="163" height="94" loading="lazy" /></div> <div class="field field--name-field-funciones-dax-involucradas field--type-entity-reference field--label-above"> <div class="field__label">DAX functions involved</div> <div class="field__items"> <div class="field__item"><a href="/es/taxonomy/term/75" hreflang="es">UNION</a></div> <div class="field__item"><a href="/es/taxonomy/term/69" hreflang="es">SELECTCOLUMNS</a></div> <div class="field__item"><a href="/es/taxonomy/term/51" hreflang="es">SUMMARIZE</a></div> <div class="field__item"><a href="/es/taxonomy/term/28" hreflang="es">SUM</a></div> </div> </div> <div class="field field--name-field-dax-esc-dificultad field--type-list-string field--label-above"> <div class="field__label">Difficulty</div> <div class="field__item">Intermediate</div> </div> Wed, 10 Apr 2019 08:58:12 +0000 admin 1046 at https://interactivechaos.ovh