├── busca_desaparecidos ├── __init__.py ├── tests │ ├── __init__.py │ └── test_dao.py ├── queries │ ├── __init__.py │ └── rank.py └── dao.py ├── requirements.txt ├── setup.cfg ├── Makefile ├── README.md ├── setup.py └── .gitignore /busca_desaparecidos/__init__.py: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /busca_desaparecidos/tests/__init__.py: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /requirements.txt: -------------------------------------------------------------------------------- 1 | cx-Oracle==7.3.0 2 | -------------------------------------------------------------------------------- /busca_desaparecidos/queries/__init__.py: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /setup.cfg: -------------------------------------------------------------------------------- 1 | [bdist_wheel] 2 | universal=1 3 | 4 | [metadata] 5 | description-file=README.md 6 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | clean: 2 | find . -type f -name "*.py[co]" -delete 3 | find . -type d -name "__pycache__" -delete 4 | 5 | test:clean 6 | py.test --verbose --color=yes -s ./ 7 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Projeto Deprecado 2 | 3 | O código deste pacote foi incorporado pela nossa [API genérica](https://github.com/MinisterioPublicoRJ/apimpmapas) 4 | 5 | 6 | # Busca Desaparecidos 7 | 8 | version 0.0.6dev0 9 | 10 | Python package for helping localizing missing persons 11 | 12 | ## Installing 13 | 14 | python3 -m venv env 15 | source env/bin/activate 16 | pip install -r requirements.txt 17 | 18 | Also, make sure to install [Oracle Client libraries](https://oracle.github.io/odpi/doc/installation.html), 64-bit version, Basic Light Edition. Note that you have to be logged in Oracle website (create a free account). 19 | 20 | ### Mac 21 | 22 | On a Mac, after downloading the zip, you can: 23 | 24 | cd ~/Downloads 25 | sudo su 26 | mkdir -p /opt/oracle 27 | mv instantclient-*.zip /opt/oracle 28 | cd /opt/oracle 29 | unzip *.zip 30 | exit 31 | mkdir ~/lib 32 | ln -s /opt/oracle/instantclient_12_2/libclntsh.dylib.12.1 ~/lib/ 33 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from setuptools import setup, find_packages 2 | from codecs import open 3 | from os import path 4 | 5 | __version__ = '0.0.6dev0' 6 | 7 | here = path.abspath(path.dirname(__file__)) 8 | 9 | # Get the long description from the README file 10 | with open(path.join(here, 'README.md'), encoding='utf-8') as f: 11 | long_description = f.read() 12 | 13 | # get the dependencies and installs 14 | with open(path.join(here, 'requirements.txt'), encoding='utf-8') as f: 15 | all_reqs = f.read().split('\n') 16 | 17 | install_requires = [x.strip() for x in all_reqs if 'git+' not in x] 18 | dependency_links = [x.strip().replace('git+', '') for x in all_reqs if x.startswith('git+')] 19 | 20 | setup( 21 | name='busca_desaparecidos', 22 | version=__version__, 23 | description='A python package to help finding missing persosn', 24 | long_description=long_description, 25 | long_description_content_type='text/markdown', 26 | url='https://github.com/MinisterioPublicoRJ', 27 | license='MIT', 28 | classifiers=[ 29 | 'Development Status :: 3 - Alpha', 30 | 'Intended Audience :: Developers', 31 | 'Programming Language :: Python :: 3', 32 | ], 33 | keywords='', 34 | packages=find_packages(exclude=['docs', 'tests*']), 35 | include_package_data=True, 36 | author='Ministério Público do Rio de Janeiro', 37 | install_requires=install_requires, 38 | dependency_links=dependency_links, 39 | ) 40 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Created by https://www.gitignore.io 2 | 3 | ### OSX ### 4 | .DS_Store 5 | .AppleDouble 6 | .LSOverride 7 | 8 | # Icon must end with two \r 9 | Icon 10 | 11 | 12 | # Thumbnails 13 | ._* 14 | 15 | # Files that might appear on external disk 16 | .Spotlight-V100 17 | .Trashes 18 | 19 | # Directories potentially created on remote AFP share 20 | .AppleDB 21 | .AppleDesktop 22 | Network Trash Folder 23 | Temporary Items 24 | .apdisk 25 | 26 | 27 | ### Python ### 28 | # Byte-compiled / optimized / DLL files 29 | __pycache__/ 30 | *.py[cod] 31 | 32 | # C extensions 33 | *.so 34 | 35 | # Distribution / packaging 36 | .Python 37 | env/ 38 | build/ 39 | develop-eggs/ 40 | dist/ 41 | downloads/ 42 | eggs/ 43 | lib/ 44 | lib64/ 45 | parts/ 46 | sdist/ 47 | var/ 48 | *.egg-info/ 49 | .installed.cfg 50 | *.egg 51 | 52 | # PyInstaller 53 | # Usually these files are written by a python script from a template 54 | # before PyInstaller builds the exe, so as to inject date/other infos into it. 55 | *.manifest 56 | *.spec 57 | 58 | # Installer logs 59 | pip-log.txt 60 | pip-delete-this-directory.txt 61 | 62 | # Unit test / coverage reports 63 | htmlcov/ 64 | .tox/ 65 | .coverage 66 | .cache 67 | nosetests.xml 68 | coverage.xml 69 | 70 | # Translations 71 | *.mo 72 | *.pot 73 | 74 | # Sphinx documentation 75 | docs/_build/ 76 | 77 | # PyBuilder 78 | target/ 79 | 80 | 81 | ### Django ### 82 | *.log 83 | *.pot 84 | *.pyc 85 | __pycache__/ 86 | local_settings.py 87 | 88 | settings.ini 89 | .env 90 | db.sqlite3 91 | -------------------------------------------------------------------------------- /busca_desaparecidos/dao.py: -------------------------------------------------------------------------------- 1 | import datetime 2 | import json 3 | 4 | import cx_Oracle 5 | 6 | from busca_desaparecidos.queries.rank import query as q_rank 7 | 8 | 9 | def client(db_username, db_pwd, db_host): 10 | orcl = cx_Oracle.connect( 11 | db_username, 12 | db_pwd, 13 | db_host 14 | ) 15 | cursor = orcl.cursor() 16 | return cursor 17 | 18 | 19 | def format_query(query, id_sinalid): 20 | return query.replace("{{ id_sinalid }}", id_sinalid) 21 | 22 | 23 | def rank_query(cursor, id_sinalid): 24 | f_query = format_query(q_rank, id_sinalid) 25 | cursor.execute(f_query) 26 | return cursor.fetchall() 27 | 28 | 29 | def serialize(result_set, limit=None): 30 | def default(o): 31 | if isinstance(o, (datetime.date, datetime.datetime)): 32 | return o.isoformat() 33 | 34 | columns = [ 35 | "busca_id_sinalid", 36 | "candidato_id_sinalid", 37 | "data_nascimento", 38 | "score_sexo", 39 | "score_data_fato", 40 | "score_idade", 41 | "score_distancia", 42 | "score_total", 43 | ] 44 | limit = limit if limit else len(result_set) 45 | return json.loads(json.dumps( 46 | [dict(zip(columns, res)) for res in result_set[:limit]], 47 | default=default, 48 | )) 49 | 50 | 51 | def rank(cursor, id_sinalid, limit=100): 52 | result_set = rank_query(cursor, id_sinalid) 53 | return serialize(result_set, limit) if result_set\ 54 | else {'erro': 'ID Sinalid não encontrado'} 55 | -------------------------------------------------------------------------------- /busca_desaparecidos/tests/test_dao.py: -------------------------------------------------------------------------------- 1 | from datetime import datetime 2 | from unittest import TestCase, mock 3 | 4 | from busca_desaparecidos.dao import ( 5 | format_query, 6 | rank_query, 7 | serialize, 8 | rank, 9 | ) 10 | 11 | 12 | class Dao(TestCase): 13 | def test_format_rank_query(self): 14 | query = """ 15 | SELECT * FROM table WHERE id_sinalid = '{{ id_sinalid }}' 16 | """ 17 | 18 | id_sinalid = "1234" 19 | formatted_query = format_query(query, id_sinalid) 20 | expected_query = """ 21 | SELECT * FROM table WHERE id_sinalid = '1234' 22 | """ 23 | 24 | self.assertEqual(formatted_query, expected_query) 25 | 26 | @mock.patch("busca_desaparecidos.dao.q_rank") 27 | @mock.patch('busca_desaparecidos.dao.format_query', 28 | return_value="formatted query") 29 | def test_rank_query(self, _format_query, _query): 30 | cursor_mock = mock.MagicMock() 31 | cursor_mock.fetchall.return_value = [(1, 2, 3), (4, 5, 6)] 32 | 33 | id_sinalid = "1234" 34 | result = rank_query(cursor_mock, id_sinalid) 35 | 36 | _format_query.assert_called_once_with(_query, id_sinalid) 37 | cursor_mock.execute.assert_called_once_with("formatted query") 38 | cursor_mock.fetchall.assert_called_once_with() 39 | self.assertEqual(result, [(1, 2, 3), (4, 5, 6)]) 40 | 41 | def test_serialize_to_json(self): 42 | oracle_resp = [ 43 | ('id 1', 44 | 'id 2', 45 | datetime(1941, 4, 27, 0, 0), 46 | 0.01, 47 | 0, 48 | 0, 49 | 0, 50 | 0.01), 51 | ('id 3', 52 | 'id 4', 53 | datetime(1972, 4, 27, 0, 0), 54 | 0.01, 55 | 0, 56 | 0, 57 | 0, 58 | 0.01) 59 | ] 60 | 61 | resp_json = serialize(oracle_resp) 62 | expected = [ 63 | { 64 | "busca_id_sinalid": "id 1", 65 | "candidato_id_sinalid": "id 2", 66 | "data_nascimento": "1941-04-27T00:00:00", 67 | "score_sexo": 0.01, 68 | "score_data_fato": 0, 69 | "score_idade": 0, 70 | "score_distancia": 0, 71 | "score_total": 0.01 72 | }, 73 | 74 | { 75 | "busca_id_sinalid": "id 3", 76 | "candidato_id_sinalid": "id 4", 77 | "data_nascimento": "1972-04-27T00:00:00", 78 | "score_sexo": 0.01, 79 | "score_data_fato": 0, 80 | "score_idade": 0, 81 | "score_distancia": 0, 82 | "score_total": 0.01 83 | } 84 | ] 85 | 86 | self.assertEqual(resp_json, expected) 87 | 88 | @mock.patch("busca_desaparecidos.dao.serialize", return_value="ser result") 89 | @mock.patch("busca_desaparecidos.dao.rank_query", return_value="result") 90 | def test_whole_workflow(self, _rank_query, _serialize): 91 | cursor = mock.MagicMock() 92 | id_sinalid = "1234" 93 | 94 | result = rank(cursor, id_sinalid) 95 | 96 | _rank_query.assert_called_once_with(cursor, id_sinalid) 97 | _serialize.assert_called_once_with("result", 100) 98 | self.assertEqual(result, "ser result") 99 | 100 | @mock.patch("busca_desaparecidos.dao.serialize", return_value="ser result") 101 | @mock.patch("busca_desaparecidos.dao.rank_query", return_value="result") 102 | def test_whole_workflow_with_limit(self, _rank_query, _serialize): 103 | cursor = mock.MagicMock() 104 | id_sinalid = "1234" 105 | 106 | result = rank(cursor, id_sinalid, limit=200) 107 | 108 | _rank_query.assert_called_once_with(cursor, id_sinalid) 109 | _serialize.assert_called_once_with("result", 200) 110 | self.assertEqual(result, "ser result") 111 | 112 | @mock.patch("busca_desaparecidos.dao.serialize") 113 | @mock.patch("busca_desaparecidos.dao.rank_query", return_value=[]) 114 | def test_whole_workflow_empty_response(self, _rank_query, _serialize): 115 | cursor = mock.MagicMock() 116 | id_sinalid = "1234" 117 | 118 | result = rank(cursor, id_sinalid, limit=200) 119 | 120 | _rank_query.assert_called_once_with(cursor, id_sinalid) 121 | _serialize.assert_not_called() 122 | self.assertEqual(result, {'erro': 'ID Sinalid não encontrado'}) 123 | -------------------------------------------------------------------------------- /busca_desaparecidos/queries/rank.py: -------------------------------------------------------------------------------- 1 | query = """WITH 2 | SID_IDADE_APARENTE AS ( 3 | SELECT SIDP_DK, 4 | CAST(NVL(SUBSTR(SIDP_NM_IDADE_APARENTE, 1, INSTR(SIDP_NM_IDADE_APARENTE, '-')-1), 1) AS INT) AS INICIO, 5 | CAST(REPLACE(REPLACE(SUBSTR(SIDP_NM_IDADE_APARENTE, INSTR(SIDP_NM_IDADE_APARENTE, '-')+1), '>',''), '<','') AS INT) AS FIM 6 | FROM SILD.SILD_IDADE_APARENTE 7 | WHERE SILD_IDADE_APARENTE.SIDP_DK <> 19 8 | ), 9 | PESSOAS_POSSIVEIS AS ( 10 | SELECT 11 | VTMA_DT_NASCIMENTO, 12 | FLOOR(MONTHS_BETWEEN(SNCA_DT_FATO, SILD_VITIMA.VTMA_DT_NASCIMENTO) / 12) IDADE, 13 | VTMA_IN_SEXO, 14 | CASE 15 | WHEN SNCA_DT_FATO < to_date('1900-01-01', 'yyyy-mm-dd') THEN to_date('1900-01-01', 'yyyy-mm-dd') 16 | ELSE SNCA_DT_FATO 17 | END SNCA_DT_FATO, 18 | BAIR_LATITUDE, 19 | BAIR_LONGITUDE, 20 | BAIR_NM_BAIRRO, 21 | VTMA_SIDP_DK, 22 | CASE 23 | WHEN VTMA_DT_NASCIMENTO IS NULL AND VTMA_SIDP_DK IS NULL THEN NULL 24 | WHEN VTMA_DT_NASCIMENTO IS NOT NULL THEN ( 25 | SELECT MAX(SIDP_DK) 26 | FROM 27 | SID_IDADE_APARENTE 28 | WHERE CAST(ABS(SNCA_DT_FATO - VTMA_DT_NASCIMENTO)/365.2425 AS INT) 29 | BETWEEN SID_IDADE_APARENTE.INICIO AND SID_IDADE_APARENTE.FIM 30 | ) 31 | ELSE 32 | VTMA_SIDP_DK 33 | END IDADE_APARENTE_PESSOA, 34 | CASE 35 | WHEN CIDA_LATITUDE IS NULL THEN 36 | (SELECT CIDA_LATITUDE FROM CORP.CORP_CIDADE WHERE CIDA_DK = BAIR_CIDA_DK) 37 | ELSE CIDA_LATITUDE 38 | END CIDA_LATITUDE, 39 | CASE WHEN CIDA_LONGITUDE IS NULL THEN 40 | (SELECT CIDA_LONGITUDE FROM CORP.CORP_CIDADE WHERE CIDA_DK = BAIR_CIDA_DK) 41 | ELSE CIDA_LONGITUDE 42 | END CIDA_LONGITUDE, 43 | CASE 44 | WHEN CIDA_NM_CIDADE IS NULL THEN 45 | (SELECT CIDA_NM_CIDADE FROM CORP.CORP_CIDADE WHERE CIDA_DK = BAIR_CIDA_DK) 46 | ELSE CIDA_NM_CIDADE 47 | END CIDA_NM_CIDADE, 48 | SNCA_IDENTIFICADOR_SINALID 49 | FROM SILD_SINDICANCIA 50 | LEFT JOIN 51 | SILD_ENDERECO_FATO ON SILD_SINDICANCIA.SNCA_DK = SILD_ENDERECO_FATO.SIES_SNCA_DK 52 | LEFT JOIN 53 | CORP.CORP_CIDADE 54 | ON SILD_ENDERECO_FATO.SIES_CIDA_DK = CORP.CORP_CIDADE.CIDA_DK 55 | LEFT JOIN 56 | CORP.CORP_BAIRRO 57 | ON SILD_ENDERECO_FATO.SIES_BAIR_DK = CORP.CORP_BAIRRO.BAIR_DK 58 | LEFT JOIN 59 | SILD_DOCUMENTO 60 | ON SILD_SINDICANCIA.SNCA_DK = SILD_DOCUMENTO.DMTO_SNCA_DK 61 | AND SILD_DOCUMENTO.DMTO_TDCT_DK = 5 62 | LEFT JOIN 63 | SILD_BLOB_DOCUMENTO 64 | ON SILD_DOCUMENTO.DMTO_DK = SILD_BLOB_DOCUMENTO.BDMT_DMTO_DK 65 | LEFT JOIN 66 | SILD_VITIMA 67 | ON SILD_VITIMA.VTMA_DK = SILD_SINDICANCIA.SNCA_VTMA_DK 68 | ), 69 | SCORES AS ( 70 | SELECT ALVO.SNCA_IDENTIFICADOR_SINALID AS SNCA_IDENTIFICADOR_ALVO, 71 | TODOMUNDO.SNCA_IDENTIFICADOR_SINALID AS SNCA_IDENTIFICADOR_TODOMUNDO, 72 | TODOMUNDO.VTMA_DT_NASCIMENTO, 73 | CASE 74 | WHEN ALVO.VTMA_IN_SEXO IS NULL THEN 0.01 75 | WHEN TODOMUNDO.VTMA_IN_SEXO IS NULL THEN 0.5 76 | WHEN ALVO.VTMA_IN_SEXO = TODOMUNDO.VTMA_IN_SEXO THEN 0.01 77 | WHEN ALVO.VTMA_IN_SEXO <> TODOMUNDO.VTMA_IN_SEXO THEN 1 78 | END SEX_SCORE, 79 | CASE 80 | WHEN ALVO.SNCA_DT_FATO IS NOT NULL AND TODOMUNDO.SNCA_DT_FATO IS NOT NULL THEN 81 | trunc(ABS(ALVO.SNCA_DT_FATO - TODOMUNDO.SNCA_DT_FATO)) 82 | ELSE null 83 | END DATE_SCORE, 84 | CASE 85 | WHEN ALVO.VTMA_DT_NASCIMENTO IS NULL AND ALVO.VTMA_SIDP_DK IS NULL THEN 19 86 | WHEN TODOMUNDO.VTMA_DT_NASCIMENTO IS NULL AND TODOMUNDO.VTMA_SIDP_DK IS NULL THEN 19 87 | ELSE 88 | ABS(( 89 | SELECT MAX(SIDP_DK) 90 | FROM 91 | SID_IDADE_APARENTE 92 | WHERE CAST(ABS(TODOMUNDO.SNCA_DT_FATO - ALVO.VTMA_DT_NASCIMENTO)/365.2425 AS INT) 93 | BETWEEN SID_IDADE_APARENTE.INICIO AND SID_IDADE_APARENTE.FIM 94 | ) - TODOMUNDO.IDADE_APARENTE_PESSOA) 95 | END DIFERENCA_IDADE_APARENTE, 96 | CASE 97 | WHEN alvo.bair_latitude IS NULL AND alvo.cida_latitude IS NULL THEN 0.0 98 | WHEN todomundo.bair_latitude IS NULL AND todomundo.cida_latitude IS NULL THEN null 99 | else 100 | SQRT( 101 | POWER( 102 | NVL(ALVO.BAIR_LATITUDE, ALVO.CIDA_LATITUDE) 103 | - 104 | NVL(TODOMUNDO.BAIR_LATITUDE, TODOMUNDO.CIDA_LATITUDE), 105 | 2) + 106 | POWER( 107 | NVL(ALVO.BAIR_LONGITUDE, ALVO.CIDA_LONGITUDE) 108 | - 109 | NVL(TODOMUNDO.BAIR_LONGITUDE, TODOMUNDO.CIDA_LONGITUDE), 110 | 2) 111 | ) 112 | END DISTANCIA 113 | FROM PESSOAS_POSSIVEIS TODOMUNDO 114 | INNER JOIN PESSOAS_POSSIVEIS ALVO ON 1=1 115 | WHERE ALVO.SNCA_IDENTIFICADOR_SINALID = '{{ id_sinalid }}' 116 | ), 117 | nulospreenchidos AS ( 118 | SELECT 119 | SNCA_IDENTIFICADOR_ALVO, 120 | SNCA_IDENTIFICADOR_TODOMUNDO, 121 | VTMA_DT_NASCIMENTO, 122 | nvl(SEX_SCORE, 123 | (SELECT max(sex_score) FROM SCORES)+1) AS SEX_SCORE, 124 | nvl(DATE_SCORE, 125 | (SELECT max(DATE_SCORE) FROM SCORES)+1) AS DATE_SCORE, 126 | nvl(DIFERENCA_IDADE_APARENTE, 127 | (SELECT max(DIFERENCA_IDADE_APARENTE) FROM SCORES)+1) AS DIFERENCA_IDADE_APARENTE, 128 | nvl(DISTANCIA, 129 | (SELECT max(DISTANCIA) FROM SCORES)+1) AS DISTANCIA 130 | FROM SCORES 131 | ), 132 | maximos AS ( 133 | SELECT 134 | SNCA_IDENTIFICADOR_ALVO, 135 | SNCA_IDENTIFICADOR_TODOMUNDO, 136 | VTMA_DT_NASCIMENTO, 137 | SEX_SCORE, 138 | DATE_SCORE, 139 | DIFERENCA_IDADE_APARENTE, 140 | DISTANCIA, 141 | (SELECT max(sex_score) FROM nulospreenchidos) M_SEX_SCORE, 142 | (SELECT max(DATE_SCORE) FROM nulospreenchidos) M_DATE_SCORE, 143 | (SELECT max(DIFERENCA_IDADE_APARENTE) FROM nulospreenchidos) M_DIFERENCA_IDADE_APARENTE, 144 | (SELECT max(DISTANCIA) FROM nulospreenchidos) M_DISTANCIA 145 | FROM nulospreenchidos 146 | ), 147 | normalizada AS ( 148 | SELECT 149 | SNCA_IDENTIFICADOR_ALVO, 150 | SNCA_IDENTIFICADOR_TODOMUNDO, 151 | VTMA_DT_NASCIMENTO, 152 | SEX_SCORE, 153 | SEX_SCORE/M_SEX_SCORE AS N_SEX_SCORE, 154 | DATE_SCORE, 155 | DATE_SCORE/M_DATE_SCORE AS N_DATE_SCORE, 156 | DIFERENCA_IDADE_APARENTE, 157 | DIFERENCA_IDADE_APARENTE/M_DIFERENCA_IDADE_APARENTE AS N_DIFERENCA_IDADE_APARENTE, 158 | DISTANCIA, 159 | DISTANCIA/M_DISTANCIA AS N_DISTANCIA 160 | FROM maximos 161 | GROUP BY 162 | SNCA_IDENTIFICADOR_ALVO, 163 | SNCA_IDENTIFICADOR_TODOMUNDO, 164 | VTMA_DT_NASCIMENTO, 165 | SEX_SCORE, 166 | DATE_SCORE, 167 | DIFERENCA_IDADE_APARENTE, 168 | DISTANCIA, 169 | M_SEX_SCORE, 170 | M_DATE_SCORE, 171 | M_DIFERENCA_IDADE_APARENTE, 172 | M_DISTANCIA 173 | 174 | ) 175 | SELECT 176 | SNCA_IDENTIFICADOR_ALVO, 177 | SNCA_IDENTIFICADOR_TODOMUNDO, 178 | VTMA_DT_NASCIMENTO, 179 | N_SEX_SCORE, 180 | N_DATE_SCORE, 181 | N_DIFERENCA_IDADE_APARENTE, 182 | N_DISTANCIA, 183 | N_SEX_SCORE+N_DATE_SCORE+N_DIFERENCA_IDADE_APARENTE+N_DISTANCIA AS SOMA 184 | FROM normalizada 185 | ORDER BY N_SEX_SCORE+N_DATE_SCORE+N_DIFERENCA_IDADE_APARENTE+N_DISTANCIA 186 | """ 187 | --------------------------------------------------------------------------------