I think John is correct in his comments except I am making the assumption the
ID is a SampleID and not StoreID. Based on that I built some queries for you
but left your field names the same.
Link the Excel file and name it StoreSample.
Use the first query to build a table (Make Table Query), naming it
SampleInfo, and limit number of records to one (click on the window on the
icon tool bar that says “All†and change it to 1 (one). Open the table in
design view and make the ID a key field by clicking on the icon the looks
like a yellow key – save. Then append the data. Never mind the error message
that it did not append records due to key violation as they are duplicates
and are not used in this table.
StoreSampleAppend --
INSERT INTO SampleInfo ( [ID#], Sector, [Date], Store, Address, Phone, Area,
ZIP, [Signer/Mgr], Inspector, Items, [Total $], [# +], [# -], [$ +], [$ -],
Comments, [Error %] )
SELECT StoreSample.[ID#], StoreSample.Sector, StoreSample.Date,
StoreSample.Store, StoreSample.Address, StoreSample.Phone, StoreSample.Area,
StoreSample.ZIP, StoreSample.[Signer/Mgr], StoreSample.Inspector,
StoreSample.Items, StoreSample.[Total $], StoreSample.[# +], StoreSample.[#
-], StoreSample.[$ +], StoreSample.[$ -], StoreSample.Comments,
StoreSample.[Error %]
FROM StoreSample;
SampleDataTable --
SELECT TOP 1 StoreSample.[ID#], 1 AS Item, StoreSample.[Shelf-1] AS Shelf,
StoreSample.[Scan-1] AS Scan INTO SampleData
FROM StoreSample;
Open the SampleData table and delete all records. Open the SampleData table
in design view and hightlight ID# and Items, click the key icon and save.
Make this query --
SampleCount --
SELECT SampleData.[ID#], Max(SampleData.Item) AS MaxOfItem
FROM SampleData
GROUP BY SampleData.[ID#];
This query will append the first set of data.
SampleDataAppend --
INSERT INTO SampleData ( [ID#], Item, Shelf, Scan )
SELECT StoreSample.[ID#], 1 AS Item, StoreSample.[Shelf-1],
StoreSample.[Scan-1]
FROM StoreSample;
Make 37 queries like this. The difference is the Shelf/Scan column number.
That number also is calculated into the Item number.
(Int([MaxOfItem]/37)*37)+1
SampleDataAppend-1
INSERT INTO SampleData ( [ID#], Item, Shelf, Scan )
SELECT StoreSample.[ID#], (Int([MaxOfItem]/37)*37)+1 AS Item,
StoreSample.[Shelf-1], StoreSample.[Scan-1]
FROM StoreSample INNER JOIN SampleCount ON StoreSample.[ID#] =
SampleCount.[ID#];
SampleDataAppend-2
INSERT INTO SampleData ( [ID#], Item, Shelf, Scan )
SELECT StoreSample.[ID#], (Int([MaxOfItem]/37)*37)+2 AS Item,
StoreSample.[Shelf-2], StoreSample.[Scan-2]
FROM StoreSample INNER JOIN SampleCount ON StoreSample.[ID#] =
SampleCount.[ID#];
SampleDataAppend-3
INSERT INTO SampleData ( [ID#], Item, Shelf, Scan )
SELECT StoreSample.[ID#], (Int([MaxOfItem]/37)*37)+3 AS Item,
StoreSample.[Shelf-3], StoreSample.[Scan-3]
FROM StoreSample INNER JOIN SampleCount ON StoreSample.[ID#] =
SampleCount.[ID#];
Using 37 Shelf/Scan in each Excel row use two rows plus 26 on the third row
to equal 100 items.
The append queries will need to be run 3 times.
John Nurick said:
A couple of questions:
1) Which of the first 18 fields are actually required to identify an
individual row (rather than just being useful for sorting and grouping
the data)? For example, each store presumably keeps its address, Zip
code, and area. Does the ID number provide this unique identifier?
2) It sounds as if the 37 pairs of results columns all refer to the same
kind of result but on different tills, or different sections of the
store, or something like that. Do these things have names, or are they
referred to by numbers 1 to 37?
What I'm thinking is that you need to normalise the data into three,
four or more Access tables. Note that I've used field names with no
special characters:
Stores
(one record per store, with fields such as)
Store (e.g. Walgreeen #2120) - primary key
Sector
Address
Area
Zip
Phone
DataReturns
(one record for each row in the Excel data)
ID (same as ID# in the Excel data) - primary key
Store - foreign key into Stores table
DateOfReturn
Signer_Mgr
Inspector
Items
AmtTotal
NumberOver
NumberUnder
AmtOver
AmtUnder
Comments
ErrorPercentage
XXX
(I don't know what to call this table. It needs to
contain a list of the 37 different things to which the
37 Shelf/Scan pairs refer)
XXXName - primary key
DataItems
(one record for each Shelf/Scan pair in each DataReturn)
ID - foreign key into DataReturns table
XXXName - foreign key into DataItems table
(primary key consists of ID, XXXName)
Shelf - amount from the relevant Excel column
Scan - ditto
A structure like that will allow very sophisticated querying and
totalling of the data.
As for actually importing it, the general idea is to link to or import
the Excel data as is, and then use a series of append queries to move
the data into the Access tables. Life will be simpler if you can change
the Excel column headings into unique, legal Access field names.