mirror of
https://github.com/acedanger/shell.git
synced 2025-12-06 00:00:13 -08:00
307 lines
9.1 KiB
Bash
Executable File
307 lines
9.1 KiB
Bash
Executable File
#!/bin/bash
|
|
|
|
################################################################################
|
|
# Plex Database Query Script
|
|
################################################################################
|
|
#
|
|
# Author: Peter Wood <peter@peterwood.dev>
|
|
# Description: Flexible Plex Media Server database query tool supporting
|
|
# multiple query types including recent additions, library stats,
|
|
# media counts, and custom queries.
|
|
#
|
|
# Features:
|
|
# - Multiple query types (recent, stats, count, libraries, custom)
|
|
# - Recent additions reporting (configurable time range)
|
|
# - Library section filtering and statistics
|
|
# - Formatted output with headers and columns
|
|
# - Direct SQLite database querying
|
|
# - Media type categorization
|
|
# - Custom SQL query execution
|
|
#
|
|
# Related Scripts:
|
|
# - backup-plex.sh: Backs up the database queried by this script
|
|
# - plex.sh: General Plex service management
|
|
# - validate-plex-backups.sh: Validates database integrity
|
|
# - monitor-plex-backup.sh: System monitoring
|
|
#
|
|
# Usage:
|
|
# ./plex-recent-additions.sh [QUERY_TYPE] [OPTIONS]
|
|
#
|
|
# Query Types:
|
|
# recent [DAYS] # Show additions from last N days (default: 7)
|
|
# stats # Show library statistics
|
|
# count # Show media counts by library
|
|
# libraries # List all libraries
|
|
# custom "SQL" # Execute custom SQL query
|
|
#
|
|
# Examples:
|
|
# ./plex-recent-additions.sh recent # Last 7 days additions
|
|
# ./plex-recent-additions.sh recent 30 # Last 30 days additions
|
|
# ./plex-recent-additions.sh stats # Library statistics
|
|
# ./plex-recent-additions.sh count # Media counts
|
|
# ./plex-recent-additions.sh libraries # List libraries
|
|
# ./plex-recent-additions.sh custom "SELECT name FROM library_sections"
|
|
#
|
|
# Dependencies:
|
|
# - sqlite3 (for database queries)
|
|
# - Plex Media Server with populated library
|
|
# - Read access to Plex database files
|
|
#
|
|
# Exit Codes:
|
|
# 0 - Success
|
|
# 1 - Database not found or access denied
|
|
# 2 - Query execution failure
|
|
# 3 - Invalid arguments
|
|
#
|
|
################################################################################
|
|
|
|
# Configuration
|
|
PLEX_SQLITE="/usr/lib/plexmediaserver/Plex SQLite"
|
|
PLEX_DB="/var/lib/plexmediaserver/Library/Application Support/Plex Media Server/Plug-in Support/Databases/com.plexapp.plugins.library.db"
|
|
|
|
################################################################################
|
|
# Core Functions
|
|
################################################################################
|
|
|
|
# Execute SQL query with formatted output
|
|
execute_query() {
|
|
local query="$1"
|
|
local description="$2"
|
|
|
|
if [ -n "$description" ]; then
|
|
echo "=== $description ==="
|
|
echo
|
|
fi
|
|
|
|
if ! "$PLEX_SQLITE" "$PLEX_DB" <<EOF
|
|
.headers on
|
|
.mode column
|
|
$query
|
|
EOF
|
|
then
|
|
echo "Error: Query execution failed" >&2
|
|
return 2
|
|
fi
|
|
|
|
echo
|
|
}
|
|
|
|
# Validate database access
|
|
check_database() {
|
|
if [ ! -f "$PLEX_DB" ]; then
|
|
echo "Error: Plex database not found at $PLEX_DB" >&2
|
|
exit 1
|
|
fi
|
|
|
|
if [ ! -r "$PLEX_DB" ]; then
|
|
echo "Error: Cannot read Plex database at $PLEX_DB" >&2
|
|
exit 1
|
|
fi
|
|
}
|
|
|
|
################################################################################
|
|
# Query Functions
|
|
################################################################################
|
|
|
|
# Recent additions query
|
|
query_recent_additions() {
|
|
local days=${1:-7}
|
|
|
|
# Validate that days is a number
|
|
if ! [[ "$days" =~ ^[0-9]+$ ]]; then
|
|
echo "Error: DAYS must be a positive integer" >&2
|
|
return 3
|
|
fi
|
|
|
|
# Count query
|
|
local count_query="
|
|
SELECT
|
|
count(meta.library_section_id) as \"Count\"
|
|
FROM
|
|
metadata_items meta
|
|
join library_sections lib on meta.library_section_id = lib.id
|
|
WHERE
|
|
meta.added_at >= strftime('%s', 'now', '-$days days')
|
|
and meta.year is not null
|
|
and meta.title is not null;"
|
|
|
|
execute_query "$count_query" "Total Recent Additions (Last $days days)"
|
|
|
|
# Detail query
|
|
local detail_query="
|
|
SELECT
|
|
date(meta.added_at, 'unixepoch', 'localtime') AS \"added_at\",
|
|
trim(lib.name) as \"library_name\",
|
|
meta.year,
|
|
trim(meta.title) as \"title\"
|
|
FROM
|
|
metadata_items meta
|
|
join library_sections lib on meta.library_section_id = lib.id
|
|
WHERE
|
|
meta.added_at >= strftime('%s', 'now', '-$days days')
|
|
and meta.year is not null
|
|
and meta.title is not null
|
|
ORDER BY lib.name, meta.added_at DESC;"
|
|
|
|
execute_query "$detail_query" "Recent Additions Details (Last $days days)"
|
|
}
|
|
|
|
# Library statistics query
|
|
query_library_stats() {
|
|
local stats_query="
|
|
SELECT
|
|
lib.name as \"Library\",
|
|
COUNT(meta.id) as \"Total Items\",
|
|
COUNT(CASE WHEN meta.added_at >= strftime('%s', 'now', '-7 days') THEN 1 END) as \"Added Last 7 Days\",
|
|
COUNT(CASE WHEN meta.added_at >= strftime('%s', 'now', '-30 days') THEN 1 END) as \"Added Last 30 Days\",
|
|
date(MIN(meta.added_at), 'unixepoch', 'localtime') as \"Oldest Addition\",
|
|
date(MAX(meta.added_at), 'unixepoch', 'localtime') as \"Latest Addition\"
|
|
FROM
|
|
library_sections lib
|
|
LEFT JOIN metadata_items meta ON lib.id = meta.library_section_id
|
|
WHERE
|
|
meta.metadata_type IN (1, 2, 4) -- Movies, Shows, Episodes
|
|
AND meta.title IS NOT NULL
|
|
GROUP BY
|
|
lib.id, lib.name
|
|
ORDER BY
|
|
lib.name;"
|
|
|
|
execute_query "$stats_query" "Library Statistics"
|
|
}
|
|
|
|
# Media count by library
|
|
query_media_counts() {
|
|
local count_query="
|
|
SELECT
|
|
lib.name as \"Library\",
|
|
CASE
|
|
WHEN meta.metadata_type = 1 THEN 'Movie'
|
|
WHEN meta.metadata_type = 2 THEN 'TV Show'
|
|
WHEN meta.metadata_type = 4 THEN 'Episode'
|
|
WHEN meta.metadata_type = 9 THEN 'Album'
|
|
WHEN meta.metadata_type = 10 THEN 'Track'
|
|
ELSE 'Other'
|
|
END as \"Media Type\",
|
|
COUNT(*) as \"Count\"
|
|
FROM
|
|
library_sections lib
|
|
LEFT JOIN metadata_items meta ON lib.id = meta.library_section_id
|
|
WHERE
|
|
meta.title IS NOT NULL
|
|
GROUP BY
|
|
lib.name, meta.metadata_type
|
|
ORDER BY
|
|
lib.name, meta.metadata_type;"
|
|
|
|
execute_query "$count_query" "Media Counts by Library and Type"
|
|
}
|
|
|
|
# List all libraries
|
|
query_libraries() {
|
|
local libraries_query="
|
|
SELECT
|
|
lib.id as \"ID\",
|
|
lib.name as \"Library Name\",
|
|
lib.section_type as \"Type\",
|
|
COUNT(meta.id) as \"Items\"
|
|
FROM
|
|
library_sections lib
|
|
LEFT JOIN metadata_items meta ON lib.id = meta.library_section_id
|
|
GROUP BY
|
|
lib.id, lib.name, lib.section_type
|
|
ORDER BY
|
|
lib.name;"
|
|
|
|
execute_query "$libraries_query" "All Libraries"
|
|
}
|
|
|
|
# Execute custom query
|
|
query_custom() {
|
|
local custom_sql="$1"
|
|
|
|
if [ -z "$custom_sql" ]; then
|
|
echo "Error: Custom SQL query cannot be empty" >&2
|
|
return 3
|
|
fi
|
|
|
|
execute_query "$custom_sql" "Custom Query"
|
|
}
|
|
|
|
################################################################################
|
|
# Help and Usage
|
|
################################################################################
|
|
|
|
show_help() {
|
|
echo "Usage: $0 [QUERY_TYPE] [OPTIONS]"
|
|
echo
|
|
echo "Query Types:"
|
|
echo " recent [DAYS] Show additions from last N days (default: 7)"
|
|
echo " stats Show library statistics"
|
|
echo " count Show media counts by library"
|
|
echo " libraries List all libraries"
|
|
echo " custom \"SQL\" Execute custom SQL query"
|
|
echo
|
|
echo "Examples:"
|
|
echo " $0 recent # Last 7 days additions"
|
|
echo " $0 recent 30 # Last 30 days additions"
|
|
echo " $0 stats # Library statistics"
|
|
echo " $0 count # Media counts"
|
|
echo " $0 libraries # List libraries"
|
|
echo " $0 custom \"SELECT COUNT(*) FROM metadata_items\""
|
|
echo
|
|
echo "Options:"
|
|
echo " --help, -h Show this help message"
|
|
echo
|
|
echo "Exit Codes:"
|
|
echo " 0 - Success"
|
|
echo " 1 - Database not found or access denied"
|
|
echo " 2 - Query execution failure"
|
|
echo " 3 - Invalid arguments"
|
|
}
|
|
|
|
################################################################################
|
|
# Main Script Logic
|
|
################################################################################
|
|
|
|
# Check database access first
|
|
check_database
|
|
|
|
# Handle command line arguments
|
|
case "${1:-recent}" in
|
|
"recent"|"additions")
|
|
query_recent_additions "${2:-7}"
|
|
;;
|
|
"stats"|"statistics")
|
|
query_library_stats
|
|
;;
|
|
"count"|"counts")
|
|
query_media_counts
|
|
;;
|
|
"libraries"|"libs")
|
|
query_libraries
|
|
;;
|
|
"custom")
|
|
if [ -z "$2" ]; then
|
|
echo "Error: Custom query requires SQL as second argument" >&2
|
|
echo "Usage: $0 custom \"SELECT * FROM library_sections\"" >&2
|
|
exit 3
|
|
fi
|
|
query_custom "$2"
|
|
;;
|
|
"--help"|"-h"|"help")
|
|
show_help
|
|
exit 0
|
|
;;
|
|
*)
|
|
# Backward compatibility: if first arg is a number, treat as recent query
|
|
if [[ "$1" =~ ^[0-9]+$ ]]; then
|
|
query_recent_additions "$1"
|
|
else
|
|
echo "Error: Unknown query type '$1'" >&2
|
|
echo "Use --help for usage information" >&2
|
|
exit 3
|
|
fi
|
|
;;
|
|
esac
|