use std::io::Write;

use chrono::NaiveDate;
use ics::{
    properties::{DtStart, Summary},
    Event, ICalendar,
};
use serde::Serialize;
use sqlx::{FromRow, Row, SqlitePool};

use super::{notification::Notification, tripdetails::TripDetails, triptype::TripType, user::User};

#[derive(Serialize, Clone, FromRow, Debug, PartialEq)]
pub struct PlannedEvent {
    pub id: i64,
    pub name: String,
    planned_amount_cox: i64,
    trip_details_id: i64,
    pub planned_starting_time: String,
    pub(crate) max_people: i64,
    pub day: String,
    pub notes: Option<String>,
    pub allow_guests: bool,
    trip_type_id: Option<i64>,
    always_show: bool,
    is_locked: bool,
}

#[derive(Serialize, Debug)]
pub struct PlannedEventWithUserAndTriptype {
    #[serde(flatten)]
    pub planned_event: PlannedEvent,
    trip_type: Option<TripType>,
    cox_needed: bool,
    cox: Vec<Registration>,
    rower: Vec<Registration>,
}

//TODO: move to appropriate place
#[derive(Serialize, Debug)]
pub struct Registration {
    pub name: String,
    pub registered_at: String,
    pub is_guest: bool,
    pub is_real_guest: bool,
}

impl Registration {
    pub async fn all_rower(db: &SqlitePool, trip_details_id: i64) -> Vec<Registration> {
        sqlx::query(
            &format!(
            r#"
SELECT
    (SELECT name FROM user WHERE user_trip.user_id = user.id) as "name?", 
    user_note,
    user_id,
    (SELECT created_at FROM user WHERE user_trip.user_id = user.id) as registered_at,
    (SELECT EXISTS (SELECT 1 FROM user_role WHERE user_role.user_id = user_trip.user_id AND user_role.role_id = (SELECT id FROM role WHERE name = 'scheckbuch'))) as is_guest
FROM user_trip WHERE trip_details_id = {} 
        "#,trip_details_id),
        )
        .fetch_all(db)
        .await
        .unwrap()
        .into_iter()
        .map(|r|
            Registration {
            name: r.get::<Option<String>, usize>(0).or(r.get::<Option<String>, usize>(1)).unwrap(), //Ok, either name or user_note needs to be set
            registered_at: r.get::<String,usize>(3),
            is_guest: r.get::<bool, usize>(4),
            is_real_guest: r.get::<Option<i64>, usize>(2).is_none(),
        })
        .collect()
    }

    pub async fn all_cox(db: &SqlitePool, trip_details_id: i64) -> Vec<Registration> {
        //TODO: switch to join
        sqlx::query!(
            "
SELECT
    (SELECT name FROM user WHERE cox_id = id) as name,
    (SELECT created_at FROM user WHERE cox_id = id) as registered_at
FROM trip WHERE planned_event_id = ?
        ",
            trip_details_id
        )
        .fetch_all(db)
        .await
        .unwrap()
        .into_iter()
        .map(|r| Registration {
            name: r.name,
            registered_at: r.registered_at,
            is_guest: false,
            is_real_guest: false,
        })
        .collect() //Okay, as PlannedEvent can only be created with proper DB backing
    }
}

pub struct EventUpdate<'a> {
    pub name: &'a str,
    pub planned_amount_cox: i32,
    pub max_people: i32,
    pub notes: Option<&'a str>,
    pub always_show: bool,
    pub is_locked: bool,
}

impl PlannedEvent {
    pub async fn find_by_id(db: &SqlitePool, id: i64) -> Option<Self> {
        sqlx::query_as!(
            Self,
            "
SELECT
    planned_event.id, planned_event.name, planned_amount_cox, trip_details_id, planned_starting_time, max_people, day, notes, allow_guests, trip_type_id, always_show, is_locked
FROM planned_event 
INNER JOIN trip_details ON planned_event.trip_details_id = trip_details.id
WHERE planned_event.id like ?
        ",
            id
        )
        .fetch_one(db)
        .await
        .ok()
    }

    pub async fn get_pinned_for_day(
        db: &SqlitePool,
        day: NaiveDate,
    ) -> Vec<PlannedEventWithUserAndTriptype> {
        let mut events = Self::get_for_day(db, day).await;
        events.retain(|e| e.planned_event.always_show);
        events
    }

    pub async fn get_for_day(
        db: &SqlitePool,
        day: NaiveDate,
    ) -> Vec<PlannedEventWithUserAndTriptype> {
        let day = format!("{day}");
        let events = sqlx::query_as!(
            PlannedEvent,
            "SELECT planned_event.id, planned_event.name, planned_amount_cox, trip_details_id, planned_starting_time, always_show, max_people, day, notes, allow_guests, trip_type_id, is_locked
FROM planned_event
INNER JOIN trip_details ON planned_event.trip_details_id = trip_details.id
WHERE day=?",
        day
        )
        .fetch_all(db)
        .await
        .unwrap(); //TODO: fixme

        let mut ret = Vec::new();
        for event in events {
            let cox = Registration::all_cox(db, event.id).await;
            let mut trip_type = None;
            if let Some(trip_type_id) = event.trip_type_id {
                trip_type = TripType::find_by_id(db, trip_type_id).await;
            }
            ret.push(PlannedEventWithUserAndTriptype {
                cox_needed: event.planned_amount_cox > cox.len() as i64,
                cox,
                rower: Registration::all_rower(db, event.trip_details_id).await,
                planned_event: event,
                trip_type,
            });
        }
        ret
    }

    pub async fn all(db: &SqlitePool) -> Vec<PlannedEvent> {
        sqlx::query_as!(
            PlannedEvent,
            "SELECT planned_event.id, planned_event.name, planned_amount_cox, trip_details_id, planned_starting_time, always_show, max_people, day, notes, allow_guests, trip_type_id, is_locked
FROM planned_event
INNER JOIN trip_details ON planned_event.trip_details_id = trip_details.id",
        )
        .fetch_all(db)
        .await
        .unwrap() //TODO: fixme
    }

    //TODO: add tests
    pub async fn is_rower_registered(&self, db: &SqlitePool, user: &User) -> bool {
        let is_rower = sqlx::query!(
            "SELECT count(*) as amount
            FROM user_trip
            WHERE trip_details_id =
                (SELECT trip_details_id FROM planned_event WHERE id = ?)
            AND user_id = ?",
            self.id,
            user.id
        )
        .fetch_one(db)
        .await
        .unwrap(); //Okay, bc planned_event can only be created with proper DB backing
        is_rower.amount > 0
    }

    pub async fn create(
        db: &SqlitePool,
        name: &str,
        planned_amount_cox: i32,
        trip_details: TripDetails,
    ) {
        sqlx::query!(
            "INSERT INTO planned_event(name, planned_amount_cox, trip_details_id) VALUES(?, ?, ?)",
            name,
            planned_amount_cox,
            trip_details.id,
        )
        .execute(db)
        .await
        .unwrap(); //Okay, as TripDetails can only be created with proper DB backing
    }

    //TODO: create unit test
    pub async fn update(&self, db: &SqlitePool, update: &EventUpdate<'_>) {
        sqlx::query!(
            "UPDATE planned_event SET name = ?, planned_amount_cox = ? WHERE id = ?",
            update.name,
            update.planned_amount_cox,
            self.id
        )
        .execute(db)
        .await
        .unwrap(); //Okay, as planned_event can only be created with proper DB backing

        let tripdetails = self.trip_details(db).await;
        let was_already_cancelled = tripdetails.max_people == 0;

        sqlx::query!(
            "UPDATE trip_details SET max_people = ?, notes = ?, always_show = ?, is_locked = ? WHERE id = ?",
            update.max_people,
            update.notes,
            update.always_show,
            update.is_locked,
            self.trip_details_id
        )
        .execute(db)
        .await
        .unwrap(); //Okay, as planned_event can only be created with proper DB backing

        if update.max_people == 0 && !was_already_cancelled {
            let coxes = Registration::all_cox(db, self.id).await;
            for user in coxes {
                if let Some(user) = User::find_by_name(db, &user.name).await {
                    let notes = if let Some(notes) = update.notes {
                        format!("Grund der Absage: {notes}")
                    } else {
                        String::from("")
                    };
                    Notification::create(
                        db,
                        &user,
                        &format!(
                            "Die Ausfahrt {} am {} um {} wurde abgesagt. {}",
                            self.name, self.day, self.planned_starting_time, notes
                        ),
                        "Absage Ausfahrt",
                        None,
                        Some(&format!("remove_trip_by_planned_event:{}", self.id)),
                    )
                    .await;
                }
            }

            let rower = Registration::all_rower(db, self.trip_details_id).await;
            for user in rower {
                if let Some(user) = User::find_by_name(db, &user.name).await {
                    let notes = match update.notes {
                        Some(n) if !n.is_empty() => n,
                        _ => ".",
                    };

                    Notification::create(
                        db,
                        &user,
                        &format!(
                            "Die Ausfahrt {} am {} um {} wurde abgesagt{}",
                            self.name, self.day, self.planned_starting_time, notes
                        ),
                        "Absage Ausfahrt",
                        None,
                        Some(&format!(
                            "remove_user_trip_with_trip_details_id:{}",
                            tripdetails.id
                        )),
                    )
                    .await;
                }
            }
        }
        if update.max_people > 0 && was_already_cancelled {
            Notification::delete_by_action(
                db,
                &format!("remove_user_trip_with_trip_details_id:{}", tripdetails.id),
            )
            .await;
            Notification::delete_by_action(
                db,
                &format!("remove_trip_by_planned_event:{}", self.id),
            )
            .await;
        }
    }

    pub async fn delete(&self, db: &SqlitePool) -> Result<(), String> {
        if !Registration::all_rower(db, self.trip_details_id)
            .await
            .is_empty()
        {
            return Err(
                "Event kann nicht gelöscht werden, weil mind. 1 Ruderer angemeldet ist.".into(),
            );
        }
        if !Registration::all_cox(db, self.trip_details_id)
            .await
            .is_empty()
        {
            return Err(
                "Event kann nicht gelöscht werden, weil mind. 1 Steuerperson angemeldet ist."
                    .into(),
            );
        }

        sqlx::query!("DELETE FROM planned_event WHERE id = ?", self.id)
            .execute(db)
            .await
            .unwrap(); //Okay, as PlannedEvent can only be created with proper DB backing

        Ok(())
    }

    pub async fn get_ics_feed(db: &SqlitePool) -> String {
        let mut calendar = ICalendar::new("2.0", "ics-rs");

        let events = PlannedEvent::all(db).await;
        for event in events {
            let mut vevent = Event::new(format!("{}@rudernlinz.at", event.id), "19900101T180000");
            vevent.push(DtStart::new(format!(
                "{}T{}00",
                event.day.replace('-', ""),
                event.planned_starting_time.replace(':', "")
            )));
            vevent.push(Summary::new(event.name));
            calendar.add_event(vevent);
        }
        let mut buf = Vec::new();
        write!(&mut buf, "{}", calendar).unwrap();
        String::from_utf8(buf).unwrap()
    }

    pub async fn trip_details(&self, db: &SqlitePool) -> TripDetails {
        TripDetails::find_by_id(db, self.trip_details_id)
            .await
            .unwrap() //ok, not null in db
    }
}

#[cfg(test)]
mod test {
    use crate::{model::tripdetails::TripDetails, testdb};

    use super::PlannedEvent;
    use chrono::NaiveDate;
    use sqlx::SqlitePool;

    #[sqlx::test]
    fn test_get_day() {
        let pool = testdb!();

        let res =
            PlannedEvent::get_for_day(&pool, NaiveDate::from_ymd_opt(1970, 1, 1).unwrap()).await;
        assert_eq!(res.len(), 1);
    }

    #[sqlx::test]
    fn test_create() {
        let pool = testdb!();

        let trip_details = TripDetails::find_by_id(&pool, 1).await.unwrap();

        PlannedEvent::create(&pool, "new-event".into(), 2, trip_details).await;

        let res =
            PlannedEvent::get_for_day(&pool, NaiveDate::from_ymd_opt(1970, 1, 1).unwrap()).await;
        assert_eq!(res.len(), 2);
    }

    #[sqlx::test]
    fn test_delete() {
        let pool = testdb!();
        let planned_event = PlannedEvent::find_by_id(&pool, 1).await.unwrap();

        planned_event.delete(&pool).await.unwrap();

        let res =
            PlannedEvent::get_for_day(&pool, NaiveDate::from_ymd_opt(1970, 1, 1).unwrap()).await;
        assert_eq!(res.len(), 0);
    }

    #[sqlx::test]
    fn test_ics() {
        let pool = testdb!();

        let actual = PlannedEvent::get_ics_feed(&pool).await;
        assert_eq!("BEGIN:VCALENDAR\r\nVERSION:2.0\r\nPRODID:ics-rs\r\nBEGIN:VEVENT\r\nUID:1@rudernlinz.at\r\nDTSTAMP:19900101T180000\r\nDTSTART:19700101T100000\r\nSUMMARY:test-planned-event\r\nEND:VEVENT\r\nEND:VCALENDAR\r\n", actual);
    }
}