Solved Comparison with non-matches in query (1 Viewer)

spike_access

New member
Local time
Today, 17:27
Joined
Mar 22, 2022
Messages
14
Hi,

I have a very specific query that I want run in order to identify mismatches.
The comparison is to be performed between two tables; tblContentTracker and tblMeta.

The key between tblContentTracker and tblMeta is the field MetaID/Meta ID and the comparison should be done between the edit level ID and compliance fields from tblContentTracker and the relevant compliance field from tblMeta. And here is where it becomes way to complicated for a simple minded hobbyist like me.

Every record in tblContentTracker has a specific compliance and edit level ID. However, the tblMeta table contains all possible compliance versions as a unique field (simply because a meta record can contain multiple compliances, but only one edit level ID per compliance) which holds the edit level ID valid for that compliance.

The end result I'm after is a query that identifies where;
  • Assigned compliance in tblContentTracker has another edit level ID on the compliance in tblMeta
  • Assigned edit level ID in tblContentTracker has another compliance with that edit level ID in tblMeta
  • Assigned edit level ID in tblContentTracker doesn't exist at all in tblMeta
  • Assigned compliance in tblContentTracker doesn't have an edit level ID on the compliance in tblMeta
So basically, any other scenario than a full match ([tblContentTracker.Edit level ID] and [tblContentTracker.Compliance] exactly the same as in tblMeta).

Have attached an Excel file with example data split up in three sheets;
  • tblContentTracker
  • tblMeta
  • Query results
    • Shows the expected outcome of the comparison between the two previous sheets
This is most likely not the best setup data wise, but just as in many other cases I just have to accept the output :-(
Will highly appreciate any suggestions on how to perform this exercise.

Best
 

Attachments

  • compliance validation.zip
    8.2 KB · Views: 172

MajP

You've got your good things, and you've got mine.
Local time
Today, 11:27
Joined
May 21, 2018
Messages
8,527
Make a union query to normalize your data
Code:
SELECT tblMeta.[Meta ID], "HUGM" AS Compliance, tblMeta.HUGM AS EditLevelID
FROM tblMeta
WHERE Not tblMeta.HUGM Is Null
UNION
SELECT tblMeta.[Meta ID], "CEGM" AS CompType, tblMeta.CEGM AS Compliance
FROM tblMeta
WHERE Not tblMeta.CEGM Is Null
UNION
SELECT tblMeta.[Meta ID], "NDGM" AS CompType, tblMeta.NDGM AS Compliance
FROM tblMeta
WHERE Not tblMeta.NDGM Is Null
UNION SELECT tblMeta.[Meta ID], "SPGM" AS CompType, tblMeta.SPGM AS Compliance
FROM tblMeta
WHERE Not tblMeta.SPGM Is Null
ORDER BY 1, 2, 3;

Then you can do whatever you want.
qryCompliance

qryCompliance qryCompliance

Meta IDComplianceEditLevelID
EP000012CEGM123456
EP000012NDGMHBON-ABCDE
EP001256CEGM456123
EP001256HUGM456321
FE000125CEGM654132
FE000125HUGM654133
FE000125SPGMHBOE-AADGT
SP000016NDGM165324
SP000016SPGMHBON-ACCYU
 
Last edited:

MajP

You've got your good things, and you've got mine.
Local time
Today, 11:27
Joined
May 21, 2018
Messages
8,527
So using the union you can build QryAll to answer all your questions.
Code:
SELECT tblcontenttracker.unique,
       tblcontenttracker.[edit level id],
       tblcontenttracker.compliance,
       qrycompliance.editlevelid AS MetaEditLevelID,
       qrycompliance.compliance  AS MetaCompliance,
       tblcontenttracker.metaid
FROM   tblcontenttracker
       LEFT JOIN qrycompliance
              ON tblcontenttracker.metaid = qrycompliance.[meta id]
ORDER  BY tblcontenttracker.unique,
          tblcontenttracker.[edit level id],
          tblcontenttracker.compliance;

qryAllData qryAllData

UniqueEdit level IDComplianceMetaEditLevelIDMetaComplianceMetaID
Hungary-74851456123HUGM456123CEGMEP001256
Hungary-74851456123HUGM456321HUGMEP001256
Nordic-16875HBON-ACCYUNDGM165324NDGMSP000016
Nordic-16875HBON-ACCYUNDGMHBON-ACCYUSPGMSP000016
Romania-14578123456CEGM123456CEGMEP000012
Romania-14578123456CEGMHBON-ABCDENDGMEP000012
Spain-87413125634SPGM654132CEGMFE000125
Spain-87413125634SPGM654133HUGMFE000125
Spain-87413125634SPGMHBOE-AADGTSPGMFE000125
 
Last edited:

MajP

You've got your good things, and you've got mine.
Local time
Today, 11:27
Joined
May 21, 2018
Messages
8,527
Example where Compliance = metaCompliance and EditLevelID <> MetaEditLevelID, which I believe is the query results you want.

Code:
SELECT qryalldata.unique,
       qryalldata.[edit level id],
       qryalldata.compliance,
       qryalldata.metaeditlevelid,
       qryalldata.metacompliance,
       qryalldata.metaid
FROM   qryalldata
WHERE  ( ( ( qryalldata.[edit level id] ) <> [metaeditlevelid] )
         AND ( ( qryalldata.metacompliance ) = [compliance] ) );

Query1 Query1

UniqueEdit level IDComplianceMetaEditLevelIDMetaComplianceMetaID
Hungary-74851456123HUGM456321HUGMEP001256
Nordic-16875HBON-ACCYUNDGM165324NDGMSP000016
Spain-87413125634SPGMHBOE-AADGTSPGMFE000125
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 23:27
Joined
May 7, 2009
Messages
19,230
i created a function again and call it in Query1.
 

Attachments

  • anotherCompliance.accdb
    532 KB · Views: 175

spike_access

New member
Local time
Today, 17:27
Joined
Mar 22, 2022
Messages
14
Hi @arnelgp,
As your solution seemed a bit easier I tried that one, but when applying it to my db I get "Data type mismatch in criteria expression" when running the query. I've double checked and all the fields have the same type (short text) so not sure what the reason could be. Any idea?
Only thing I changed was changing metaID to MetaID.

Best
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 23:27
Joined
May 7, 2009
Messages
19,230
see my sample table in design view (they are all short text).
show me your table structure so i can adjust the code.
or much better if you can post those Two tables.
 

spike_access

New member
Local time
Today, 17:27
Joined
Mar 22, 2022
Messages
14
Seems like I'm getting either -1, 0 or #Error values in the IsCompliant so when filtering on "False" I get the error. If I remove the "False" it works. Not sure how to filter the non-successful mappings... Tried Not "-1" as filter but that rendered an error.
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 23:27
Joined
May 7, 2009
Messages
19,230
"false" should be False (no quotes).

you should either use False or 0.
 

spike_access

New member
Local time
Today, 17:27
Joined
Mar 22, 2022
Messages
14
Still getting an error when running the query I'm afraid. If I leave the IsComplied without any criteria it works, only when adding False or 0 it errors
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 23:27
Joined
May 7, 2009
Messages
19,230
you upload your db with that has tblContentTracker and tblMeta.
 

spike_access

New member
Local time
Today, 17:27
Joined
Mar 22, 2022
Messages
14
Here's a snapshot of the db
 

Attachments

  • compliance test.zip
    3.7 MB · Views: 182

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 23:27
Joined
May 7, 2009
Messages
19,230
see the function in module1.
right now when "Compliance" field is blank (Null), it will return True.
change the function if you like.
 

Attachments

  • compliance test.zip
    3.9 MB · Views: 161

spike_access

New member
Local time
Today, 17:27
Joined
Mar 22, 2022
Messages
14
Perfect @arnelgp, thank you so much!
Wouldn't have been able to pull this through without you. Not the first time you've been my hero (and probably not the last one either).

Very much appreciated!
 

Users who are viewing this thread

Top Bottom