Of course it's not ideal to have to keep two separate reports, one for current items and one for deleted items. With a slightly fancier query we can tell our report to look at both the items and deleteditems tables and give us whatever it finds in each. We can do that with a UNION.
Essentially, we're displaying the results of two separate queries on top of each other -- all the current items that match our barcode and then all the deleted items the match our barcode. This option is quick and easy and works well for simple reports.
Deleted records referenced in other tables
Things get a little more complicated when we start dealing with other tables that refer back to records that might have been deleted. Here's a report that will ask for a date and list the titles of all the books with holds that were cancelled on that day.
SELECT title
FROM old_reserves
LEFT JOIN biblio USING (biblionumber)
WHERE cancellationdate=<<enter date|date=>>
We can tell this report is only going to work for biblio records that haven't been deleted because it only looks at the biblio table. If we want to also find titles for deleted records we'll need to pull in the deletedbiblio table. We could use a UNION as we did before, but now that we're starting with the old_reserves table and joining to the biblio records we have a new option.
SELECT IFNULL(biblio.title,deletedbiblio.title)
FROM old_reserves
LEFT JOIN biblio USING (biblionumber)
LEFT JOIN deletedbiblio USING (biblionumber)
WHERE cancellationdate=<<enter date|date=>>
The IFNULL() function lets us name two fields. If the first field has a value it is returned. If the first field is null, the second field's value is returned instead. Because IFNULL() lets us accomplish our whole query with just one SELECT statement its a bit faster and less resource-intensive than using two SELECT statements connected with a UNION.
IFNULL() also makes it easier to look at more than one type of record at a time. For example, we could write a report that looks at how many holds patrons of each category place on items of each item type in the past year to get a sense of which materials are popular with which patrons. We know we want to start in the old_reserves table. To find patron categories we'll need the borrowers table and then deletedborrowers for anyone who's been deleted. Likewise, we'll need items and deleteditems for itemtypes. Here's what that report would look like.
SELECT IFNULL(borrowers.categorycode,deletedborrowers.categorycode) as category,
IFNULL(items.itype,deleteditems.itype) as itemtype,
COUNT(reserve_id)
FROM old_reserves
LEFT JOIN borrowers USING (borrowernumber)
LEFT JOIN deletedborrowers USING (borrowernumber)
LEFT JOIN items USING (itemnumber)
LEFT JOIN deleteditems USING (itemnumber)
WHERE reservedate >= date_sub(curdate(), interval 1 year)
GROUP BY category,itemtype
If we wanted to run this same report with UNION instead of IFNULL() we'd have to combine 4 separate reports for every combination of current and deleted borrowers and items.
Old_issues and old_reserves
So far I've been talking about deleted records, but these same functions can be used with issues and reserves. When a book is checked out that's recorded in the issues table and when it's returned that line moves to the old_issues table. Likewise, when a hold is placed it goes into the reserves table and when it's either completed or cancelled it moves into old_reserves. If you need to write a report looking at both current and old checkouts or holds, you can use either UNION or IFNULL() just like we did above.