mirror of
https://github.com/gevera/hot-cold-cities.git
synced 2025-12-06 08:18:19 +00:00
89 lines
3.0 KiB
TypeScript
89 lines
3.0 KiB
TypeScript
import db from ".";
|
|
|
|
// export const allCountries = db.query('SELECT id, name, native, emoji FROM countries');
|
|
export const allCountries = db.query(`
|
|
SELECT id, name, native, emoji
|
|
FROM countries
|
|
WHERE id IN(
|
|
SELECT DISTINCT country_id
|
|
FROM cities
|
|
WHERE capital IN('capital', 'admin') OR(population >= 100000 AND population IS NOT NULL)
|
|
)
|
|
`);
|
|
|
|
export const allCities = db.query("SELECT id, city as name, country_id, lat as latitude, lng as longitude FROM cities WHERE capital IN ('capital', 'admin') OR (population >= 100000 AND population != '')");
|
|
export const allCitiesWithNoTemperatureToday = db.query(`
|
|
SELECT c.id, c.city as name, c.country_id, c.lat as latitude, c.lng as longitude
|
|
FROM cities c
|
|
LEFT JOIN meteo_data md ON c.id = md.city_id AND md.date = $date
|
|
WHERE (c.capital IN ('capital', 'admin') OR (c.population >= 100000 AND c.population != ''))
|
|
AND md.city_id IS NULL;
|
|
`);
|
|
|
|
export const cityTemperatureToday = db.query(`
|
|
SELECT c.id, c.city as name, md.min, md.max, md.date
|
|
FROM cities as c
|
|
JOIN meteo_data as md ON c.id = md.city_id
|
|
WHERE c.id = $id
|
|
AND md.date = $date
|
|
`);
|
|
|
|
export const insertCityTemperatureData = db.query(`
|
|
INSERT INTO meteo_data (city_id, min, max, date)
|
|
VALUES ($id, $min, $max, $date)
|
|
`);
|
|
export const getAllCitiesInCountryByTemp = db.query(`
|
|
SELECT
|
|
c.id as city_id,
|
|
c.city as city_name,
|
|
md.max as max_temp,
|
|
md.min as min_temp,
|
|
md.date
|
|
FROM cities c
|
|
JOIN meteo_data md ON c.id = md.city_id
|
|
WHERE c.country_id = $country_id
|
|
AND md.date = $date
|
|
ORDER BY md.max DESC
|
|
`);
|
|
|
|
export const getHottestAndColdestCityInCountry = db.query(`
|
|
WITH city_temps AS (
|
|
SELECT
|
|
c.id as city_id,
|
|
c.city as city_name,
|
|
c.country_id,
|
|
md.max as max_temp,
|
|
md.date,
|
|
ROW_NUMBER() OVER (PARTITION BY c.country_id ORDER BY md.max DESC) as hottest_rank,
|
|
ROW_NUMBER() OVER (PARTITION BY c.country_id ORDER BY md.max ASC) as coldest_rank
|
|
FROM cities c
|
|
JOIN meteo_data md ON c.id = md.city_id
|
|
WHERE md.date = $date
|
|
AND c.country_id = $country_id
|
|
)
|
|
SELECT * FROM city_temps
|
|
WHERE hottest_rank = 1 OR coldest_rank = 1
|
|
`);
|
|
|
|
export const getHottestAndColdestCityInWorld = db.query(`
|
|
WITH city_temps AS (
|
|
SELECT
|
|
c.id as city_id,
|
|
c.city as city_name,
|
|
c.country_id,
|
|
co.name as country_name,
|
|
md.max as max_temp,
|
|
md.min as min_temp,
|
|
md.date,
|
|
ROW_NUMBER() OVER (ORDER BY md.max DESC) as hottest_rank,
|
|
ROW_NUMBER() OVER (ORDER BY md.min ASC) as coldest_rank
|
|
FROM cities c
|
|
JOIN meteo_data md ON c.id = md.city_id
|
|
JOIN countries co ON c.country_id = co.id
|
|
WHERE md.date = $date
|
|
)
|
|
SELECT * FROM city_temps
|
|
WHERE hottest_rank = 1 OR coldest_rank = 1
|
|
LIMIT 2
|
|
`);
|