1<?php 2 3/** 4 * webtrees: online genealogy 5 * Copyright (C) 2023 webtrees development team 6 * This program is free software: you can redistribute it and/or modify 7 * it under the terms of the GNU General Public License as published by 8 * the Free Software Foundation, either version 3 of the License, or 9 * (at your option) any later version. 10 * This program is distributed in the hope that it will be useful, 11 * but WITHOUT ANY WARRANTY; without even the implied warranty of 12 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 13 * GNU General Public License for more details. 14 * You should have received a copy of the GNU General Public License 15 * along with this program. If not, see <https://www.gnu.org/licenses/>. 16 */ 17 18declare(strict_types=1); 19 20namespace Fisharebest\Webtrees\Services; 21 22use Closure; 23use Fisharebest\Webtrees\Date; 24use Fisharebest\Webtrees\DB; 25use Fisharebest\Webtrees\Family; 26use Fisharebest\Webtrees\Gedcom; 27use Fisharebest\Webtrees\GedcomRecord; 28use Fisharebest\Webtrees\Http\Exceptions\HttpServiceUnavailableException; 29use Fisharebest\Webtrees\I18N; 30use Fisharebest\Webtrees\Individual; 31use Fisharebest\Webtrees\Location; 32use Fisharebest\Webtrees\Media; 33use Fisharebest\Webtrees\Note; 34use Fisharebest\Webtrees\Place; 35use Fisharebest\Webtrees\Registry; 36use Fisharebest\Webtrees\Repository; 37use Fisharebest\Webtrees\SharedNote; 38use Fisharebest\Webtrees\Soundex; 39use Fisharebest\Webtrees\Source; 40use Fisharebest\Webtrees\Submission; 41use Fisharebest\Webtrees\Submitter; 42use Fisharebest\Webtrees\Tree; 43use Illuminate\Database\Query\Builder; 44use Illuminate\Database\Query\Expression; 45use Illuminate\Database\Query\JoinClause; 46use Illuminate\Support\Collection; 47 48use function addcslashes; 49use function array_filter; 50use function array_map; 51use function array_unique; 52use function explode; 53use function implode; 54use function mb_stripos; 55use function preg_match; 56use function preg_quote; 57use function preg_replace; 58use function str_ends_with; 59use function str_starts_with; 60 61use const PHP_INT_MAX; 62 63/** 64 * Search trees for genealogy records. 65 */ 66class SearchService 67{ 68 // Do not attempt to show search results larger than this/ 69 protected const MAX_SEARCH_RESULTS = 5000; 70 71 private TreeService $tree_service; 72 73 /** 74 * @param TreeService $tree_service 75 */ 76 public function __construct( 77 TreeService $tree_service 78 ) { 79 $this->tree_service = $tree_service; 80 } 81 82 /** 83 * @param array<Tree> $trees 84 * @param array<string> $search 85 * 86 * @return Collection<int,Family> 87 */ 88 public function searchFamilies(array $trees, array $search): Collection 89 { 90 $query = DB::table('families'); 91 92 $this->whereTrees($query, 'f_file', $trees); 93 $this->whereSearch($query, 'f_gedcom', $search); 94 95 return $query 96 ->get() 97 ->each($this->rowLimiter()) 98 ->map($this->familyRowMapper()) 99 ->filter(GedcomRecord::accessFilter()) 100 ->filter($this->rawGedcomFilter($search)); 101 } 102 103 /** 104 * Search for families by name. 105 * 106 * @param array<Tree> $trees 107 * @param array<string> $search 108 * @param int $offset 109 * @param int $limit 110 * 111 * @return Collection<int,Family> 112 */ 113 public function searchFamilyNames(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 114 { 115 $query = DB::table('families') 116 ->leftJoin('name AS husb_name', static function (JoinClause $join): void { 117 $join 118 ->on('husb_name.n_file', '=', 'families.f_file') 119 ->on('husb_name.n_id', '=', 'families.f_husb') 120 ->where('husb_name.n_type', '<>', '_MARNM'); 121 }) 122 ->leftJoin('name AS wife_name', static function (JoinClause $join): void { 123 $join 124 ->on('wife_name.n_file', '=', 'families.f_file') 125 ->on('wife_name.n_id', '=', 'families.f_wife') 126 ->where('wife_name.n_type', '<>', '_MARNM'); 127 }); 128 129 $prefix = DB::connection()->getTablePrefix(); 130 $field = new Expression('COALESCE(' . $prefix . "husb_name.n_full, '') || COALESCE(" . $prefix . "wife_name.n_full, '')"); 131 132 $this->whereTrees($query, 'f_file', $trees); 133 $this->whereSearch($query, $field, $search); 134 135 $query 136 ->orderBy('husb_name.n_sort') 137 ->orderBy('wife_name.n_sort') 138 ->select(['families.*', 'husb_name.n_sort', 'wife_name.n_sort']); 139 140 return $this->paginateQuery($query, $this->familyRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 141 } 142 143 /** 144 * @param Place $place 145 * 146 * @return Collection<int,Family> 147 */ 148 public function searchFamiliesInPlace(Place $place): Collection 149 { 150 return DB::table('families') 151 ->join('placelinks', static function (JoinClause $query) { 152 $query 153 ->on('families.f_file', '=', 'placelinks.pl_file') 154 ->on('families.f_id', '=', 'placelinks.pl_gid'); 155 }) 156 ->where('f_file', '=', $place->tree()->id()) 157 ->where('pl_p_id', '=', $place->id()) 158 ->select(['families.*']) 159 ->get() 160 ->each($this->rowLimiter()) 161 ->map($this->familyRowMapper()) 162 ->filter(GedcomRecord::accessFilter()); 163 } 164 165 /** 166 * @param array<Tree> $trees 167 * @param array<string> $search 168 * 169 * @return Collection<int,Individual> 170 */ 171 public function searchIndividuals(array $trees, array $search): Collection 172 { 173 $query = DB::table('individuals'); 174 175 $this->whereTrees($query, 'i_file', $trees); 176 $this->whereSearch($query, 'i_gedcom', $search); 177 178 return $query 179 ->get() 180 ->each($this->rowLimiter()) 181 ->map($this->individualRowMapper()) 182 ->filter(GedcomRecord::accessFilter()) 183 ->filter($this->rawGedcomFilter($search)); 184 } 185 186 /** 187 * Search for individuals by name. 188 * 189 * @param array<Tree> $trees 190 * @param array<string> $search 191 * @param int $offset 192 * @param int $limit 193 * 194 * @return Collection<int,Individual> 195 */ 196 public function searchIndividualNames(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 197 { 198 $query = DB::table('individuals') 199 ->join('name', static function (JoinClause $join): void { 200 $join 201 ->on('name.n_file', '=', 'individuals.i_file') 202 ->on('name.n_id', '=', 'individuals.i_id'); 203 }) 204 ->orderBy('n_sort') 205 ->select(['individuals.*', 'n_sort']); 206 207 $this->whereTrees($query, 'i_file', $trees); 208 $this->whereSearch($query, 'n_full', $search); 209 210 return $this->paginateQuery($query, $this->individualRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 211 } 212 213 /** 214 * @param Place $place 215 * 216 * @return Collection<int,Individual> 217 */ 218 public function searchIndividualsInPlace(Place $place): Collection 219 { 220 return DB::table('individuals') 221 ->join('placelinks', static function (JoinClause $join) { 222 $join 223 ->on('i_file', '=', 'pl_file') 224 ->on('i_id', '=', 'pl_gid'); 225 }) 226 ->where('i_file', '=', $place->tree()->id()) 227 ->where('pl_p_id', '=', $place->id()) 228 ->select(['individuals.*']) 229 ->get() 230 ->each($this->rowLimiter()) 231 ->map($this->individualRowMapper()) 232 ->filter(GedcomRecord::accessFilter()); 233 } 234 235 /** 236 * Search for submissions. 237 * 238 * @param array<Tree> $trees 239 * @param array<string> $search 240 * @param int $offset 241 * @param int $limit 242 * 243 * @return Collection<int,Location> 244 */ 245 public function searchLocations(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 246 { 247 $query = DB::table('other') 248 ->where('o_type', '=', Location::RECORD_TYPE); 249 250 $this->whereTrees($query, 'o_file', $trees); 251 $this->whereSearch($query, 'o_gedcom', $search); 252 253 return $this->paginateQuery($query, $this->locationRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 254 } 255 256 /** 257 * Search for media objects. 258 * 259 * @param array<Tree> $trees 260 * @param array<string> $search 261 * @param int $offset 262 * @param int $limit 263 * 264 * @return Collection<int,Media> 265 */ 266 public function searchMedia(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 267 { 268 $query = DB::table('media'); 269 270 $this->whereTrees($query, 'media.m_file', $trees); 271 $this->whereSearch($query, 'm_gedcom', $search); 272 273 return $this->paginateQuery($query, $this->mediaRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 274 } 275 276 /** 277 * Search for notes. 278 * 279 * @param array<Tree> $trees 280 * @param array<string> $search 281 * @param int $offset 282 * @param int $limit 283 * 284 * @return Collection<int,Note> 285 */ 286 public function searchNotes(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 287 { 288 $query = DB::table('other') 289 ->where('o_type', '=', Note::RECORD_TYPE); 290 291 $this->whereTrees($query, 'o_file', $trees); 292 $this->whereSearch($query, 'o_gedcom', $search); 293 294 return $this->paginateQuery($query, $this->noteRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 295 } 296 297 /** 298 * Search for notes. 299 * 300 * @param array<Tree> $trees 301 * @param array<string> $search 302 * @param int $offset 303 * @param int $limit 304 * 305 * @return Collection<int,SharedNote> 306 */ 307 public function searchSharedNotes(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 308 { 309 $query = DB::table('other') 310 ->where('o_type', '=', SharedNote::RECORD_TYPE); 311 312 $this->whereTrees($query, 'o_file', $trees); 313 $this->whereSearch($query, 'o_gedcom', $search); 314 315 return $this->paginateQuery($query, $this->sharedNoteRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 316 } 317 318 /** 319 * Search for repositories. 320 * 321 * @param array<Tree> $trees 322 * @param array<string> $search 323 * @param int $offset 324 * @param int $limit 325 * 326 * @return Collection<int,Repository> 327 */ 328 public function searchRepositories(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 329 { 330 $query = DB::table('other') 331 ->where('o_type', '=', Repository::RECORD_TYPE); 332 333 $this->whereTrees($query, 'o_file', $trees); 334 $this->whereSearch($query, 'o_gedcom', $search); 335 336 return $this->paginateQuery($query, $this->repositoryRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 337 } 338 339 /** 340 * Search for sources. 341 * 342 * @param array<Tree> $trees 343 * @param array<string> $search 344 * @param int $offset 345 * @param int $limit 346 * 347 * @return Collection<int,Source> 348 */ 349 public function searchSources(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 350 { 351 $query = DB::table('sources'); 352 353 $this->whereTrees($query, 's_file', $trees); 354 $this->whereSearch($query, 's_gedcom', $search); 355 356 return $this->paginateQuery($query, $this->sourceRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 357 } 358 359 /** 360 * Search for sources by name. 361 * 362 * @param array<Tree> $trees 363 * @param array<string> $search 364 * @param int $offset 365 * @param int $limit 366 * 367 * @return Collection<int,Source> 368 */ 369 public function searchSourcesByName(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 370 { 371 $query = DB::table('sources') 372 ->orderBy('s_name'); 373 374 $this->whereTrees($query, 's_file', $trees); 375 $this->whereSearch($query, 's_name', $search); 376 377 return $this->paginateQuery($query, $this->sourceRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 378 } 379 380 /** 381 * Search for sources. 382 * 383 * @param array<Tree> $trees 384 * @param array<string> $search 385 * @param int $offset 386 * @param int $limit 387 * 388 * @return Collection<int,string> 389 */ 390 public function searchSurnames(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 391 { 392 $query = DB::table('name'); 393 394 $this->whereTrees($query, 'n_file', $trees); 395 $this->whereSearch($query, 'n_surname', $search); 396 397 return $query 398 ->groupBy(['n_surname']) 399 ->orderBy('n_surname') 400 ->skip($offset) 401 ->take($limit) 402 ->pluck('n_surname'); 403 } 404 405 /** 406 * Search for submissions. 407 * 408 * @param array<Tree> $trees 409 * @param array<string> $search 410 * @param int $offset 411 * @param int $limit 412 * 413 * @return Collection<int,Submission> 414 */ 415 public function searchSubmissions(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 416 { 417 $query = DB::table('other') 418 ->where('o_type', '=', Submission::RECORD_TYPE); 419 420 $this->whereTrees($query, 'o_file', $trees); 421 $this->whereSearch($query, 'o_gedcom', $search); 422 423 return $this->paginateQuery($query, $this->submissionRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 424 } 425 426 /** 427 * Search for submitters. 428 * 429 * @param array<Tree> $trees 430 * @param array<string> $search 431 * @param int $offset 432 * @param int $limit 433 * 434 * @return Collection<int,Submitter> 435 */ 436 public function searchSubmitters(array $trees, array $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 437 { 438 $query = DB::table('other') 439 ->where('o_type', '=', Submitter::RECORD_TYPE); 440 441 $this->whereTrees($query, 'o_file', $trees); 442 $this->whereSearch($query, 'o_gedcom', $search); 443 444 return $this->paginateQuery($query, $this->submitterRowMapper(), GedcomRecord::accessFilter(), $offset, $limit); 445 } 446 447 /** 448 * Search for places. 449 * 450 * @param Tree $tree 451 * @param string $search 452 * @param int $offset 453 * @param int $limit 454 * 455 * @return Collection<int,Place> 456 */ 457 public function searchPlaces(Tree $tree, string $search, int $offset = 0, int $limit = PHP_INT_MAX): Collection 458 { 459 $query = DB::table('places AS p0') 460 ->where('p0.p_file', '=', $tree->id()) 461 ->leftJoin('places AS p1', 'p1.p_id', '=', 'p0.p_parent_id') 462 ->leftJoin('places AS p2', 'p2.p_id', '=', 'p1.p_parent_id') 463 ->leftJoin('places AS p3', 'p3.p_id', '=', 'p2.p_parent_id') 464 ->leftJoin('places AS p4', 'p4.p_id', '=', 'p3.p_parent_id') 465 ->leftJoin('places AS p5', 'p5.p_id', '=', 'p4.p_parent_id') 466 ->leftJoin('places AS p6', 'p6.p_id', '=', 'p5.p_parent_id') 467 ->leftJoin('places AS p7', 'p7.p_id', '=', 'p6.p_parent_id') 468 ->leftJoin('places AS p8', 'p8.p_id', '=', 'p7.p_parent_id') 469 ->orderBy('p0.p_place') 470 ->orderBy('p1.p_place') 471 ->orderBy('p2.p_place') 472 ->orderBy('p3.p_place') 473 ->orderBy('p4.p_place') 474 ->orderBy('p5.p_place') 475 ->orderBy('p6.p_place') 476 ->orderBy('p7.p_place') 477 ->orderBy('p8.p_place') 478 ->select([ 479 'p0.p_place AS place0', 480 'p1.p_place AS place1', 481 'p2.p_place AS place2', 482 'p3.p_place AS place3', 483 'p4.p_place AS place4', 484 'p5.p_place AS place5', 485 'p6.p_place AS place6', 486 'p7.p_place AS place7', 487 'p8.p_place AS place8', 488 ]); 489 490 // Filter each level of the hierarchy. 491 foreach (explode(',', $search, 9) as $level => $string) { 492 $query->where('p' . $level . '.p_place', $this->iLike(), '%' . addcslashes($string, '\\%_') . '%'); 493 } 494 495 $row_mapper = static function (object $row) use ($tree): Place { 496 $place = implode(', ', array_filter((array) $row)); 497 498 return new Place($place, $tree); 499 }; 500 501 $filter = static fn(): bool => true; 502 503 return $this->paginateQuery($query, $row_mapper, $filter, $offset, $limit); 504 } 505 506 /** 507 * @param Tree $tree 508 * @param array<string,string> $fields 509 * @param array<string,string> $modifiers 510 * 511 * @return Collection<int,Individual> 512 */ 513 public function searchIndividualsAdvanced(Tree $tree, array $fields, array $modifiers): Collection 514 { 515 $fields = array_filter($fields, static fn (string $x): bool => $x !== ''); 516 517 $query = DB::table('individuals') 518 ->where('i_file', '=', $tree->id()) 519 ->select(['individuals.*']) 520 ->distinct(); 521 522 // Join the following tables 523 $father_name = false; 524 $mother_name = false; 525 $spouse_family = false; 526 $indi_name = false; 527 $indi_dates = []; 528 $fam_dates = []; 529 $indi_plac = false; 530 $fam_plac = false; 531 532 foreach ($fields as $field_name => $field_value) { 533 if (str_starts_with($field_name, 'FATHER:NAME')) { 534 $father_name = true; 535 } elseif (str_starts_with($field_name, 'MOTHER:NAME')) { 536 $mother_name = true; 537 } elseif (str_starts_with($field_name, 'INDI:NAME:GIVN')) { 538 $indi_name = true; 539 } elseif (str_starts_with($field_name, 'INDI:NAME:SURN')) { 540 $indi_name = true; 541 } elseif (str_starts_with($field_name, 'FAM:')) { 542 $spouse_family = true; 543 if (str_ends_with($field_name, ':DATE')) { 544 $fam_dates[] = explode(':', $field_name)[1]; 545 } elseif (str_ends_with($field_name, ':PLAC')) { 546 $fam_plac = true; 547 } 548 } elseif (str_starts_with($field_name, 'INDI:')) { 549 if (str_ends_with($field_name, ':DATE')) { 550 $indi_dates[] = explode(':', $field_name)[1]; 551 } elseif (str_ends_with($field_name, ':PLAC')) { 552 $indi_plac = true; 553 } 554 } 555 } 556 557 if ($father_name || $mother_name) { 558 $query->join('link AS l1', static function (JoinClause $join): void { 559 $join 560 ->on('l1.l_file', '=', 'individuals.i_file') 561 ->on('l1.l_from', '=', 'individuals.i_id') 562 ->where('l1.l_type', '=', 'FAMC'); 563 }); 564 565 if ($father_name) { 566 $query->join('link AS l2', static function (JoinClause $join): void { 567 $join 568 ->on('l2.l_file', '=', 'l1.l_file') 569 ->on('l2.l_from', '=', 'l1.l_to') 570 ->where('l2.l_type', '=', 'HUSB'); 571 }); 572 $query->join('name AS father_name', static function (JoinClause $join): void { 573 $join 574 ->on('father_name.n_file', '=', 'l2.l_file') 575 ->on('father_name.n_id', '=', 'l2.l_to'); 576 }); 577 } 578 579 if ($mother_name) { 580 $query->join('link AS l3', static function (JoinClause $join): void { 581 $join 582 ->on('l3.l_file', '=', 'l1.l_file') 583 ->on('l3.l_from', '=', 'l1.l_to') 584 ->where('l3.l_type', '=', 'WIFE'); 585 }); 586 $query->join('name AS mother_name', static function (JoinClause $join): void { 587 $join 588 ->on('mother_name.n_file', '=', 'l3.l_file') 589 ->on('mother_name.n_id', '=', 'l3.l_to'); 590 }); 591 } 592 } 593 594 if ($spouse_family) { 595 $query->join('link AS l4', static function (JoinClause $join): void { 596 $join 597 ->on('l4.l_file', '=', 'individuals.i_file') 598 ->on('l4.l_from', '=', 'individuals.i_id') 599 ->where('l4.l_type', '=', 'FAMS'); 600 }); 601 $query->join('families AS spouse_families', static function (JoinClause $join): void { 602 $join 603 ->on('spouse_families.f_file', '=', 'l4.l_file') 604 ->on('spouse_families.f_id', '=', 'l4.l_to'); 605 }); 606 } 607 608 if ($indi_name) { 609 $query->join('name AS individual_name', static function (JoinClause $join): void { 610 $join 611 ->on('individual_name.n_file', '=', 'individuals.i_file') 612 ->on('individual_name.n_id', '=', 'individuals.i_id'); 613 }); 614 } 615 616 foreach (array_unique($indi_dates) as $indi_date) { 617 $query->join('dates AS date_' . $indi_date, static function (JoinClause $join) use ($indi_date): void { 618 $join 619 ->on('date_' . $indi_date . '.d_file', '=', 'individuals.i_file') 620 ->on('date_' . $indi_date . '.d_gid', '=', 'individuals.i_id'); 621 }); 622 } 623 624 foreach (array_unique($fam_dates) as $fam_date) { 625 $query->join('dates AS date_' . $fam_date, static function (JoinClause $join) use ($fam_date): void { 626 $join 627 ->on('date_' . $fam_date . '.d_file', '=', 'spouse_families.f_file') 628 ->on('date_' . $fam_date . '.d_gid', '=', 'spouse_families.f_id'); 629 }); 630 } 631 632 if ($indi_plac) { 633 $query->join('placelinks AS individual_placelinks', static function (JoinClause $join): void { 634 $join 635 ->on('individual_placelinks.pl_file', '=', 'individuals.i_file') 636 ->on('individual_placelinks.pl_gid', '=', 'individuals.i_id'); 637 }); 638 $query->join('places AS individual_places', static function (JoinClause $join): void { 639 $join 640 ->on('individual_places.p_file', '=', 'individual_placelinks.pl_file') 641 ->on('individual_places.p_id', '=', 'individual_placelinks.pl_p_id'); 642 }); 643 } 644 645 if ($fam_plac) { 646 $query->join('placelinks AS family_placelinks', static function (JoinClause $join): void { 647 $join 648 ->on('family_placelinks.pl_file', '=', 'spouse_families.f_file') 649 ->on('family_placelinks.pl_gid', '=', 'spouse_families.f_id'); 650 }); 651 $query->join('places AS family_places', static function (JoinClause $join): void { 652 $join 653 ->on('family_places.p_file', '=', 'family_placelinks.pl_file') 654 ->on('family_places.p_id', '=', 'family_placelinks.pl_p_id'); 655 }); 656 } 657 658 foreach ($fields as $field_name => $field_value) { 659 $parts = explode(':', $field_name . ':::'); 660 if (str_starts_with($field_name, 'INDI:NAME:')) { 661 switch ($field_name) { 662 case 'INDI:NAME:GIVN': 663 switch ($modifiers[$field_name]) { 664 case 'EXACT': 665 $query->where('individual_name.n_givn', '=', $field_value); 666 break; 667 case 'BEGINS': 668 $query->where('individual_name.n_givn', $this->iLike(), $field_value . '%'); 669 break; 670 case 'CONTAINS': 671 $query->where('individual_name.n_givn', $this->iLike(), '%' . $field_value . '%'); 672 break; 673 case 'SDX_STD': 674 $sdx = Soundex::russell($field_value); 675 if ($sdx !== '') { 676 $this->wherePhonetic($query, 'individual_name.n_soundex_givn_std', $sdx); 677 } else { 678 // No phonetic content? Use a substring match 679 $query->where('individual_name.n_givn', $this->iLike(), '%' . $field_value . '%'); 680 } 681 break; 682 case 'SDX': // SDX uses DM by default. 683 case 'SDX_DM': 684 $sdx = Soundex::daitchMokotoff($field_value); 685 if ($sdx !== '') { 686 $this->wherePhonetic($query, 'individual_name.n_soundex_givn_dm', $sdx); 687 } else { 688 // No phonetic content? Use a substring match 689 $query->where('individual_name.n_givn', $this->iLike(), '%' . $field_value . '%'); 690 } 691 break; 692 } 693 unset($fields[$field_name]); 694 break; 695 case 'INDI:NAME:SURN': 696 switch ($modifiers[$field_name]) { 697 case 'EXACT': 698 $query->where(function (Builder $query) use ($field_value): void { 699 $query 700 ->where('individual_name.n_surn', '=', $field_value) 701 ->orWhere('individual_name.n_surname', '=', $field_value); 702 }); 703 break; 704 case 'BEGINS': 705 $query->where(function (Builder $query) use ($field_value): void { 706 $query 707 ->where('individual_name.n_surn', $this->iLike(), $field_value . '%') 708 ->orWhere('individual_name.n_surname', $this->iLike(), $field_value . '%'); 709 }); 710 break; 711 case 'CONTAINS': 712 $query->where(function (Builder $query) use ($field_value): void { 713 $query 714 ->where('individual_name.n_surn', $this->iLike(), '%' . $field_value . '%') 715 ->orWhere('individual_name.n_surname', $this->iLike(), '%' . $field_value . '%'); 716 }); 717 break; 718 case 'SDX_STD': 719 $sdx = Soundex::russell($field_value); 720 if ($sdx !== '') { 721 $this->wherePhonetic($query, 'individual_name.n_soundex_surn_std', $sdx); 722 } else { 723 // No phonetic content? Use a substring match 724 $query->where(function (Builder $query) use ($field_value): void { 725 $query 726 ->where('individual_name.n_surn', $this->iLike(), '%' . $field_value . '%') 727 ->orWhere('individual_name.n_surname', $this->iLike(), '%' . $field_value . '%'); 728 }); 729 } 730 break; 731 case 'SDX': // SDX uses DM by default. 732 case 'SDX_DM': 733 $sdx = Soundex::daitchMokotoff($field_value); 734 if ($sdx !== '') { 735 $this->wherePhonetic($query, 'individual_name.n_soundex_surn_dm', $sdx); 736 } else { 737 // No phonetic content? Use a substring match 738 $query->where(function (Builder $query) use ($field_value): void { 739 $query 740 ->where('individual_name.n_surn', $this->iLike(), '%' . $field_value . '%') 741 ->orWhere('individual_name.n_surname', $this->iLike(), '%' . $field_value . '%'); 742 }); 743 } 744 break; 745 } 746 unset($fields[$field_name]); 747 break; 748 case 'INDI:NAME:NICK': 749 case 'INDI:NAME:_MARNM': 750 case 'INDI:NAME:_HEB': 751 case 'INDI:NAME:_AKA': 752 $like = "%\n1 NAME%\n2 " . $parts[2] . ' %' . preg_quote($field_value, '/') . '%'; 753 $query->where('individuals.i_gedcom', $this->iLike(), $like); 754 break; 755 } 756 } elseif (str_starts_with($field_name, 'INDI:') && str_ends_with($field_name, ':DATE')) { 757 $date = new Date($field_value); 758 if ($date->isOK()) { 759 $delta = 365 * (int) ($modifiers[$field_name] ?? 0); 760 $query 761 ->where('date_' . $parts[1] . '.d_fact', '=', $parts[1]) 762 ->where('date_' . $parts[1] . '.d_julianday1', '>=', $date->minimumJulianDay() - $delta) 763 ->where('date_' . $parts[1] . '.d_julianday2', '<=', $date->maximumJulianDay() + $delta); 764 } 765 unset($fields[$field_name]); 766 } elseif (str_starts_with($field_name, 'FAM:') && str_ends_with($field_name, ':DATE')) { 767 $date = new Date($field_value); 768 if ($date->isOK()) { 769 $delta = 365 * (int) ($modifiers[$field_name] ?? 0); 770 $query 771 ->where('date_' . $parts[1] . '.d_fact', '=', $parts[1]) 772 ->where('date_' . $parts[1] . '.d_julianday1', '>=', $date->minimumJulianDay() - $delta) 773 ->where('date_' . $parts[1] . '.d_julianday2', '<=', $date->maximumJulianDay() + $delta); 774 } 775 unset($fields[$field_name]); 776 } elseif (str_starts_with($field_name, 'INDI:') && str_ends_with($field_name, ':PLAC')) { 777 // SQL can only link a place to a person/family, not to an event. 778 $query->where('individual_places.p_id', '=', $field_value); 779 } elseif (str_starts_with($field_name, 'FAM:') && str_ends_with($field_name, ':PLAC')) { 780 // SQL can only link a place to a person/family, not to an event. 781 $query->where('family_places.p_id', '=', $field_value); 782 } elseif (str_starts_with($field_name, 'MOTHER:NAME:') || str_starts_with($field_name, 'FATHER:NAME:')) { 783 $table = str_starts_with($field_name, 'FATHER:NAME:') ? 'father_name' : 'mother_name'; 784 switch ($parts[2]) { 785 case 'GIVN': 786 switch ($modifiers[$field_name]) { 787 case 'EXACT': 788 $query->where($table . '.n_givn', '=', $field_value); 789 break; 790 case 'BEGINS': 791 $query->where($table . '.n_givn', $this->iLike(), $field_value . '%'); 792 break; 793 case 'CONTAINS': 794 $query->where($table . '.n_givn', $this->iLike(), '%' . $field_value . '%'); 795 break; 796 case 'SDX_STD': 797 $sdx = Soundex::russell($field_value); 798 if ($sdx !== '') { 799 $this->wherePhonetic($query, $table . '.n_soundex_givn_std', $sdx); 800 } else { 801 // No phonetic content? Use a substring match 802 $query->where($table . '.n_givn', $this->iLike(), '%' . $field_value . '%'); 803 } 804 break; 805 case 'SDX': // SDX uses DM by default. 806 case 'SDX_DM': 807 $sdx = Soundex::daitchMokotoff($field_value); 808 if ($sdx !== '') { 809 $this->wherePhonetic($query, $table . '.n_soundex_givn_dm', $sdx); 810 } else { 811 // No phonetic content? Use a substring match 812 $query->where($table . '.n_givn', $this->iLike(), '%' . $field_value . '%'); 813 } 814 break; 815 } 816 break; 817 case 'SURN': 818 switch ($modifiers[$field_name]) { 819 case 'EXACT': 820 $query->where($table . '.n_surn', '=', $field_value); 821 break; 822 case 'BEGINS': 823 $query->where($table . '.n_surn', $this->iLike(), $field_value . '%'); 824 break; 825 case 'CONTAINS': 826 $query->where($table . '.n_surn', $this->iLike(), '%' . $field_value . '%'); 827 break; 828 case 'SDX_STD': 829 $sdx = Soundex::russell($field_value); 830 if ($sdx !== '') { 831 $this->wherePhonetic($query, $table . '.n_soundex_surn_std', $sdx); 832 } else { 833 // No phonetic content? Use a substring match 834 $query->where($table . '.n_surn', $this->iLike(), '%' . $field_value . '%'); 835 } 836 break; 837 case 'SDX': // SDX uses DM by default. 838 case 'SDX_DM': 839 $sdx = Soundex::daitchMokotoff($field_value); 840 if ($sdx !== '') { 841 $this->wherePhonetic($query, $table . '.n_soundex_surn_dm', $sdx); 842 } else { 843 // No phonetic content? Use a substring match 844 $query->where($table . '.n_surn', $this->iLike(), '%' . $field_value . '%'); 845 } 846 break; 847 } 848 break; 849 } 850 unset($fields[$field_name]); 851 } elseif (str_starts_with($field_name, 'FAM:')) { 852 // e.g. searches for occupation, religion, note, etc. 853 // Initial matching only. Need PHP to apply filter. 854 $query->where('spouse_families.f_gedcom', $this->iLike(), "%\n1 " . $parts[1] . ' %' . $field_value . '%'); 855 } elseif (str_starts_with($field_name, 'INDI:') && str_ends_with($field_name, ':TYPE')) { 856 // Initial matching only. Need PHP to apply filter. 857 $query->where('individuals.i_gedcom', $this->iLike(), "%\n1 " . $parts[1] . "%\n2 TYPE %" . $field_value . '%'); 858 } elseif (str_starts_with($field_name, 'INDI:')) { 859 // e.g. searches for occupation, religion, note, etc. 860 // Initial matching only. Need PHP to apply filter. 861 $query->where('individuals.i_gedcom', $this->iLike(), "%\n1 " . $parts[1] . '%' . $parts[2] . '%' . $field_value . '%'); 862 } 863 } 864 865 return $query 866 ->get() 867 ->each($this->rowLimiter()) 868 ->map($this->individualRowMapper()) 869 ->filter(GedcomRecord::accessFilter()) 870 ->filter(static function (Individual $individual) use ($fields, $tree): bool { 871 // Check for searches which were only partially matched by SQL 872 foreach ($fields as $field_name => $field_value) { 873 $parts = explode(':', $field_name . '::::'); 874 875 if (str_starts_with($field_name, 'INDI:NAME:') && $field_name !== 'INDI:NAME:GIVN' && $field_name !== 'INDI:NAME:SURN') { 876 $regex = '/\n1 NAME.*(?:\n2.*)*\n2 ' . $parts[2] . ' .*' . preg_quote($field_value, '/') . '/i'; 877 878 if (preg_match($regex, $individual->gedcom()) === 1) { 879 continue; 880 } 881 882 return false; 883 } 884 885 if (str_starts_with($field_name, 'INDI:') && str_ends_with($field_name, ':PLAC')) { 886 $place = Place::find((int) $field_value, $tree); 887 888 foreach ($individual->facts([$parts[1]]) as $fact) { 889 if ($fact->place()->gedcomName() === $place->gedcomName() || str_ends_with($fact->place()->gedcomName(), ', ' . $place->gedcomName())) { 890 continue 2; 891 } 892 } 893 return false; 894 } 895 896 if (str_starts_with($field_name, 'FAM:') && str_ends_with($field_name, ':PLAC')) { 897 $place = Place::find((int) $field_value, $tree); 898 899 foreach ($individual->spouseFamilies() as $family) { 900 foreach ($family->facts([$parts[1]]) as $fact) { 901 if ($fact->place()->gedcomName() === $place->gedcomName() || str_ends_with($fact->place()->gedcomName(), ', ' . $place->gedcomName())) { 902 continue 3; 903 } 904 } 905 } 906 return false; 907 } 908 909 $regex = '/' . preg_quote($field_value, '/') . '/i'; 910 911 if ($field_name === 'INDI:FACT:TYPE' || $field_name === 'INDI:EVEN:TYPE' || $field_name === 'INDI:CHAN:_WT_USER') { 912 foreach ($individual->facts([$parts[1]]) as $fact) { 913 if (preg_match($regex, $fact->attribute($parts[2])) === 1) { 914 continue 2; 915 } 916 } 917 918 return false; 919 } 920 921 if (str_starts_with($field_name, 'INDI:')) { 922 foreach ($individual->facts([$parts[1]]) as $fact) { 923 if (preg_match($regex, $fact->value()) === 1) { 924 continue 2; 925 } 926 } 927 928 return false; 929 } 930 931 if (str_starts_with($field_name, 'FAM:')) { 932 foreach ($individual->spouseFamilies() as $family) { 933 foreach ($family->facts([$parts[1]]) as $fact) { 934 if (preg_match($regex, $fact->value()) === 1) { 935 continue 3; 936 } 937 } 938 } 939 return false; 940 } 941 } 942 943 return true; 944 }); 945 } 946 947 /** 948 * @param string $soundex 949 * @param string $lastname 950 * @param string $firstname 951 * @param string $place 952 * @param array<Tree> $search_trees 953 * 954 * @return Collection<int,Individual> 955 */ 956 public function searchIndividualsPhonetic(string $soundex, string $lastname, string $firstname, string $place, array $search_trees): Collection 957 { 958 switch ($soundex) { 959 default: 960 case 'Russell': 961 $givn_sdx = Soundex::russell($firstname); 962 $surn_sdx = Soundex::russell($lastname); 963 $plac_sdx = Soundex::russell($place); 964 $givn_field = 'n_soundex_givn_std'; 965 $surn_field = 'n_soundex_surn_std'; 966 $plac_field = 'p_std_soundex'; 967 break; 968 case 'DaitchM': 969 $givn_sdx = Soundex::daitchMokotoff($firstname); 970 $surn_sdx = Soundex::daitchMokotoff($lastname); 971 $plac_sdx = Soundex::daitchMokotoff($place); 972 $givn_field = 'n_soundex_givn_dm'; 973 $surn_field = 'n_soundex_surn_dm'; 974 $plac_field = 'p_dm_soundex'; 975 break; 976 } 977 978 // Nothing to search for? Return nothing. 979 if ($givn_sdx === '' && $surn_sdx === '' && $plac_sdx === '') { 980 return new Collection(); 981 } 982 983 $query = DB::table('individuals') 984 ->select(['individuals.*']) 985 ->distinct(); 986 987 $this->whereTrees($query, 'i_file', $search_trees); 988 989 if ($plac_sdx !== '') { 990 $query->join('placelinks', static function (JoinClause $join): void { 991 $join 992 ->on('placelinks.pl_file', '=', 'individuals.i_file') 993 ->on('placelinks.pl_gid', '=', 'individuals.i_id'); 994 }); 995 $query->join('places', static function (JoinClause $join): void { 996 $join 997 ->on('places.p_file', '=', 'placelinks.pl_file') 998 ->on('places.p_id', '=', 'placelinks.pl_p_id'); 999 }); 1000 1001 $this->wherePhonetic($query, $plac_field, $plac_sdx); 1002 } 1003 1004 if ($givn_sdx !== '' || $surn_sdx !== '') { 1005 $query->join('name', static function (JoinClause $join): void { 1006 $join 1007 ->on('name.n_file', '=', 'individuals.i_file') 1008 ->on('name.n_id', '=', 'individuals.i_id'); 1009 }); 1010 1011 $this->wherePhonetic($query, $givn_field, $givn_sdx); 1012 $this->wherePhonetic($query, $surn_field, $surn_sdx); 1013 } 1014 1015 return $query 1016 ->get() 1017 ->each($this->rowLimiter()) 1018 ->map($this->individualRowMapper()) 1019 ->filter(GedcomRecord::accessFilter()); 1020 } 1021 1022 /** 1023 * Paginate a search query. 1024 * 1025 * @param Builder $query Searches the database for the desired records. 1026 * @param Closure $row_mapper Converts a row from the query into a record. 1027 * @param Closure $row_filter 1028 * @param int $offset Skip this many rows. 1029 * @param int $limit Take this many rows. 1030 * 1031 * @return Collection<int,mixed> 1032 */ 1033 private function paginateQuery(Builder $query, Closure $row_mapper, Closure $row_filter, int $offset, int $limit): Collection 1034 { 1035 $collection = new Collection(); 1036 1037 foreach ($query->cursor() as $row) { 1038 $record = $row_mapper($row); 1039 // searchIndividualNames() and searchFamilyNames() can return duplicate rows, 1040 // where individuals have multiple names - and we need to sort results by name. 1041 if ($collection->containsStrict($record)) { 1042 continue; 1043 } 1044 // If the object has a method "canShow()", then use it to filter for privacy. 1045 if ($row_filter($record)) { 1046 if ($offset > 0) { 1047 $offset--; 1048 } else { 1049 if ($limit > 0) { 1050 $collection->push($record); 1051 } 1052 1053 $limit--; 1054 1055 if ($limit === 0) { 1056 break; 1057 } 1058 } 1059 } 1060 } 1061 1062 1063 return $collection; 1064 } 1065 1066 /** 1067 * Apply search filters to a SQL query column. Apply collation rules to MySQL. 1068 * 1069 * @param Builder $query 1070 * @param Expression|string $column 1071 * @param array<string> $search_terms 1072 */ 1073 private function whereSearch(Builder $query, Expression|string $column, array $search_terms): void 1074 { 1075 foreach ($search_terms as $search_term) { 1076 $query->where($column, $this->iLike(), '%' . addcslashes($search_term, '\\%_') . '%'); 1077 } 1078 } 1079 1080 /** 1081 * Apply soundex search filters to a SQL query column. 1082 * 1083 * @param Builder $query 1084 * @param Expression|string $field 1085 * @param string $soundex 1086 */ 1087 private function wherePhonetic(Builder $query, $field, string $soundex): void 1088 { 1089 if ($soundex !== '') { 1090 $query->where(function (Builder $query) use ($soundex, $field): void { 1091 foreach (explode(':', $soundex) as $sdx) { 1092 $query->orWhere($field, $this->iLike(), '%' . $sdx . '%'); 1093 } 1094 }); 1095 } 1096 } 1097 1098 /** 1099 * @param Builder $query 1100 * @param string $tree_id_field 1101 * @param array<Tree> $trees 1102 */ 1103 private function whereTrees(Builder $query, string $tree_id_field, array $trees): void 1104 { 1105 $tree_ids = array_map(static fn(Tree $tree): int => $tree->id(), $trees); 1106 1107 $query->whereIn($tree_id_field, $tree_ids); 1108 } 1109 1110 /** 1111 * Find the media object that uses a particular media file. 1112 * 1113 * @param string $file 1114 * 1115 * @return array<Media> 1116 */ 1117 public function findMediaObjectsForMediaFile(string $file): array 1118 { 1119 return DB::table('media') 1120 ->join('media_file', static function (JoinClause $join): void { 1121 $join 1122 ->on('media_file.m_file', '=', 'media.m_file') 1123 ->on('media_file.m_id', '=', 'media.m_id'); 1124 }) 1125 ->join('gedcom_setting', 'media.m_file', '=', 'gedcom_setting.gedcom_id') 1126 ->where(new Expression('setting_value || multimedia_file_refn'), '=', $file) 1127 ->select(['media.*']) 1128 ->distinct() 1129 ->get() 1130 ->map($this->mediaRowMapper()) 1131 ->all(); 1132 } 1133 1134 /** 1135 * A closure to filter records by privacy-filtered GEDCOM data. 1136 * 1137 * @param array<string> $search_terms 1138 * 1139 * @return Closure(GedcomRecord):bool 1140 */ 1141 private function rawGedcomFilter(array $search_terms): Closure 1142 { 1143 return static function (GedcomRecord $record) use ($search_terms): bool { 1144 // Ignore non-genealogy fields 1145 $gedcom = preg_replace('/\n\d (?:_UID|_WT_USER) .*/', '', $record->gedcom()); 1146 1147 // Ignore matches in links 1148 $gedcom = preg_replace('/\n\d ' . Gedcom::REGEX_TAG . '( @' . Gedcom::REGEX_XREF . '@)?/', '', $gedcom); 1149 1150 // Re-apply the filtering 1151 foreach ($search_terms as $search_term) { 1152 if (mb_stripos($gedcom, $search_term) === false) { 1153 return false; 1154 } 1155 } 1156 1157 return true; 1158 }; 1159 } 1160 1161 /** 1162 * Searching for short or common text can give more results than the system can process. 1163 * 1164 * @param int $limit 1165 * 1166 * @return Closure():void 1167 */ 1168 private function rowLimiter(int $limit = self::MAX_SEARCH_RESULTS): Closure 1169 { 1170 return static function () use ($limit): void { 1171 static $n = 0; 1172 1173 if (++$n > $limit) { 1174 $message = I18N::translate('The search returned too many results.'); 1175 1176 throw new HttpServiceUnavailableException($message); 1177 } 1178 }; 1179 } 1180 1181 /** 1182 * Convert a row from any tree in the families table into a family object. 1183 * 1184 * @return Closure(object):Family 1185 */ 1186 private function familyRowMapper(): Closure 1187 { 1188 return function (object $row): Family { 1189 $tree = $this->tree_service->find((int) $row->f_file); 1190 1191 return Registry::familyFactory()->mapper($tree)($row); 1192 }; 1193 } 1194 1195 /** 1196 * Convert a row from any tree in the individuals table into an individual object. 1197 * 1198 * @return Closure(object):Individual 1199 */ 1200 private function individualRowMapper(): Closure 1201 { 1202 return function (object $row): Individual { 1203 $tree = $this->tree_service->find((int) $row->i_file); 1204 1205 return Registry::individualFactory()->mapper($tree)($row); 1206 }; 1207 } 1208 1209 /** 1210 * Convert a row from any tree in the media table into a location object. 1211 * 1212 * @return Closure(object):Location 1213 */ 1214 private function locationRowMapper(): Closure 1215 { 1216 return function (object $row): Location { 1217 $tree = $this->tree_service->find((int) $row->o_file); 1218 1219 return Registry::locationFactory()->mapper($tree)($row); 1220 }; 1221 } 1222 1223 /** 1224 * Convert a row from any tree in the media table into an media object. 1225 * 1226 * @return Closure(object):Media 1227 */ 1228 private function mediaRowMapper(): Closure 1229 { 1230 return function (object $row): Media { 1231 $tree = $this->tree_service->find((int) $row->m_file); 1232 1233 return Registry::mediaFactory()->mapper($tree)($row); 1234 }; 1235 } 1236 1237 /** 1238 * Convert a row from any tree in the other table into a note object. 1239 * 1240 * @return Closure:Note 1241 */ 1242 private function noteRowMapper(): Closure 1243 { 1244 return function (object $row): Note { 1245 $tree = $this->tree_service->find((int) $row->o_file); 1246 1247 return Registry::noteFactory()->mapper($tree)($row); 1248 }; 1249 } 1250 1251 /** 1252 * Convert a row from any tree in the other table into a repository object. 1253 * 1254 * @return Closure:Repository 1255 */ 1256 private function repositoryRowMapper(): Closure 1257 { 1258 return function (object $row): Repository { 1259 $tree = $this->tree_service->find((int) $row->o_file); 1260 1261 return Registry::repositoryFactory()->mapper($tree)($row); 1262 }; 1263 } 1264 1265 /** 1266 * Convert a row from any tree in the other table into a note object. 1267 * 1268 * @return Closure(object):SharedNote 1269 */ 1270 private function sharedNoteRowMapper(): Closure 1271 { 1272 return function (object $row): Note { 1273 $tree = $this->tree_service->find((int) $row->o_file); 1274 1275 return Registry::sharedNoteFactory()->mapper($tree)($row); 1276 }; 1277 } 1278 1279 /** 1280 * Convert a row from any tree in the sources table into a source object. 1281 * 1282 * @return Closure:Source 1283 */ 1284 private function sourceRowMapper(): Closure 1285 { 1286 return function (object $row): Source { 1287 $tree = $this->tree_service->find((int) $row->s_file); 1288 1289 return Registry::sourceFactory()->mapper($tree)($row); 1290 }; 1291 } 1292 1293 /** 1294 * Convert a row from any tree in the other table into a submission object. 1295 * 1296 * @return Closure(object):Submission 1297 */ 1298 private function submissionRowMapper(): Closure 1299 { 1300 return function (object $row): Submission { 1301 $tree = $this->tree_service->find((int) $row->o_file); 1302 1303 return Registry::submissionFactory()->mapper($tree)($row); 1304 }; 1305 } 1306 1307 /** 1308 * Convert a row from any tree in the other table into a submitter object. 1309 * 1310 * @return Closure(object):Submitter 1311 */ 1312 private function submitterRowMapper(): Closure 1313 { 1314 return function (object $row): Submitter { 1315 $tree = $this->tree_service->find((int) $row->o_file); 1316 1317 return Registry::submitterFactory()->mapper($tree)($row); 1318 }; 1319 } 1320 1321 /** 1322 * @internal - a better solution would support other RDBMS, probably by using collations. 1323 */ 1324 private function iLike(): string 1325 { 1326 if (DB::connection()->getDriverName() === 'pgsql') { 1327 return 'ILIKE'; 1328 } 1329 1330 return 'LIKE'; 1331 } 1332} 1333