+ Reply to Thread
Results 1 to 13 of 13

Problem with postcodes and sales for multiple locations

  1. #1
    Registered User
    Join Date
    08-08-2020
    Location
    UK
    MS-Off Ver
    16.39 (Mac user)
    Posts
    6

    Unhappy Problem with postcodes and sales for multiple locations

    Hi guys,

    I came across this problem today and I'm not sure how to solve it..I'm sure this is easy for you but I'm a beginner so this is really stressing me out

    I have two tabs which include:

    1: Sales dates, postcodes and number of sales

    2: postcodes, store number, store names

    Each postcodes is associated with a certain store number and store numbers are associated with a store name.

    Now....

    1)How do I get total number of sales per store (name)?

    2)How do I calculate which two months had the highest volume of sales taking only into consideration stores that had sales from September onwards? (and excluding stores which are not associate with a postcode)?

    3) How do I figure out which store had the fastest growth?


    Number 1 and 2 are giving me more headaches...I tried to look online but I cannot find a solution


    I really appreciate your help !!!!
    Attached Files Attached Files

  2. #2
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2404 Win 11 Home 64 Bit
    Posts
    23,870

    Re: Problem with postcodes and sales for multiple locations

    crossposted: https://www.mrexcel.com/board/thread...s-etc.1142419/

    Rule 03: Cross-posting Without Telling Us

    Your post does not comply with Rule 3 of our Forum RULES. Do not cross-post your question on multiple forums without telling us about your threads on other forums.

    Post a link to any other forums where you have asked the same question.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Read this to understand why we ask you to do this.

    I have added the crosspost reference for you today. Please comply with this and all our rules in the future
    Alan עַם יִשְׂרָאֵל חַי


    Change an Ugly Report with Power Query
    Database Normalization
    Complete Guide to Power Query
    Man's Mind Stretched to New Dimensions Never Returns to Its Original Form

  3. #3
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Problem with postcodes and sales for multiple locations

    Try this Array Formula to get total sales,

    =SUM(SUMIF('Data set'!B:B,IF(B$2:B$1696=D2,A$2:A$1696),'Data set'!C:C))

    In the 2nd, please clarify what do you mean by sales from September onwards.
    Regards,
    Haseeb Avarakkan

    __________________________________
    "Feedback is the breakfast of champions"

  4. #4
    Registered User
    Join Date
    08-08-2020
    Location
    UK
    MS-Off Ver
    16.39 (Mac user)
    Posts
    6

    Re: Problem with postcodes and sales for multiple locations

    Sorry Alan, it's a rookie mistake! I'll be more careful in the future

  5. #5
    Registered User
    Join Date
    08-08-2020
    Location
    UK
    MS-Off Ver
    16.39 (Mac user)
    Posts
    6

    Re: Problem with postcodes and sales for multiple locations

    HI Hasseb,

    thank you very much for your reply.
    -The formula returns 0, am I missing something?
    - Some store open after September. I need to calculate the two months with higher sales taking into consideration only stores that were open since September .

  6. #6
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Problem with postcodes and sales for multiple locations

    Hello Silverboy,

    This is an array formula (**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself)).

    2) ...so do you you want excel to look since 2019 Sep - 2020 Aug? also are the dates exactly in your data sheet or is it real date & formatted as yyyy-mm?

  7. #7
    Registered User
    Join Date
    08-08-2020
    Location
    UK
    MS-Off Ver
    16.39 (Mac user)
    Posts
    6

    Re: Problem with postcodes and sales for multiple locations

    Apologies Haseeb, I'm a noob

    1 )I tried to copy and paste and type Command + Return on a Mac but the result it's still 0

    2) Excluding new stores launched 2019, i.e., taking only stores that were active since September 2018, I need to know which two months had the highest volume of sales

  8. #8
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2404 Win 11 Home 64 Bit
    Posts
    23,870

    Re: Problem with postcodes and sales for multiple locations

    Look at the attached and advise if this is the direction you wish to go. It is completed by merging (joining) the files in Power Query and then grouping them to meet requirements.

    EDIT: Just read in your latest post that you are on a MAC. My solution will not work for you. Power Query is not an option on a MAC. Please update your profile to indicate that you are running Excel on a MAC and the version number so that helpers do not waste time on a solution that will not be appropriate for you. Not all versions of excel offer the same features.
    Attached Files Attached Files
    Last edited by alansidman; 08-08-2020 at 11:47 AM.

  9. #9
    Registered User
    Join Date
    08-08-2020
    Location
    UK
    MS-Off Ver
    16.39 (Mac user)
    Posts
    6

    Re: Problem with postcodes and sales for multiple locations

    Thank you for trying...seems like my version if Excel and using Mac makes solving this problem even more complicated...

    Any help is appreciated

  10. #10
    Forum Expert
    Join Date
    10-15-2018
    Location
    MA, USA
    MS-Off Ver
    2010, 2019
    Posts
    1,616

    Re: Problem with postcodes and sales for multiple locations

    Just an observation: the key connecting the two worksheets is "postcode", but there are no instances in the "DataSet" worksheet of postcodes beginning with "BT", whereas the first 40 rows of the "Lookup" worksheet have only postcodes beginning with "BT". So if you had pasted Haseeb's post #3 formula into Lookup!F2 and on down then the fact that it returns zero is the correct result. If I write "KT12" to Lookup!A2, then Haseeb's formula returns 56 which I think is the correct answer.

    Perhaps a more representative sample workbook would help? - see the instructions in the yellow banner at the top of this window.

  11. #11
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Problem with postcodes and sales for multiple locations

    Formulas are applying in Lookup tab and all are Array Formulas.

    F2,

    =SUM(SUMIF('Data set'!B:B,IF(B$2:B$1696=D2,A$2:A$1696),'Data set'!C:C))

    G2,

    =IF(F2,INDEX(TEXT(date(2018,9,1)+{1;2;3;4}*29,"yyyy-mm"),MATCH(1,FREQUENCY(0,1/(MMULT(SUMIFS('Data set'!C:C,'Data set'!B:B,TRANSPOSE(IF(B$2:B$1696=D2,A$2:A$1696)),'Data set'!A:A,TEXT(date(2018,9,1)+{1;2;3;4}*29,"yyyy-mm")),ROW(B$2:B$1696)^0)+ROW(A$2:A$1696)/1000000)),0)),"")

    then copy down.

    G2 formula will look this way.

    If month is in 2018-09, 2018-10, 2018-11, 2018-12
    Postcodes are from associated store #

    Attached is the file.

  12. #12
    Registered User
    Join Date
    08-08-2020
    Location
    UK
    MS-Off Ver
    16.39 (Mac user)
    Posts
    6

    Re: Problem with postcodes and sales for multiple locations

    Hi Haseeb,

    thank you for your help, that's great. How do I calculate the second largest month thought?

    On a side note, I also need to figure out the growth of all store, from 2018 to 2019 (so the entire date range of datas)
    I guess I need to figure out the sales of the first month of 2018 and last month of 2019 per store first, but I'm not sure how to do that...
    Any help?

  13. #13
    Forum Expert bebo021999's Avatar
    Join Date
    07-22-2011
    Location
    Vietnam
    MS-Off Ver
    Excel 2016
    Posts
    9,463

    Re: Problem with postcodes and sales for multiple locations

    Here's my solution;
    Sheet Dataset: Column D and E is lookup store # and month convert to real 1st dys of month-year
    Sheet Lookup
    From F to AE is every month sales from month to month given in G1 and I1
    AG to AQ is rank of monthly sales from 1st to, i.e, 5th
    See attachment.
    Attached Files Attached Files
    Quang PT

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. [SOLVED] Q: Enter ID Value and Return the SUM of all ID sales (multiple sales entries)?
    By svance in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 10-07-2019, 01:12 AM
  2. [SOLVED] Merging 2 tables to track Employee sales during different periods and locations
    By naira in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 01-10-2018, 06:33 AM
  3. [SOLVED] sumif using multiple sales locations
    By makinmomb in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 02-06-2016, 03:08 AM
  4. Replies: 1
    Last Post: 06-09-2015, 09:30 AM
  5. [SOLVED] Problem with the getting all locations sales using iferror, index, match
    By brandedadnan in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 12-10-2013, 03:14 AM
  6. Replies: 2
    Last Post: 06-19-2012, 10:19 AM
  7. String problem - UK postcodes
    By EdMac in forum Excel General
    Replies: 5
    Last Post: 02-16-2007, 08:08 AM

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1