sequence

snjpverma

Well-known Member
assuming there is a team of 3 employees named a, b and c who have to be assigned a task as shown below.
They have to be assigned task in the same sequence as it comes. i.e. First task to a, second to b and third to c (the last person), when the fourth file comes it has to be assigned again to "a" and 5 to "b" and so on... please see the below illustration. Any suggestions?
Copy pasting the tasks against each member individually is pretty time consuming when there are more then 30 employees.
The tasks are available in a separate sheet as shown in Sheet 2 below. The tasks doesn't come in one go, it keep adding throughout the day.
suggestions please.
Hint: the Employees names are always in serial order. in the below example I have kept each employees' names 4 times to make it simpler. In actual each employees names are mentioned 20 times (in ascending order).

Sheet 1


EmployeesTasks
a1
a4
a
a
b2
b
b
b
c3
c
c
c

<tbody>
</tbody>




Sheet 2
Tasks
1
2
3
4
5

<tbody>
</tbody>
 

Dr. Demento

Well-known Member
There are some details you haven't covered about the final format you'd like, but here's one solution
The first time a new person's name is listed, hardcode their number (a=1, b=2, c=3, etc). In all the remaining cells, copy this formula:
Code:
=IFERROR(IF($E$1>=B1+$I$1,B1+$I$1,""),"")
Additionally, I created two helper cells:
E1 = Total number of tasks to be completed; alternatively, this could be a formula to count the number of filled in cells on Sheet2 (=COUNTA(B:B), where B is the actual name of the task). If this is the case, any unassigned tasks would need to be kept blank.
I1 = Total number of employees (in your example, 3)

If you're looking for more than a numeric output, you could use an INDEX MATCH formula to show the actual task name listed on Sheet2.
 

MickG

MrExcel MVP
Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG17May43
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Rng2 [COLOR="Navy"]As[/COLOR] Range, Q [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]With[/COLOR] Sheets("Sheet1")
    [COLOR="Navy"]Set[/COLOR] Rng = .Range("A2", .Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
[COLOR="Navy"]If[/COLOR] Not .Exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
    .Add Dn.Value, Array(Dn, 1)
[COLOR="Navy"]Else[/COLOR]
   Q = .Item(Dn.Value)
      [COLOR="Navy"]Set[/COLOR] Q(0) = Union(Q(0), Dn)
  .Item(Dn.Value) = Q
[COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR]

[COLOR="Navy"]With[/COLOR] Sheets("Sheet2")
    [COLOR="Navy"]Set[/COLOR] Rng2 = .Range("A2", .Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]Dim[/COLOR] K [COLOR="Navy"]As[/COLOR] Variant

[COLOR="Navy"]Do[/COLOR] [COLOR="Navy"]While[/COLOR] n <= Rng2.Count
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] K [COLOR="Navy"]In[/COLOR] .keys
        n = n + 1
        Q = .Item(K)
            Q(0)(Q(1)).Offset(, 1).Value = Rng2(n)
        Q(1) = Q(1) + 1
    .Item(K) = Q
[COLOR="Navy"]Next[/COLOR] K
[COLOR="Navy"]Loop[/COLOR]

[COLOR="Navy"]End[/COLOR] With
Regards Mick
 

snjpverma

Well-known Member
thanks Demento for your support. the output is not numeric. It is an alphanumeric combination. Could you help me with the Index Match suggestion?

Thanks MickG for your support. But I am not much into VBA
 

Marcelo Branco

MrExcel MVP
Maybe something like this

Sheet2 (list of tasks)

A
1
Tasks​
2
Task1​
3
Task2​
4
Task3​
5
Task4​
6
Task5​
7
Task6​
8
Task7​
9

Sheet1

A
B
C
D
1
Employees​
Tasks​
Num of Employees​
2
a​
Task1​
3​
3
a​
Task4​
4
a​
Task7​
5
a​
6
b​
Task2​
7
b​
Task5​
8
b​
9
b​
10
c​
Task3​
11
c​
Task6​
12
c​
13
c​
14

Array formula in D2 (count unique of employees)
=SUM(IF(FREQUENCY(IF(A2:A100<>"",MATCH(A2:A100,A2:A100,0)),ROW(A2:A100)-ROW(A2)+1),1))
confirmed with Ctrl+Shift+Enter, not just Enter

Formula in B2 copied down
=IF(A2="","",INDEX(Sheet2!A$2:A$100,D$2*COUNTIF(A$2:A2,A2)-(D$2-1)+SUMPRODUCT(--(A$2:A2<>A$1:A1))-1)&"")

Hope this helps

M.
 

snjpverma

Well-known Member
Hi Marcela,
Your formula works great but I would like to kow why you used the part highlighted in Red at the end.

=IF(A2="","",INDEX(Sheet2!A$2:A$100,D$2*COUNTIF(A$2:A2,A2)-(D$2-1)+SUMPRODUCT(--(A$2:A2<>A$1:A1))-1)&"")
 

Marcelo Branco

MrExcel MVP
I don't remember exactly the logic i used 5 months ago ;) , but &"" avoids results equal to 0 (zero).
Try without &"" and you'll see

M.
 

Some videos you may like

This Week's Hot Topics

  • Importing multiple excel files into one spreadsheet
    Hi, I'm trying to import multiple excel files (with the same format into a single spreadsheet) so that each day's file is listed underneath the...
  • find many based on a certain criteria
    good evening, I hope someone can help me? I have a workbook sheet 2 contains lots of data.... I would like to be able to find anything on sheet...
  • How to copy multiple rows using If
    Hi all, I'm very new to VBA and have written this simple code to copy certain cells if a certain cell within that row contains any data. I need...
  • VBA If statement
    Dear All, I have two dates, where I'd like a message box to pop, if the dates are between this criteria. [CODE] sDate1 = #10/1/2019#...
  • Text Format
    I have a sheet for user to keyin the data. The format of the data can be 451 / 1903, 0012 / 9908 or 00287 / 0099. The number after the "/" is...
  • Syntax errors
    Good Morning, Trying to compile a workbook, I keep getting a few errors. Here are the first two: [code=rich]Syntax Error: Function...
Top